mirror of
				https://github.com/chartdb/chartdb.git
				synced 2025-10-30 19:43:54 +00:00 
			
		
		
		
	fix(sql-import): fix SQL Server foreign key parsing for tables without schema prefix (#857)
This commit is contained in:
		| @@ -0,0 +1,573 @@ | |||||||
|  | import { describe, expect, it } from 'vitest'; | ||||||
|  | import { fromSQLServer } from '../sqlserver'; | ||||||
|  |  | ||||||
|  | describe('SQL Server Multi-Schema Database Tests', () => { | ||||||
|  |     it('should parse a fantasy-themed multi-schema database with cross-schema relationships', async () => { | ||||||
|  |         const sql = ` | ||||||
|  | -- ============================================= | ||||||
|  | -- Magical Realm Multi-Schema Database | ||||||
|  | -- A comprehensive fantasy database with multiple schemas | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | -- Create schemas | ||||||
|  | CREATE SCHEMA [realm]; | ||||||
|  | CREATE SCHEMA [academy]; | ||||||
|  | CREATE SCHEMA [treasury]; | ||||||
|  | CREATE SCHEMA [combat]; | ||||||
|  | CREATE SCHEMA [marketplace]; | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- REALM Schema - Core realm entities | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [realm].[kingdoms] ( | ||||||
|  |     [kingdom_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [kingdom_name] NVARCHAR(100) NOT NULL UNIQUE, | ||||||
|  |     [ruler_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [founding_date] DATE NOT NULL, | ||||||
|  |     [capital_city] NVARCHAR(100), | ||||||
|  |     [population] BIGINT, | ||||||
|  |     [treasury_gold] DECIMAL(18, 2) DEFAULT 10000.00 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [realm].[cities] ( | ||||||
|  |     [city_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [city_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [kingdom_id] BIGINT NOT NULL, | ||||||
|  |     [population] INT, | ||||||
|  |     [has_walls] BIT DEFAULT 0, | ||||||
|  |     [has_academy] BIT DEFAULT 0, | ||||||
|  |     [has_marketplace] BIT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [realm].[guilds] ( | ||||||
|  |     [guild_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [guild_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [guild_type] NVARCHAR(50) NOT NULL, -- 'Mages', 'Warriors', 'Thieves', 'Merchants' | ||||||
|  |     [headquarters_city_id] BIGINT NOT NULL, | ||||||
|  |     [founding_year] INT, | ||||||
|  |     [member_count] INT DEFAULT 0, | ||||||
|  |     [guild_master] NVARCHAR(100) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- ACADEMY Schema - Educational institutions | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [academy].[schools] ( | ||||||
|  |     [school_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [school_name] NVARCHAR(150) NOT NULL, | ||||||
|  |     [city_id] BIGINT NOT NULL, | ||||||
|  |     [specialization] NVARCHAR(100), -- 'Elemental Magic', 'Necromancy', 'Healing', 'Alchemy' | ||||||
|  |     [founded_year] INT, | ||||||
|  |     [tuition_gold] DECIMAL(10, 2), | ||||||
|  |     [headmaster] NVARCHAR(100) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [academy].[students] ( | ||||||
|  |     [student_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [first_name] NVARCHAR(50) NOT NULL, | ||||||
|  |     [last_name] NVARCHAR(50) NOT NULL, | ||||||
|  |     [school_id] BIGINT NOT NULL, | ||||||
|  |     [enrollment_date] DATE NOT NULL, | ||||||
|  |     [graduation_date] DATE NULL, | ||||||
|  |     [major_discipline] NVARCHAR(100), | ||||||
|  |     [home_kingdom_id] BIGINT NOT NULL, | ||||||
|  |     [sponsor_guild_id] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [academy].[courses] ( | ||||||
|  |     [course_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [course_name] NVARCHAR(200) NOT NULL, | ||||||
|  |     [school_id] BIGINT NOT NULL, | ||||||
|  |     [credit_hours] INT, | ||||||
|  |     [difficulty_level] INT CHECK (difficulty_level BETWEEN 1 AND 10), | ||||||
|  |     [prerequisites] NVARCHAR(MAX), | ||||||
|  |     [professor_name] NVARCHAR(100) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [academy].[enrollments] ( | ||||||
|  |     [enrollment_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [student_id] BIGINT NOT NULL, | ||||||
|  |     [course_id] BIGINT NOT NULL, | ||||||
|  |     [enrollment_date] DATE NOT NULL, | ||||||
|  |     [grade] NVARCHAR(2), | ||||||
|  |     [completed] BIT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- TREASURY Schema - Financial entities | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [treasury].[currencies] ( | ||||||
|  |     [currency_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [currency_name] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [symbol] NVARCHAR(10), | ||||||
|  |     [gold_exchange_rate] DECIMAL(10, 4) NOT NULL, | ||||||
|  |     [issuing_kingdom_id] BIGINT NOT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [treasury].[banks] ( | ||||||
|  |     [bank_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [bank_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [headquarters_city_id] BIGINT NOT NULL, | ||||||
|  |     [total_deposits] DECIMAL(18, 2) DEFAULT 0, | ||||||
|  |     [vault_security_level] INT CHECK (vault_security_level BETWEEN 1 AND 10), | ||||||
|  |     [founding_date] DATE | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [treasury].[accounts] ( | ||||||
|  |     [account_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [account_number] NVARCHAR(20) NOT NULL UNIQUE, | ||||||
|  |     [bank_id] BIGINT NOT NULL, | ||||||
|  |     [owner_type] NVARCHAR(20) NOT NULL, -- 'Student', 'Guild', 'Kingdom', 'Merchant' | ||||||
|  |     [owner_id] BIGINT NOT NULL, | ||||||
|  |     [balance] DECIMAL(18, 2) DEFAULT 0, | ||||||
|  |     [currency_id] BIGINT NOT NULL, | ||||||
|  |     [opened_date] DATE NOT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [treasury].[transactions] ( | ||||||
|  |     [transaction_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [from_account_id] BIGINT NULL, | ||||||
|  |     [to_account_id] BIGINT NULL, | ||||||
|  |     [amount] DECIMAL(18, 2) NOT NULL, | ||||||
|  |     [currency_id] BIGINT NOT NULL, | ||||||
|  |     [transaction_date] DATETIME NOT NULL, | ||||||
|  |     [description] NVARCHAR(500), | ||||||
|  |     [transaction_type] NVARCHAR(50) -- 'Deposit', 'Withdrawal', 'Transfer', 'Payment' | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- COMBAT Schema - Battle and warrior entities | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [combat].[warriors] ( | ||||||
|  |     [warrior_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [warrior_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [class] NVARCHAR(50) NOT NULL, -- 'Knight', 'Archer', 'Mage', 'Barbarian' | ||||||
|  |     [level] INT DEFAULT 1, | ||||||
|  |     [experience_points] BIGINT DEFAULT 0, | ||||||
|  |     [guild_id] BIGINT NULL, | ||||||
|  |     [home_city_id] BIGINT NOT NULL, | ||||||
|  |     [strength] INT, | ||||||
|  |     [agility] INT, | ||||||
|  |     [intelligence] INT, | ||||||
|  |     [current_hp] INT, | ||||||
|  |     [max_hp] INT | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [combat].[weapons] ( | ||||||
|  |     [weapon_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [weapon_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [weapon_type] NVARCHAR(50), -- 'Sword', 'Bow', 'Staff', 'Axe' | ||||||
|  |     [damage] INT, | ||||||
|  |     [durability] INT, | ||||||
|  |     [enchantment_level] INT DEFAULT 0, | ||||||
|  |     [market_value] DECIMAL(10, 2), | ||||||
|  |     [owner_warrior_id] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [combat].[battles] ( | ||||||
|  |     [battle_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [battle_name] NVARCHAR(200), | ||||||
|  |     [battle_date] DATETIME NOT NULL, | ||||||
|  |     [location_city_id] BIGINT NOT NULL, | ||||||
|  |     [victor_warrior_id] BIGINT NULL, | ||||||
|  |     [total_participants] INT, | ||||||
|  |     [battle_type] NVARCHAR(50) -- 'Duel', 'Tournament', 'War', 'Training' | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [combat].[battle_participants] ( | ||||||
|  |     [participant_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [battle_id] BIGINT NOT NULL, | ||||||
|  |     [warrior_id] BIGINT NOT NULL, | ||||||
|  |     [damage_dealt] INT DEFAULT 0, | ||||||
|  |     [damage_received] INT DEFAULT 0, | ||||||
|  |     [survived] BIT DEFAULT 1, | ||||||
|  |     [rewards_earned] DECIMAL(10, 2) DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- MARKETPLACE Schema - Commerce entities | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [marketplace].[merchants] ( | ||||||
|  |     [merchant_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [merchant_name] NVARCHAR(100) NOT NULL, | ||||||
|  |     [shop_name] NVARCHAR(150), | ||||||
|  |     [city_id] BIGINT NOT NULL, | ||||||
|  |     [specialization] NVARCHAR(100), -- 'Weapons', 'Potions', 'Scrolls', 'Artifacts' | ||||||
|  |     [reputation_score] INT DEFAULT 50, | ||||||
|  |     [bank_account_id] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [marketplace].[items] ( | ||||||
|  |     [item_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [item_name] NVARCHAR(150) NOT NULL, | ||||||
|  |     [item_type] NVARCHAR(50), | ||||||
|  |     [base_price] DECIMAL(10, 2), | ||||||
|  |     [rarity] NVARCHAR(20), -- 'Common', 'Uncommon', 'Rare', 'Epic', 'Legendary' | ||||||
|  |     [merchant_id] BIGINT NOT NULL, | ||||||
|  |     [stock_quantity] INT DEFAULT 0, | ||||||
|  |     [magical_properties] NVARCHAR(MAX) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [marketplace].[trade_routes] ( | ||||||
|  |     [route_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [from_city_id] BIGINT NOT NULL, | ||||||
|  |     [to_city_id] BIGINT NOT NULL, | ||||||
|  |     [distance_leagues] INT, | ||||||
|  |     [travel_days] INT, | ||||||
|  |     [danger_level] INT CHECK (danger_level BETWEEN 1 AND 10), | ||||||
|  |     [toll_cost] DECIMAL(10, 2), | ||||||
|  |     [controlled_by_guild_id] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [marketplace].[transactions] ( | ||||||
|  |     [transaction_id] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [buyer_type] NVARCHAR(20), -- 'Warrior', 'Student', 'Merchant' | ||||||
|  |     [buyer_id] BIGINT NOT NULL, | ||||||
|  |     [merchant_id] BIGINT NOT NULL, | ||||||
|  |     [item_id] BIGINT NOT NULL, | ||||||
|  |     [quantity] INT NOT NULL, | ||||||
|  |     [total_price] DECIMAL(10, 2) NOT NULL, | ||||||
|  |     [transaction_date] DATETIME NOT NULL, | ||||||
|  |     [payment_account_id] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Foreign Key Constraints - Cross-Schema Relationships | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | -- Realm schema relationships | ||||||
|  | ALTER TABLE [realm].[cities] ADD CONSTRAINT [FK_Cities_Kingdoms]  | ||||||
|  |     FOREIGN KEY ([kingdom_id]) REFERENCES [realm].[kingdoms]([kingdom_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [realm].[guilds] ADD CONSTRAINT [FK_Guilds_Cities]  | ||||||
|  |     FOREIGN KEY ([headquarters_city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | -- Academy schema relationships (references realm schema) | ||||||
|  | ALTER TABLE [academy].[schools] ADD CONSTRAINT [FK_Schools_Cities]  | ||||||
|  |     FOREIGN KEY ([city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [academy].[students] ADD CONSTRAINT [FK_Students_Schools]  | ||||||
|  |     FOREIGN KEY ([school_id]) REFERENCES [academy].[schools]([school_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [academy].[students] ADD CONSTRAINT [FK_Students_Kingdoms]  | ||||||
|  |     FOREIGN KEY ([home_kingdom_id]) REFERENCES [realm].[kingdoms]([kingdom_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [academy].[students] ADD CONSTRAINT [FK_Students_Guilds]  | ||||||
|  |     FOREIGN KEY ([sponsor_guild_id]) REFERENCES [realm].[guilds]([guild_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [academy].[courses] ADD CONSTRAINT [FK_Courses_Schools]  | ||||||
|  |     FOREIGN KEY ([school_id]) REFERENCES [academy].[schools]([school_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [academy].[enrollments] ADD CONSTRAINT [FK_Enrollments_Students]  | ||||||
|  |     FOREIGN KEY ([student_id]) REFERENCES [academy].[students]([student_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [academy].[enrollments] ADD CONSTRAINT [FK_Enrollments_Courses]  | ||||||
|  |     FOREIGN KEY ([course_id]) REFERENCES [academy].[courses]([course_id]); | ||||||
|  |  | ||||||
|  | -- Treasury schema relationships (references realm schema) | ||||||
|  | ALTER TABLE [treasury].[currencies] ADD CONSTRAINT [FK_Currencies_Kingdoms]  | ||||||
|  |     FOREIGN KEY ([issuing_kingdom_id]) REFERENCES [realm].[kingdoms]([kingdom_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [treasury].[banks] ADD CONSTRAINT [FK_Banks_Cities]  | ||||||
|  |     FOREIGN KEY ([headquarters_city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [treasury].[accounts] ADD CONSTRAINT [FK_Accounts_Banks]  | ||||||
|  |     FOREIGN KEY ([bank_id]) REFERENCES [treasury].[banks]([bank_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [treasury].[accounts] ADD CONSTRAINT [FK_Accounts_Currencies]  | ||||||
|  |     FOREIGN KEY ([currency_id]) REFERENCES [treasury].[currencies]([currency_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [treasury].[transactions] ADD CONSTRAINT [FK_Transactions_FromAccount]  | ||||||
|  |     FOREIGN KEY ([from_account_id]) REFERENCES [treasury].[accounts]([account_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [treasury].[transactions] ADD CONSTRAINT [FK_Transactions_ToAccount]  | ||||||
|  |     FOREIGN KEY ([to_account_id]) REFERENCES [treasury].[accounts]([account_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [treasury].[transactions] ADD CONSTRAINT [FK_Transactions_Currency]  | ||||||
|  |     FOREIGN KEY ([currency_id]) REFERENCES [treasury].[currencies]([currency_id]); | ||||||
|  |  | ||||||
|  | -- Combat schema relationships (references realm and combat schemas) | ||||||
|  | ALTER TABLE [combat].[warriors] ADD CONSTRAINT [FK_Warriors_Guilds]  | ||||||
|  |     FOREIGN KEY ([guild_id]) REFERENCES [realm].[guilds]([guild_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [combat].[warriors] ADD CONSTRAINT [FK_Warriors_Cities]  | ||||||
|  |     FOREIGN KEY ([home_city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [combat].[weapons] ADD CONSTRAINT [FK_Weapons_Warriors]  | ||||||
|  |     FOREIGN KEY ([owner_warrior_id]) REFERENCES [combat].[warriors]([warrior_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [combat].[battles] ADD CONSTRAINT [FK_Battles_Cities]  | ||||||
|  |     FOREIGN KEY ([location_city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [combat].[battles] ADD CONSTRAINT [FK_Battles_VictorWarrior]  | ||||||
|  |     FOREIGN KEY ([victor_warrior_id]) REFERENCES [combat].[warriors]([warrior_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [combat].[battle_participants] ADD CONSTRAINT [FK_BattleParticipants_Battles]  | ||||||
|  |     FOREIGN KEY ([battle_id]) REFERENCES [combat].[battles]([battle_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [combat].[battle_participants] ADD CONSTRAINT [FK_BattleParticipants_Warriors]  | ||||||
|  |     FOREIGN KEY ([warrior_id]) REFERENCES [combat].[warriors]([warrior_id]); | ||||||
|  |  | ||||||
|  | -- Marketplace schema relationships (references multiple schemas) | ||||||
|  | ALTER TABLE [marketplace].[merchants] ADD CONSTRAINT [FK_Merchants_Cities]  | ||||||
|  |     FOREIGN KEY ([city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[merchants] ADD CONSTRAINT [FK_Merchants_BankAccounts]  | ||||||
|  |     FOREIGN KEY ([bank_account_id]) REFERENCES [treasury].[accounts]([account_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[items] ADD CONSTRAINT [FK_Items_Merchants]  | ||||||
|  |     FOREIGN KEY ([merchant_id]) REFERENCES [marketplace].[merchants]([merchant_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[trade_routes] ADD CONSTRAINT [FK_TradeRoutes_FromCity]  | ||||||
|  |     FOREIGN KEY ([from_city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[trade_routes] ADD CONSTRAINT [FK_TradeRoutes_ToCity]  | ||||||
|  |     FOREIGN KEY ([to_city_id]) REFERENCES [realm].[cities]([city_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[trade_routes] ADD CONSTRAINT [FK_TradeRoutes_Guilds]  | ||||||
|  |     FOREIGN KEY ([controlled_by_guild_id]) REFERENCES [realm].[guilds]([guild_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[transactions] ADD CONSTRAINT [FK_MarketTransactions_Merchants]  | ||||||
|  |     FOREIGN KEY ([merchant_id]) REFERENCES [marketplace].[merchants]([merchant_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[transactions] ADD CONSTRAINT [FK_MarketTransactions_Items]  | ||||||
|  |     FOREIGN KEY ([item_id]) REFERENCES [marketplace].[items]([item_id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [marketplace].[transactions] ADD CONSTRAINT [FK_MarketTransactions_PaymentAccount]  | ||||||
|  |     FOREIGN KEY ([payment_account_id]) REFERENCES [treasury].[accounts]([account_id]); | ||||||
|  |  | ||||||
|  | -- Note: Testing table reference without schema prefix defaults to dbo schema | ||||||
|  |         `; | ||||||
|  |  | ||||||
|  |         const result = await fromSQLServer(sql); | ||||||
|  |  | ||||||
|  |         // Verify all schemas are recognized | ||||||
|  |         const schemas = new Set(result.tables.map((t) => t.schema)); | ||||||
|  |         expect(schemas.has('realm')).toBe(true); | ||||||
|  |         expect(schemas.has('academy')).toBe(true); | ||||||
|  |         expect(schemas.has('treasury')).toBe(true); | ||||||
|  |         expect(schemas.has('combat')).toBe(true); | ||||||
|  |         expect(schemas.has('marketplace')).toBe(true); | ||||||
|  |  | ||||||
|  |         // Verify table count per schema | ||||||
|  |         const tablesBySchema = { | ||||||
|  |             realm: result.tables.filter((t) => t.schema === 'realm').length, | ||||||
|  |             academy: result.tables.filter((t) => t.schema === 'academy').length, | ||||||
|  |             treasury: result.tables.filter((t) => t.schema === 'treasury') | ||||||
|  |                 .length, | ||||||
|  |             combat: result.tables.filter((t) => t.schema === 'combat').length, | ||||||
|  |             marketplace: result.tables.filter((t) => t.schema === 'marketplace') | ||||||
|  |                 .length, | ||||||
|  |         }; | ||||||
|  |  | ||||||
|  |         expect(tablesBySchema.realm).toBe(3); // kingdoms, cities, guilds | ||||||
|  |         expect(tablesBySchema.academy).toBe(4); // schools, students, courses, enrollments | ||||||
|  |         expect(tablesBySchema.treasury).toBe(4); // currencies, banks, accounts, transactions | ||||||
|  |         expect(tablesBySchema.combat).toBe(4); // warriors, weapons, battles, battle_participants | ||||||
|  |         expect(tablesBySchema.marketplace).toBe(4); // merchants, items, trade_routes, transactions | ||||||
|  |  | ||||||
|  |         // Total tables should be 19 | ||||||
|  |         expect(result.tables.length).toBe(19); | ||||||
|  |  | ||||||
|  |         // Debug: log which relationships are missing | ||||||
|  |         const expectedRelationshipNames = [ | ||||||
|  |             'FK_Cities_Kingdoms', | ||||||
|  |             'FK_Guilds_Cities', | ||||||
|  |             'FK_Schools_Cities', | ||||||
|  |             'FK_Students_Schools', | ||||||
|  |             'FK_Students_Kingdoms', | ||||||
|  |             'FK_Students_Guilds', | ||||||
|  |             'FK_Courses_Schools', | ||||||
|  |             'FK_Enrollments_Students', | ||||||
|  |             'FK_Enrollments_Courses', | ||||||
|  |             'FK_Currencies_Kingdoms', | ||||||
|  |             'FK_Banks_Cities', | ||||||
|  |             'FK_Accounts_Banks', | ||||||
|  |             'FK_Accounts_Currencies', | ||||||
|  |             'FK_Transactions_FromAccount', | ||||||
|  |             'FK_Transactions_ToAccount', | ||||||
|  |             'FK_Transactions_Currency', | ||||||
|  |             'FK_Warriors_Guilds', | ||||||
|  |             'FK_Warriors_Cities', | ||||||
|  |             'FK_Weapons_Warriors', | ||||||
|  |             'FK_Battles_Cities', | ||||||
|  |             'FK_Battles_VictorWarrior', | ||||||
|  |             'FK_BattleParticipants_Battles', | ||||||
|  |             'FK_BattleParticipants_Warriors', | ||||||
|  |             'FK_Merchants_Cities', | ||||||
|  |             'FK_Merchants_BankAccounts', | ||||||
|  |             'FK_Items_Merchants', | ||||||
|  |             'FK_TradeRoutes_FromCity', | ||||||
|  |             'FK_TradeRoutes_ToCity', | ||||||
|  |             'FK_TradeRoutes_Guilds', | ||||||
|  |             'FK_MarketTransactions_Merchants', | ||||||
|  |             'FK_MarketTransactions_Items', | ||||||
|  |             'FK_MarketTransactions_PaymentAccount', | ||||||
|  |         ]; | ||||||
|  |  | ||||||
|  |         const foundRelationshipNames = result.relationships.map((r) => r.name); | ||||||
|  |         const missingRelationships = expectedRelationshipNames.filter( | ||||||
|  |             (name) => !foundRelationshipNames.includes(name) | ||||||
|  |         ); | ||||||
|  |  | ||||||
|  |         if (missingRelationships.length > 0) { | ||||||
|  |             console.log('Missing relationships:', missingRelationships); | ||||||
|  |             console.log('Found relationships:', foundRelationshipNames); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Verify relationships count - we have 32 working relationships | ||||||
|  |         expect(result.relationships.length).toBe(32); | ||||||
|  |  | ||||||
|  |         // Verify some specific cross-schema relationships | ||||||
|  |         const crossSchemaRelationships = result.relationships.filter( | ||||||
|  |             (r) => r.sourceSchema !== r.targetSchema | ||||||
|  |         ); | ||||||
|  |  | ||||||
|  |         expect(crossSchemaRelationships.length).toBeGreaterThan(10); // Many cross-schema relationships | ||||||
|  |  | ||||||
|  |         // Check specific cross-schema relationships exist | ||||||
|  |         const schoolsToCities = result.relationships.find( | ||||||
|  |             (r) => | ||||||
|  |                 r.sourceTable === 'schools' && | ||||||
|  |                 r.sourceSchema === 'academy' && | ||||||
|  |                 r.targetTable === 'cities' && | ||||||
|  |                 r.targetSchema === 'realm' | ||||||
|  |         ); | ||||||
|  |         expect(schoolsToCities).toBeDefined(); | ||||||
|  |         expect(schoolsToCities?.name).toBe('FK_Schools_Cities'); | ||||||
|  |  | ||||||
|  |         const studentsToKingdoms = result.relationships.find( | ||||||
|  |             (r) => | ||||||
|  |                 r.sourceTable === 'students' && | ||||||
|  |                 r.sourceSchema === 'academy' && | ||||||
|  |                 r.targetTable === 'kingdoms' && | ||||||
|  |                 r.targetSchema === 'realm' | ||||||
|  |         ); | ||||||
|  |         expect(studentsToKingdoms).toBeDefined(); | ||||||
|  |         expect(studentsToKingdoms?.name).toBe('FK_Students_Kingdoms'); | ||||||
|  |  | ||||||
|  |         const warriorsToGuilds = result.relationships.find( | ||||||
|  |             (r) => | ||||||
|  |                 r.sourceTable === 'warriors' && | ||||||
|  |                 r.sourceSchema === 'combat' && | ||||||
|  |                 r.targetTable === 'guilds' && | ||||||
|  |                 r.targetSchema === 'realm' | ||||||
|  |         ); | ||||||
|  |         expect(warriorsToGuilds).toBeDefined(); | ||||||
|  |         expect(warriorsToGuilds?.name).toBe('FK_Warriors_Guilds'); | ||||||
|  |  | ||||||
|  |         const merchantsToAccounts = result.relationships.find( | ||||||
|  |             (r) => | ||||||
|  |                 r.sourceTable === 'merchants' && | ||||||
|  |                 r.sourceSchema === 'marketplace' && | ||||||
|  |                 r.targetTable === 'accounts' && | ||||||
|  |                 r.targetSchema === 'treasury' | ||||||
|  |         ); | ||||||
|  |         expect(merchantsToAccounts).toBeDefined(); | ||||||
|  |         expect(merchantsToAccounts?.name).toBe('FK_Merchants_BankAccounts'); | ||||||
|  |  | ||||||
|  |         // Verify all relationships have valid source and target table IDs | ||||||
|  |         const validRelationships = result.relationships.filter( | ||||||
|  |             (r) => r.sourceTableId && r.targetTableId | ||||||
|  |         ); | ||||||
|  |         expect(validRelationships.length).toBe(result.relationships.length); | ||||||
|  |  | ||||||
|  |         // Check that table IDs are properly linked | ||||||
|  |         for (const rel of result.relationships) { | ||||||
|  |             const sourceTable = result.tables.find( | ||||||
|  |                 (t) => | ||||||
|  |                     t.name === rel.sourceTable && t.schema === rel.sourceSchema | ||||||
|  |             ); | ||||||
|  |             const targetTable = result.tables.find( | ||||||
|  |                 (t) => | ||||||
|  |                     t.name === rel.targetTable && t.schema === rel.targetSchema | ||||||
|  |             ); | ||||||
|  |  | ||||||
|  |             expect(sourceTable).toBeDefined(); | ||||||
|  |             expect(targetTable).toBeDefined(); | ||||||
|  |             expect(rel.sourceTableId).toBe(sourceTable?.id); | ||||||
|  |             expect(rel.targetTableId).toBe(targetTable?.id); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Test relationships within the same schema | ||||||
|  |         const withinSchemaRels = result.relationships.filter( | ||||||
|  |             (r) => r.sourceSchema === r.targetSchema | ||||||
|  |         ); | ||||||
|  |         expect(withinSchemaRels.length).toBeGreaterThan(10); | ||||||
|  |  | ||||||
|  |         // Verify specific within-schema relationship | ||||||
|  |         const citiesToKingdoms = result.relationships.find( | ||||||
|  |             (r) => | ||||||
|  |                 r.sourceTable === 'cities' && | ||||||
|  |                 r.targetTable === 'kingdoms' && | ||||||
|  |                 r.sourceSchema === 'realm' && | ||||||
|  |                 r.targetSchema === 'realm' | ||||||
|  |         ); | ||||||
|  |         expect(citiesToKingdoms).toBeDefined(); | ||||||
|  |  | ||||||
|  |         console.log('Multi-schema test results:'); | ||||||
|  |         console.log('Total schemas:', schemas.size); | ||||||
|  |         console.log('Total tables:', result.tables.length); | ||||||
|  |         console.log('Total relationships:', result.relationships.length); | ||||||
|  |         console.log( | ||||||
|  |             'Cross-schema relationships:', | ||||||
|  |             crossSchemaRelationships.length | ||||||
|  |         ); | ||||||
|  |         console.log('Within-schema relationships:', withinSchemaRels.length); | ||||||
|  |     }); | ||||||
|  |  | ||||||
|  |     it('should handle mixed schema notation formats', async () => { | ||||||
|  |         const sql = ` | ||||||
|  | -- Mix of different schema notation styles | ||||||
|  | CREATE TABLE [dbo].[table1] ( | ||||||
|  |     [id] INT PRIMARY KEY, | ||||||
|  |     [name] NVARCHAR(50) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE table2 ( | ||||||
|  |     id INT PRIMARY KEY, | ||||||
|  |     table1_id INT | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [schema1].[table3] ( | ||||||
|  |     [id] INT PRIMARY KEY, | ||||||
|  |     [value] DECIMAL(10,2) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- Different ALTER TABLE formats | ||||||
|  | ALTER TABLE [dbo].[table1] ADD CONSTRAINT [FK1]  | ||||||
|  |     FOREIGN KEY ([id]) REFERENCES [schema1].[table3]([id]); | ||||||
|  |  | ||||||
|  | ALTER TABLE table2 ADD CONSTRAINT FK2  | ||||||
|  |     FOREIGN KEY (table1_id) REFERENCES [dbo].[table1](id); | ||||||
|  |  | ||||||
|  | ALTER TABLE [schema1].[table3] ADD CONSTRAINT [FK3]  | ||||||
|  |     FOREIGN KEY ([id]) REFERENCES table2(id); | ||||||
|  |         `; | ||||||
|  |  | ||||||
|  |         const result = await fromSQLServer(sql); | ||||||
|  |  | ||||||
|  |         expect(result.tables.length).toBe(3); | ||||||
|  |         expect(result.relationships.length).toBe(3); | ||||||
|  |  | ||||||
|  |         // Verify schemas are correctly assigned | ||||||
|  |         const table1 = result.tables.find((t) => t.name === 'table1'); | ||||||
|  |         const table2 = result.tables.find((t) => t.name === 'table2'); | ||||||
|  |         const table3 = result.tables.find((t) => t.name === 'table3'); | ||||||
|  |  | ||||||
|  |         expect(table1?.schema).toBe('dbo'); | ||||||
|  |         expect(table2?.schema).toBe('dbo'); | ||||||
|  |         expect(table3?.schema).toBe('schema1'); | ||||||
|  |  | ||||||
|  |         // Verify all relationships are properly linked | ||||||
|  |         for (const rel of result.relationships) { | ||||||
|  |             expect(rel.sourceTableId).toBeTruthy(); | ||||||
|  |             expect(rel.targetTableId).toBeTruthy(); | ||||||
|  |         } | ||||||
|  |     }); | ||||||
|  | }); | ||||||
| @@ -0,0 +1,704 @@ | |||||||
|  | import { describe, expect, it } from 'vitest'; | ||||||
|  | import { fromSQLServer } from '../sqlserver'; | ||||||
|  |  | ||||||
|  | describe('SQL Server Single-Schema Database Tests', () => { | ||||||
|  |     it('should parse a comprehensive fantasy-themed single-schema database with many foreign key relationships', async () => { | ||||||
|  |         // This test simulates a complex single-schema database similar to real-world scenarios | ||||||
|  |         // It tests the fix for parsing ALTER TABLE ADD CONSTRAINT statements without schema prefixes | ||||||
|  |         const sql = ` | ||||||
|  | -- ============================================= | ||||||
|  | -- Enchanted Kingdom Management System | ||||||
|  | -- A comprehensive fantasy database using single schema (dbo) | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Core Kingdom Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [Kingdoms] ( | ||||||
|  |     [KingdomID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [KingdomName] NVARCHAR(100) NOT NULL UNIQUE, | ||||||
|  |     [FoundedYear] INT NOT NULL, | ||||||
|  |     [CurrentRuler] NVARCHAR(100) NOT NULL, | ||||||
|  |     [TreasuryGold] DECIMAL(18, 2) DEFAULT 100000.00, | ||||||
|  |     [Population] BIGINT DEFAULT 0, | ||||||
|  |     [MilitaryStrength] INT DEFAULT 100 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Regions] ( | ||||||
|  |     [RegionID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [RegionName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [KingdomID] BIGINT NOT NULL, | ||||||
|  |     [Terrain] NVARCHAR(50), -- 'Mountains', 'Forest', 'Plains', 'Desert', 'Swamp' | ||||||
|  |     [Population] INT DEFAULT 0, | ||||||
|  |     [TaxRate] DECIMAL(5, 2) DEFAULT 10.00 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Cities] ( | ||||||
|  |     [CityID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CityName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [RegionID] BIGINT NOT NULL, | ||||||
|  |     [Population] INT DEFAULT 1000, | ||||||
|  |     [HasWalls] BIT DEFAULT 0, | ||||||
|  |     [HasMarket] BIT DEFAULT 1, | ||||||
|  |     [DefenseRating] INT DEFAULT 5 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Castles] ( | ||||||
|  |     [CastleID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CastleName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [CityID] BIGINT NOT NULL, | ||||||
|  |     [GarrisonSize] INT DEFAULT 50, | ||||||
|  |     [TowerCount] INT DEFAULT 4, | ||||||
|  |     [MoatDepth] DECIMAL(5, 2) DEFAULT 3.00 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Character Management Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [CharacterClasses] ( | ||||||
|  |     [ClassID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [ClassName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [ClassType] NVARCHAR(30), -- 'Warrior', 'Mage', 'Rogue', 'Cleric' | ||||||
|  |     [BaseHealth] INT DEFAULT 100, | ||||||
|  |     [BaseMana] INT DEFAULT 50, | ||||||
|  |     [BaseStrength] INT DEFAULT 10, | ||||||
|  |     [BaseIntelligence] INT DEFAULT 10 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Characters] ( | ||||||
|  |     [CharacterID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CharacterName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [ClassID] BIGINT NOT NULL, | ||||||
|  |     [Level] INT DEFAULT 1, | ||||||
|  |     [Experience] BIGINT DEFAULT 0, | ||||||
|  |     [CurrentHealth] INT DEFAULT 100, | ||||||
|  |     [CurrentMana] INT DEFAULT 50, | ||||||
|  |     [HomeCityID] BIGINT NOT NULL, | ||||||
|  |     [Gold] DECIMAL(10, 2) DEFAULT 100.00, | ||||||
|  |     [CreatedDate] DATE NOT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [CharacterSkills] ( | ||||||
|  |     [SkillID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [SkillName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [RequiredClassID] BIGINT NULL, | ||||||
|  |     [RequiredLevel] INT DEFAULT 1, | ||||||
|  |     [ManaCost] INT DEFAULT 10, | ||||||
|  |     [Cooldown] INT DEFAULT 0, | ||||||
|  |     [Damage] INT DEFAULT 0, | ||||||
|  |     [Description] NVARCHAR(MAX) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [CharacterSkillMapping] ( | ||||||
|  |     [MappingID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [SkillID] BIGINT NOT NULL, | ||||||
|  |     [SkillLevel] INT DEFAULT 1, | ||||||
|  |     [LastUsed] DATETIME NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Guild System Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [GuildTypes] ( | ||||||
|  |     [GuildTypeID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [TypeName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [Description] NVARCHAR(255) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Guilds] ( | ||||||
|  |     [GuildID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [GuildName] NVARCHAR(100) NOT NULL UNIQUE, | ||||||
|  |     [GuildTypeID] BIGINT NOT NULL, | ||||||
|  |     [HeadquartersCityID] BIGINT NOT NULL, | ||||||
|  |     [FoundedDate] DATE NOT NULL, | ||||||
|  |     [GuildMasterID] BIGINT NULL, | ||||||
|  |     [MemberCount] INT DEFAULT 0, | ||||||
|  |     [GuildBank] DECIMAL(18, 2) DEFAULT 0.00, | ||||||
|  |     [Reputation] INT DEFAULT 50 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [GuildMembers] ( | ||||||
|  |     [MembershipID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [GuildID] BIGINT NOT NULL, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [JoinDate] DATE NOT NULL, | ||||||
|  |     [Rank] NVARCHAR(50) DEFAULT 'Member', | ||||||
|  |     [ContributionPoints] INT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [GuildQuests] ( | ||||||
|  |     [QuestID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [QuestName] NVARCHAR(200) NOT NULL, | ||||||
|  |     [GuildID] BIGINT NOT NULL, | ||||||
|  |     [RequiredLevel] INT DEFAULT 1, | ||||||
|  |     [RewardGold] DECIMAL(10, 2) DEFAULT 100.00, | ||||||
|  |     [RewardExperience] INT DEFAULT 100, | ||||||
|  |     [QuestGiverID] BIGINT NULL, | ||||||
|  |     [Status] NVARCHAR(20) DEFAULT 'Available' | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Item and Inventory Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [ItemCategories] ( | ||||||
|  |     [CategoryID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CategoryName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [Description] NVARCHAR(255) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Items] ( | ||||||
|  |     [ItemID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [ItemName] NVARCHAR(150) NOT NULL, | ||||||
|  |     [CategoryID] BIGINT NOT NULL, | ||||||
|  |     [Rarity] NVARCHAR(20), -- 'Common', 'Uncommon', 'Rare', 'Epic', 'Legendary' | ||||||
|  |     [BaseValue] DECIMAL(10, 2) DEFAULT 1.00, | ||||||
|  |     [Weight] DECIMAL(5, 2) DEFAULT 1.00, | ||||||
|  |     [Stackable] BIT DEFAULT 1, | ||||||
|  |     [MaxStack] INT DEFAULT 99, | ||||||
|  |     [RequiredLevel] INT DEFAULT 1, | ||||||
|  |     [RequiredClassID] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Weapons] ( | ||||||
|  |     [WeaponID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [ItemID] BIGINT NOT NULL UNIQUE, | ||||||
|  |     [WeaponType] NVARCHAR(50), -- 'Sword', 'Axe', 'Bow', 'Staff', 'Dagger' | ||||||
|  |     [MinDamage] INT DEFAULT 1, | ||||||
|  |     [MaxDamage] INT DEFAULT 10, | ||||||
|  |     [AttackSpeed] DECIMAL(3, 2) DEFAULT 1.00, | ||||||
|  |     [Durability] INT DEFAULT 100, | ||||||
|  |     [EnchantmentSlots] INT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Armor] ( | ||||||
|  |     [ArmorID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [ItemID] BIGINT NOT NULL UNIQUE, | ||||||
|  |     [ArmorType] NVARCHAR(50), -- 'Helmet', 'Chest', 'Legs', 'Boots', 'Gloves' | ||||||
|  |     [DefenseValue] INT DEFAULT 1, | ||||||
|  |     [MagicResistance] INT DEFAULT 0, | ||||||
|  |     [Durability] INT DEFAULT 100, | ||||||
|  |     [SetBonusID] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [CharacterInventory] ( | ||||||
|  |     [InventoryID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [ItemID] BIGINT NOT NULL, | ||||||
|  |     [Quantity] INT DEFAULT 1, | ||||||
|  |     [IsEquipped] BIT DEFAULT 0, | ||||||
|  |     [SlotPosition] INT NULL, | ||||||
|  |     [AcquiredDate] DATETIME NOT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Magic System Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [MagicSchools] ( | ||||||
|  |     [SchoolID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [SchoolName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [Element] NVARCHAR(30), -- 'Fire', 'Water', 'Earth', 'Air', 'Light', 'Dark' | ||||||
|  |     [Description] NVARCHAR(MAX) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Spells] ( | ||||||
|  |     [SpellID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [SpellName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [SchoolID] BIGINT NOT NULL, | ||||||
|  |     [SpellLevel] INT DEFAULT 1, | ||||||
|  |     [ManaCost] INT DEFAULT 10, | ||||||
|  |     [CastTime] DECIMAL(3, 1) DEFAULT 1.0, | ||||||
|  |     [Range] INT DEFAULT 10, | ||||||
|  |     [AreaOfEffect] INT DEFAULT 0, | ||||||
|  |     [BaseDamage] INT DEFAULT 0, | ||||||
|  |     [Description] NVARCHAR(MAX) | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [SpellBooks] ( | ||||||
|  |     [SpellBookID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [SpellID] BIGINT NOT NULL, | ||||||
|  |     [DateLearned] DATE NOT NULL, | ||||||
|  |     [MasteryLevel] INT DEFAULT 1, | ||||||
|  |     [TimesUsed] INT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Enchantments] ( | ||||||
|  |     [EnchantmentID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [EnchantmentName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [RequiredSpellID] BIGINT NULL, | ||||||
|  |     [BonusType] NVARCHAR(50), -- 'Damage', 'Defense', 'Speed', 'Magic' | ||||||
|  |     [BonusValue] INT DEFAULT 1, | ||||||
|  |     [Duration] INT NULL, -- NULL for permanent | ||||||
|  |     [Cost] DECIMAL(10, 2) DEFAULT 100.00 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [ItemEnchantments] ( | ||||||
|  |     [ItemEnchantmentID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [ItemID] BIGINT NOT NULL, | ||||||
|  |     [EnchantmentID] BIGINT NOT NULL, | ||||||
|  |     [AppliedByCharacterID] BIGINT NOT NULL, | ||||||
|  |     [AppliedDate] DATETIME NOT NULL, | ||||||
|  |     [ExpiryDate] DATETIME NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Quest and Achievement Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [QuestLines] ( | ||||||
|  |     [QuestLineID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [QuestLineName] NVARCHAR(200) NOT NULL, | ||||||
|  |     [MinLevel] INT DEFAULT 1, | ||||||
|  |     [MaxLevel] INT DEFAULT 100, | ||||||
|  |     [TotalQuests] INT DEFAULT 1, | ||||||
|  |     [FinalRewardItemID] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Quests] ( | ||||||
|  |     [QuestID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [QuestName] NVARCHAR(200) NOT NULL, | ||||||
|  |     [QuestLineID] BIGINT NULL, | ||||||
|  |     [QuestGiverNPCID] BIGINT NULL, | ||||||
|  |     [RequiredLevel] INT DEFAULT 1, | ||||||
|  |     [RequiredQuestID] BIGINT NULL, -- Prerequisite quest | ||||||
|  |     [ObjectiveType] NVARCHAR(50), -- 'Kill', 'Collect', 'Deliver', 'Explore' | ||||||
|  |     [ObjectiveCount] INT DEFAULT 1, | ||||||
|  |     [RewardGold] DECIMAL(10, 2) DEFAULT 10.00, | ||||||
|  |     [RewardExperience] INT DEFAULT 100, | ||||||
|  |     [RewardItemID] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [CharacterQuests] ( | ||||||
|  |     [CharacterQuestID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [QuestID] BIGINT NOT NULL, | ||||||
|  |     [StartDate] DATETIME NOT NULL, | ||||||
|  |     [CompletedDate] DATETIME NULL, | ||||||
|  |     [CurrentProgress] INT DEFAULT 0, | ||||||
|  |     [Status] NVARCHAR(20) DEFAULT 'Active' -- 'Active', 'Completed', 'Failed', 'Abandoned' | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Achievements] ( | ||||||
|  |     [AchievementID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [AchievementName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [Description] NVARCHAR(500), | ||||||
|  |     [Points] INT DEFAULT 10, | ||||||
|  |     [Category] NVARCHAR(50), | ||||||
|  |     [RequiredCount] INT DEFAULT 1, | ||||||
|  |     [RewardTitle] NVARCHAR(100) NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [CharacterAchievements] ( | ||||||
|  |     [CharacterAchievementID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [AchievementID] BIGINT NOT NULL, | ||||||
|  |     [EarnedDate] DATETIME NOT NULL, | ||||||
|  |     [Progress] INT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- NPC and Monster Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [NPCTypes] ( | ||||||
|  |     [NPCTypeID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [TypeName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [IsFriendly] BIT DEFAULT 1, | ||||||
|  |     [CanTrade] BIT DEFAULT 0, | ||||||
|  |     [CanGiveQuests] BIT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [NPCs] ( | ||||||
|  |     [NPCID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [NPCName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [NPCTypeID] BIGINT NOT NULL, | ||||||
|  |     [LocationCityID] BIGINT NOT NULL, | ||||||
|  |     [Health] INT DEFAULT 100, | ||||||
|  |     [Level] INT DEFAULT 1, | ||||||
|  |     [DialogueText] NVARCHAR(MAX), | ||||||
|  |     [RespawnTime] INT DEFAULT 300 -- seconds | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Monsters] ( | ||||||
|  |     [MonsterID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [MonsterName] NVARCHAR(100) NOT NULL, | ||||||
|  |     [MonsterType] NVARCHAR(50), -- 'Beast', 'Undead', 'Dragon', 'Elemental', 'Demon' | ||||||
|  |     [Level] INT DEFAULT 1, | ||||||
|  |     [Health] INT DEFAULT 100, | ||||||
|  |     [Damage] INT DEFAULT 10, | ||||||
|  |     [Defense] INT DEFAULT 5, | ||||||
|  |     [ExperienceReward] INT DEFAULT 50, | ||||||
|  |     [GoldDrop] DECIMAL(10, 2) DEFAULT 5.00, | ||||||
|  |     [SpawnRegionID] BIGINT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [MonsterLoot] ( | ||||||
|  |     [LootID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [MonsterID] BIGINT NOT NULL, | ||||||
|  |     [ItemID] BIGINT NOT NULL, | ||||||
|  |     [DropChance] DECIMAL(5, 2) DEFAULT 10.00, -- percentage | ||||||
|  |     [MinQuantity] INT DEFAULT 1, | ||||||
|  |     [MaxQuantity] INT DEFAULT 1 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Combat and PvP Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [BattleTypes] ( | ||||||
|  |     [BattleTypeID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [TypeName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [MinParticipants] INT DEFAULT 2, | ||||||
|  |     [MaxParticipants] INT DEFAULT 2, | ||||||
|  |     [AllowTeams] BIT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Battles] ( | ||||||
|  |     [BattleID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [BattleTypeID] BIGINT NOT NULL, | ||||||
|  |     [StartTime] DATETIME NOT NULL, | ||||||
|  |     [EndTime] DATETIME NULL, | ||||||
|  |     [LocationCityID] BIGINT NOT NULL, | ||||||
|  |     [WinnerCharacterID] BIGINT NULL, | ||||||
|  |     [TotalDamageDealt] BIGINT DEFAULT 0 | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [BattleParticipants] ( | ||||||
|  |     [ParticipantID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [BattleID] BIGINT NOT NULL, | ||||||
|  |     [CharacterID] BIGINT NOT NULL, | ||||||
|  |     [TeamNumber] INT DEFAULT 0, | ||||||
|  |     [DamageDealt] INT DEFAULT 0, | ||||||
|  |     [DamageTaken] INT DEFAULT 0, | ||||||
|  |     [HealingDone] INT DEFAULT 0, | ||||||
|  |     [KillCount] INT DEFAULT 0, | ||||||
|  |     [DeathCount] INT DEFAULT 0, | ||||||
|  |     [FinalPlacement] INT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Economy Tables | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | CREATE TABLE [Currencies] ( | ||||||
|  |     [CurrencyID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [CurrencyName] NVARCHAR(50) NOT NULL UNIQUE, | ||||||
|  |     [ExchangeRate] DECIMAL(10, 4) DEFAULT 1.0000, -- relative to gold | ||||||
|  |     [IssuingKingdomID] BIGINT NOT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [MarketListings] ( | ||||||
|  |     [ListingID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [SellerCharacterID] BIGINT NOT NULL, | ||||||
|  |     [ItemID] BIGINT NOT NULL, | ||||||
|  |     [Quantity] INT DEFAULT 1, | ||||||
|  |     [PricePerUnit] DECIMAL(10, 2) NOT NULL, | ||||||
|  |     [CurrencyID] BIGINT NOT NULL, | ||||||
|  |     [ListedDate] DATETIME NOT NULL, | ||||||
|  |     [ExpiryDate] DATETIME NOT NULL, | ||||||
|  |     [Status] NVARCHAR(20) DEFAULT 'Active' | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | CREATE TABLE [Transactions] ( | ||||||
|  |     [TransactionID] BIGINT IDENTITY(1,1) PRIMARY KEY, | ||||||
|  |     [BuyerCharacterID] BIGINT NOT NULL, | ||||||
|  |     [SellerCharacterID] BIGINT NOT NULL, | ||||||
|  |     [ItemID] BIGINT NOT NULL, | ||||||
|  |     [Quantity] INT DEFAULT 1, | ||||||
|  |     [TotalPrice] DECIMAL(10, 2) NOT NULL, | ||||||
|  |     [CurrencyID] BIGINT NOT NULL, | ||||||
|  |     [TransactionDate] DATETIME NOT NULL | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- ============================================= | ||||||
|  | -- Foreign Key Constraints (Without Schema Prefix) | ||||||
|  | -- Testing the fix for single-schema foreign key parsing | ||||||
|  | -- ============================================= | ||||||
|  |  | ||||||
|  | -- Kingdom Relationships | ||||||
|  | ALTER TABLE [Regions] ADD CONSTRAINT [FK_Regions_Kingdoms]  | ||||||
|  |     FOREIGN KEY ([KingdomID]) REFERENCES [Kingdoms]([KingdomID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Cities] ADD CONSTRAINT [FK_Cities_Regions]  | ||||||
|  |     FOREIGN KEY ([RegionID]) REFERENCES [Regions]([RegionID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Castles] ADD CONSTRAINT [FK_Castles_Cities]  | ||||||
|  |     FOREIGN KEY ([CityID]) REFERENCES [Cities]([CityID]); | ||||||
|  |  | ||||||
|  | -- Character Relationships | ||||||
|  | ALTER TABLE [Characters] ADD CONSTRAINT [FK_Characters_Classes]  | ||||||
|  |     FOREIGN KEY ([ClassID]) REFERENCES [CharacterClasses]([ClassID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Characters] ADD CONSTRAINT [FK_Characters_Cities]  | ||||||
|  |     FOREIGN KEY ([HomeCityID]) REFERENCES [Cities]([CityID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterSkills] ADD CONSTRAINT [FK_CharacterSkills_Classes]  | ||||||
|  |     FOREIGN KEY ([RequiredClassID]) REFERENCES [CharacterClasses]([ClassID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterSkillMapping] ADD CONSTRAINT [FK_SkillMapping_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterSkillMapping] ADD CONSTRAINT [FK_SkillMapping_Skills]  | ||||||
|  |     FOREIGN KEY ([SkillID]) REFERENCES [CharacterSkills]([SkillID]); | ||||||
|  |  | ||||||
|  | -- Guild Relationships | ||||||
|  | ALTER TABLE [Guilds] ADD CONSTRAINT [FK_Guilds_GuildTypes]  | ||||||
|  |     FOREIGN KEY ([GuildTypeID]) REFERENCES [GuildTypes]([GuildTypeID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Guilds] ADD CONSTRAINT [FK_Guilds_Cities]  | ||||||
|  |     FOREIGN KEY ([HeadquartersCityID]) REFERENCES [Cities]([CityID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Guilds] ADD CONSTRAINT [FK_Guilds_GuildMaster]  | ||||||
|  |     FOREIGN KEY ([GuildMasterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [GuildMembers] ADD CONSTRAINT [FK_GuildMembers_Guilds]  | ||||||
|  |     FOREIGN KEY ([GuildID]) REFERENCES [Guilds]([GuildID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [GuildMembers] ADD CONSTRAINT [FK_GuildMembers_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [GuildQuests] ADD CONSTRAINT [FK_GuildQuests_Guilds]  | ||||||
|  |     FOREIGN KEY ([GuildID]) REFERENCES [Guilds]([GuildID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [GuildQuests] ADD CONSTRAINT [FK_GuildQuests_QuestGiver]  | ||||||
|  |     FOREIGN KEY ([QuestGiverID]) REFERENCES [NPCs]([NPCID]); | ||||||
|  |  | ||||||
|  | -- Item Relationships | ||||||
|  | ALTER TABLE [Items] ADD CONSTRAINT [FK_Items_Categories]  | ||||||
|  |     FOREIGN KEY ([CategoryID]) REFERENCES [ItemCategories]([CategoryID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Items] ADD CONSTRAINT [FK_Items_RequiredClass]  | ||||||
|  |     FOREIGN KEY ([RequiredClassID]) REFERENCES [CharacterClasses]([ClassID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Weapons] ADD CONSTRAINT [FK_Weapons_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Armor] ADD CONSTRAINT [FK_Armor_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterInventory] ADD CONSTRAINT [FK_Inventory_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterInventory] ADD CONSTRAINT [FK_Inventory_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | -- Magic Relationships | ||||||
|  | ALTER TABLE [Spells] ADD CONSTRAINT [FK_Spells_Schools]  | ||||||
|  |     FOREIGN KEY ([SchoolID]) REFERENCES [MagicSchools]([SchoolID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [SpellBooks] ADD CONSTRAINT [FK_SpellBooks_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [SpellBooks] ADD CONSTRAINT [FK_SpellBooks_Spells]  | ||||||
|  |     FOREIGN KEY ([SpellID]) REFERENCES [Spells]([SpellID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Enchantments] ADD CONSTRAINT [FK_Enchantments_Spells]  | ||||||
|  |     FOREIGN KEY ([RequiredSpellID]) REFERENCES [Spells]([SpellID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [ItemEnchantments] ADD CONSTRAINT [FK_ItemEnchantments_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [ItemEnchantments] ADD CONSTRAINT [FK_ItemEnchantments_Enchantments]  | ||||||
|  |     FOREIGN KEY ([EnchantmentID]) REFERENCES [Enchantments]([EnchantmentID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [ItemEnchantments] ADD CONSTRAINT [FK_ItemEnchantments_Characters]  | ||||||
|  |     FOREIGN KEY ([AppliedByCharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | -- Quest Relationships | ||||||
|  | ALTER TABLE [QuestLines] ADD CONSTRAINT [FK_QuestLines_FinalReward]  | ||||||
|  |     FOREIGN KEY ([FinalRewardItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Quests] ADD CONSTRAINT [FK_Quests_QuestLines]  | ||||||
|  |     FOREIGN KEY ([QuestLineID]) REFERENCES [QuestLines]([QuestLineID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Quests] ADD CONSTRAINT [FK_Quests_QuestGiver]  | ||||||
|  |     FOREIGN KEY ([QuestGiverNPCID]) REFERENCES [NPCs]([NPCID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Quests] ADD CONSTRAINT [FK_Quests_Prerequisites]  | ||||||
|  |     FOREIGN KEY ([RequiredQuestID]) REFERENCES [Quests]([QuestID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Quests] ADD CONSTRAINT [FK_Quests_RewardItem]  | ||||||
|  |     FOREIGN KEY ([RewardItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterQuests] ADD CONSTRAINT [FK_CharacterQuests_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterQuests] ADD CONSTRAINT [FK_CharacterQuests_Quests]  | ||||||
|  |     FOREIGN KEY ([QuestID]) REFERENCES [Quests]([QuestID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterAchievements] ADD CONSTRAINT [FK_CharAchievements_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [CharacterAchievements] ADD CONSTRAINT [FK_CharAchievements_Achievements]  | ||||||
|  |     FOREIGN KEY ([AchievementID]) REFERENCES [Achievements]([AchievementID]); | ||||||
|  |  | ||||||
|  | -- NPC and Monster Relationships | ||||||
|  | ALTER TABLE [NPCs] ADD CONSTRAINT [FK_NPCs_Types]  | ||||||
|  |     FOREIGN KEY ([NPCTypeID]) REFERENCES [NPCTypes]([NPCTypeID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [NPCs] ADD CONSTRAINT [FK_NPCs_Cities]  | ||||||
|  |     FOREIGN KEY ([LocationCityID]) REFERENCES [Cities]([CityID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Monsters] ADD CONSTRAINT [FK_Monsters_Regions]  | ||||||
|  |     FOREIGN KEY ([SpawnRegionID]) REFERENCES [Regions]([RegionID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [MonsterLoot] ADD CONSTRAINT [FK_MonsterLoot_Monsters]  | ||||||
|  |     FOREIGN KEY ([MonsterID]) REFERENCES [Monsters]([MonsterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [MonsterLoot] ADD CONSTRAINT [FK_MonsterLoot_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | -- Battle Relationships | ||||||
|  | ALTER TABLE [Battles] ADD CONSTRAINT [FK_Battles_Types]  | ||||||
|  |     FOREIGN KEY ([BattleTypeID]) REFERENCES [BattleTypes]([BattleTypeID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Battles] ADD CONSTRAINT [FK_Battles_Cities]  | ||||||
|  |     FOREIGN KEY ([LocationCityID]) REFERENCES [Cities]([CityID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Battles] ADD CONSTRAINT [FK_Battles_Winner]  | ||||||
|  |     FOREIGN KEY ([WinnerCharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [BattleParticipants] ADD CONSTRAINT [FK_BattleParticipants_Battles]  | ||||||
|  |     FOREIGN KEY ([BattleID]) REFERENCES [Battles]([BattleID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [BattleParticipants] ADD CONSTRAINT [FK_BattleParticipants_Characters]  | ||||||
|  |     FOREIGN KEY ([CharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | -- Economy Relationships | ||||||
|  | ALTER TABLE [Currencies] ADD CONSTRAINT [FK_Currencies_Kingdoms]  | ||||||
|  |     FOREIGN KEY ([IssuingKingdomID]) REFERENCES [Kingdoms]([KingdomID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [MarketListings] ADD CONSTRAINT [FK_MarketListings_Seller]  | ||||||
|  |     FOREIGN KEY ([SellerCharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [MarketListings] ADD CONSTRAINT [FK_MarketListings_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [MarketListings] ADD CONSTRAINT [FK_MarketListings_Currency]  | ||||||
|  |     FOREIGN KEY ([CurrencyID]) REFERENCES [Currencies]([CurrencyID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Transactions] ADD CONSTRAINT [FK_Transactions_Buyer]  | ||||||
|  |     FOREIGN KEY ([BuyerCharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Transactions] ADD CONSTRAINT [FK_Transactions_Seller]  | ||||||
|  |     FOREIGN KEY ([SellerCharacterID]) REFERENCES [Characters]([CharacterID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Transactions] ADD CONSTRAINT [FK_Transactions_Items]  | ||||||
|  |     FOREIGN KEY ([ItemID]) REFERENCES [Items]([ItemID]); | ||||||
|  |  | ||||||
|  | ALTER TABLE [Transactions] ADD CONSTRAINT [FK_Transactions_Currency]  | ||||||
|  |     FOREIGN KEY ([CurrencyID]) REFERENCES [Currencies]([CurrencyID]); | ||||||
|  |         `; | ||||||
|  |  | ||||||
|  |         const result = await fromSQLServer(sql); | ||||||
|  |  | ||||||
|  |         // Debug: log table names to see what's parsed | ||||||
|  |         console.log('Tables found:', result.tables.length); | ||||||
|  |         console.log( | ||||||
|  |             'Table names:', | ||||||
|  |             result.tables.map((t) => t.name) | ||||||
|  |         ); | ||||||
|  |  | ||||||
|  |         // Verify correct number of tables | ||||||
|  |         expect(result.tables.length).toBe(37); // Actually 37 tables after counting | ||||||
|  |  | ||||||
|  |         // Verify all tables use default 'dbo' schema | ||||||
|  |         const schemas = new Set(result.tables.map((t) => t.schema)); | ||||||
|  |         expect(schemas.size).toBe(1); | ||||||
|  |         expect(schemas.has('dbo')).toBe(true); | ||||||
|  |  | ||||||
|  |         // Verify correct number of relationships | ||||||
|  |         console.log('Relationships found:', result.relationships.length); | ||||||
|  |         expect(result.relationships.length).toBe(55); // 55 foreign key relationships that can be parsed | ||||||
|  |  | ||||||
|  |         // Verify all relationships have valid source and target table IDs | ||||||
|  |         const validRelationships = result.relationships.filter( | ||||||
|  |             (r) => r.sourceTableId && r.targetTableId | ||||||
|  |         ); | ||||||
|  |         expect(validRelationships.length).toBe(result.relationships.length); | ||||||
|  |  | ||||||
|  |         // Check specific table names exist | ||||||
|  |         const tableNames = result.tables.map((t) => t.name); | ||||||
|  |         expect(tableNames).toContain('Kingdoms'); | ||||||
|  |         expect(tableNames).toContain('Characters'); | ||||||
|  |         expect(tableNames).toContain('Guilds'); | ||||||
|  |         expect(tableNames).toContain('Items'); | ||||||
|  |         expect(tableNames).toContain('Spells'); | ||||||
|  |         expect(tableNames).toContain('Quests'); | ||||||
|  |         expect(tableNames).toContain('Battles'); | ||||||
|  |         expect(tableNames).toContain('Monsters'); | ||||||
|  |  | ||||||
|  |         // Verify some specific relationships exist and are properly linked | ||||||
|  |         const characterToClass = result.relationships.find( | ||||||
|  |             (r) => r.name === 'FK_Characters_Classes' | ||||||
|  |         ); | ||||||
|  |         expect(characterToClass).toBeDefined(); | ||||||
|  |         expect(characterToClass?.sourceTable).toBe('Characters'); | ||||||
|  |         expect(characterToClass?.targetTable).toBe('CharacterClasses'); | ||||||
|  |         expect(characterToClass?.sourceColumn).toBe('ClassID'); | ||||||
|  |         expect(characterToClass?.targetColumn).toBe('ClassID'); | ||||||
|  |  | ||||||
|  |         const guildsToCity = result.relationships.find( | ||||||
|  |             (r) => r.name === 'FK_Guilds_Cities' | ||||||
|  |         ); | ||||||
|  |         expect(guildsToCity).toBeDefined(); | ||||||
|  |         expect(guildsToCity?.sourceTable).toBe('Guilds'); | ||||||
|  |         expect(guildsToCity?.targetTable).toBe('Cities'); | ||||||
|  |  | ||||||
|  |         const inventoryToItems = result.relationships.find( | ||||||
|  |             (r) => r.name === 'FK_Inventory_Items' | ||||||
|  |         ); | ||||||
|  |         expect(inventoryToItems).toBeDefined(); | ||||||
|  |         expect(inventoryToItems?.sourceTable).toBe('CharacterInventory'); | ||||||
|  |         expect(inventoryToItems?.targetTable).toBe('Items'); | ||||||
|  |  | ||||||
|  |         // Check self-referencing relationship | ||||||
|  |         const questPrerequisite = result.relationships.find( | ||||||
|  |             (r) => r.name === 'FK_Quests_Prerequisites' | ||||||
|  |         ); | ||||||
|  |         expect(questPrerequisite).toBeDefined(); | ||||||
|  |         expect(questPrerequisite?.sourceTable).toBe('Quests'); | ||||||
|  |         expect(questPrerequisite?.targetTable).toBe('Quests'); | ||||||
|  |  | ||||||
|  |         // Verify table IDs are correctly linked in relationships | ||||||
|  |         for (const rel of result.relationships) { | ||||||
|  |             const sourceTable = result.tables.find( | ||||||
|  |                 (t) => | ||||||
|  |                     t.name === rel.sourceTable && t.schema === rel.sourceSchema | ||||||
|  |             ); | ||||||
|  |             const targetTable = result.tables.find( | ||||||
|  |                 (t) => | ||||||
|  |                     t.name === rel.targetTable && t.schema === rel.targetSchema | ||||||
|  |             ); | ||||||
|  |  | ||||||
|  |             expect(sourceTable).toBeDefined(); | ||||||
|  |             expect(targetTable).toBeDefined(); | ||||||
|  |             expect(rel.sourceTableId).toBe(sourceTable?.id); | ||||||
|  |             expect(rel.targetTableId).toBe(targetTable?.id); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         console.log('Single-schema test results:'); | ||||||
|  |         console.log('Total tables:', result.tables.length); | ||||||
|  |         console.log('Total relationships:', result.relationships.length); | ||||||
|  |         console.log( | ||||||
|  |             'All relationships properly linked:', | ||||||
|  |             validRelationships.length === result.relationships.length | ||||||
|  |         ); | ||||||
|  |  | ||||||
|  |         // Sample of relationship names for verification | ||||||
|  |         const sampleRelationships = result.relationships | ||||||
|  |             .slice(0, 5) | ||||||
|  |             .map((r) => ({ | ||||||
|  |                 name: r.name, | ||||||
|  |                 source: `${r.sourceTable}.${r.sourceColumn}`, | ||||||
|  |                 target: `${r.targetTable}.${r.targetColumn}`, | ||||||
|  |             })); | ||||||
|  |         console.log('Sample relationships:', sampleRelationships); | ||||||
|  |     }); | ||||||
|  | }); | ||||||
| @@ -162,15 +162,36 @@ function parseAlterTableAddConstraint(statements: string[]): SQLForeignKey[] { | |||||||
|         if (match) { |         if (match) { | ||||||
|             const [ |             const [ | ||||||
|                 , |                 , | ||||||
|                 sourceSchema = 'dbo', |                 sourceSchemaOrTable, | ||||||
|                 sourceTable, |                 sourceTableIfSchema, | ||||||
|                 constraintName, |                 constraintName, | ||||||
|                 sourceColumn, |                 sourceColumn, | ||||||
|                 targetSchema = 'dbo', |                 targetSchemaOrTable, | ||||||
|                 targetTable, |                 targetTableIfSchema, | ||||||
|                 targetColumn, |                 targetColumn, | ||||||
|             ] = match; |             ] = match; | ||||||
|  |  | ||||||
|  |             // Handle both schema.table and just table formats | ||||||
|  |             let sourceSchema = 'dbo'; | ||||||
|  |             let sourceTable = ''; | ||||||
|  |             let targetSchema = 'dbo'; | ||||||
|  |             let targetTable = ''; | ||||||
|  |  | ||||||
|  |             // If second group is empty, first group is the table name | ||||||
|  |             if (!sourceTableIfSchema) { | ||||||
|  |                 sourceTable = sourceSchemaOrTable; | ||||||
|  |             } else { | ||||||
|  |                 sourceSchema = sourceSchemaOrTable; | ||||||
|  |                 sourceTable = sourceTableIfSchema; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             if (!targetTableIfSchema) { | ||||||
|  |                 targetTable = targetSchemaOrTable; | ||||||
|  |             } else { | ||||||
|  |                 targetSchema = targetSchemaOrTable; | ||||||
|  |                 targetTable = targetTableIfSchema; | ||||||
|  |             } | ||||||
|  |  | ||||||
|             fkData.push({ |             fkData.push({ | ||||||
|                 name: constraintName, |                 name: constraintName, | ||||||
|                 sourceTable: sourceTable, |                 sourceTable: sourceTable, | ||||||
|   | |||||||
		Reference in New Issue
	
	Block a user