-- Test schema for MSSQL Reader integration tests -- This script creates a sample database for testing the MSSQL reader USE master; GO -- Drop existing database if it exists IF EXISTS (SELECT 1 FROM sys.databases WHERE name = 'RelSpecTest') BEGIN ALTER DATABASE RelSpecTest SET SINGLE_USER WITH ROLLBACK IMMEDIATE; DROP DATABASE RelSpecTest; END GO -- Create test database CREATE DATABASE RelSpecTest; GO USE RelSpecTest; GO -- Create schemas CREATE SCHEMA [public]; GO CREATE SCHEMA [auth]; GO -- Create tables in public schema CREATE TABLE [public].[users] ( [id] INT IDENTITY(1,1) NOT NULL, [email] NVARCHAR(255) NOT NULL, [username] NVARCHAR(100) NOT NULL, [created_at] DATETIME2 NOT NULL DEFAULT GETDATE(), [updated_at] DATETIME2 NULL, [is_active] BIT NOT NULL DEFAULT 1, PRIMARY KEY ([id]), UNIQUE ([email]), UNIQUE ([username]) ); GO CREATE TABLE [public].[posts] ( [id] INT IDENTITY(1,1) NOT NULL, [user_id] INT NOT NULL, [title] NVARCHAR(255) NOT NULL, [content] NVARCHAR(MAX) NOT NULL, [published_at] DATETIME2 NULL, [created_at] DATETIME2 NOT NULL DEFAULT GETDATE(), PRIMARY KEY ([id]) ); GO CREATE TABLE [public].[comments] ( [id] INT IDENTITY(1,1) NOT NULL, [post_id] INT NOT NULL, [user_id] INT NOT NULL, [content] NVARCHAR(MAX) NOT NULL, [created_at] DATETIME2 NOT NULL DEFAULT GETDATE(), PRIMARY KEY ([id]) ); GO -- Create tables in auth schema CREATE TABLE [auth].[roles] ( [id] INT IDENTITY(1,1) NOT NULL, [name] NVARCHAR(100) NOT NULL, [description] NVARCHAR(MAX) NULL, PRIMARY KEY ([id]), UNIQUE ([name]) ); GO CREATE TABLE [auth].[user_roles] ( [id] INT IDENTITY(1,1) NOT NULL, [user_id] INT NOT NULL, [role_id] INT NOT NULL, PRIMARY KEY ([id]), UNIQUE ([user_id], [role_id]) ); GO -- Add foreign keys ALTER TABLE [public].[posts] ADD CONSTRAINT [FK_posts_users] FOREIGN KEY ([user_id]) REFERENCES [public].[users] ([id]) ON DELETE CASCADE ON UPDATE NO ACTION; GO ALTER TABLE [public].[comments] ADD CONSTRAINT [FK_comments_posts] FOREIGN KEY ([post_id]) REFERENCES [public].[posts] ([id]) ON DELETE CASCADE ON UPDATE NO ACTION; GO ALTER TABLE [public].[comments] ADD CONSTRAINT [FK_comments_users] FOREIGN KEY ([user_id]) REFERENCES [public].[users] ([id]) ON DELETE CASCADE ON UPDATE NO ACTION; GO ALTER TABLE [auth].[user_roles] ADD CONSTRAINT [FK_user_roles_users] FOREIGN KEY ([user_id]) REFERENCES [public].[users] ([id]) ON DELETE CASCADE ON UPDATE NO ACTION; GO ALTER TABLE [auth].[user_roles] ADD CONSTRAINT [FK_user_roles_roles] FOREIGN KEY ([role_id]) REFERENCES [auth].[roles] ([id]) ON DELETE CASCADE ON UPDATE NO ACTION; GO -- Create indexes CREATE INDEX [IDX_users_email] ON [public].[users] ([email]); GO CREATE INDEX [IDX_posts_user_id] ON [public].[posts] ([user_id]); GO CREATE INDEX [IDX_comments_post_id] ON [public].[comments] ([post_id]); GO CREATE INDEX [IDX_comments_user_id] ON [public].[comments] ([user_id]); GO -- Add extended properties (comments) EXEC sp_addextendedproperty @name = 'MS_Description', @value = 'User accounts table', @level0type = 'SCHEMA', @level0name = 'public', @level1type = 'TABLE', @level1name = 'users'; GO EXEC sp_addextendedproperty @name = 'MS_Description', @value = 'User unique identifier', @level0type = 'SCHEMA', @level0name = 'public', @level1type = 'TABLE', @level1name = 'users', @level2type = 'COLUMN', @level2name = 'id'; GO EXEC sp_addextendedproperty @name = 'MS_Description', @value = 'User email address', @level0type = 'SCHEMA', @level0name = 'public', @level1type = 'TABLE', @level1name = 'users', @level2type = 'COLUMN', @level2name = 'email'; GO EXEC sp_addextendedproperty @name = 'MS_Description', @value = 'Blog posts table', @level0type = 'SCHEMA', @level0name = 'public', @level1type = 'TABLE', @level1name = 'posts'; GO EXEC sp_addextendedproperty @name = 'MS_Description', @value = 'User roles mapping table', @level0type = 'SCHEMA', @level0name = 'auth', @level1type = 'TABLE', @level1name = 'user_roles'; GO -- Add check constraint ALTER TABLE [public].[users] ADD CONSTRAINT [CK_users_email_format] CHECK (LEN(email) > 0 AND email LIKE '%@%.%'); GO -- Verify schema was created SELECT SCHEMA_NAME(s.schema_id) as [Schema], t.name as [Table], COUNT(c.column_id) as [ColumnCount] FROM sys.tables t INNER JOIN sys.schemas s ON t.schema_id = s.schema_id LEFT JOIN sys.columns c ON t.object_id = c.object_id WHERE SCHEMA_NAME(s.schema_id) IN ('public', 'auth') GROUP BY SCHEMA_NAME(s.schema_id), t.name ORDER BY [Schema], [Table]; GO