-- MS SQL Server Table Creation for Weather Connect -- Run this as weather_user or a user with CREATE TABLE privileges -- This creates the same schema structure as the Oracle implementation USE WeatherDB; GO -- 1. Create weather_data table (main table) IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'dbo.weather_data') AND type = 'U') BEGIN CREATE TABLE dbo.weather_data ( id BIGINT IDENTITY(1,1) PRIMARY KEY, timestamp DATETIME2(6) NOT NULL, topic NVARCHAR(255) NOT NULL, location NVARCHAR(100), temperature DECIMAL(5,2), humidity DECIMAL(5,2), pressure DECIMAL(7,2), wind_speed DECIMAL(5,2), wind_direction DECIMAL(5,2), rainfall DECIMAL(6,2), created_at DATETIME2(6) DEFAULT GETDATE() ); PRINT 'Table weather_data created successfully.'; END ELSE BEGIN PRINT 'Table weather_data already exists.'; END GO -- 2. Create raw_data table (stores raw JSON data) IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'dbo.raw_data') AND type = 'U') BEGIN CREATE TABLE dbo.raw_data ( weather_data_id BIGINT PRIMARY KEY, raw_data NVARCHAR(MAX), CONSTRAINT fk_raw_data_weather_data FOREIGN KEY (weather_data_id) REFERENCES dbo.weather_data (id) ON DELETE CASCADE, CONSTRAINT chk_raw_data_json CHECK (ISJSON(raw_data) = 1) ); PRINT 'Table raw_data created successfully.'; END ELSE BEGIN PRINT 'Table raw_data already exists.'; END GO -- 3. Create index on timestamp and topic for better query performance IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'idx_weather_data_ts_topic') BEGIN CREATE INDEX idx_weather_data_ts_topic ON dbo.weather_data (timestamp, topic); PRINT 'Index idx_weather_data_ts_topic created successfully.'; END ELSE BEGIN PRINT 'Index idx_weather_data_ts_topic already exists.'; END GO -- 4. Verify table creation SELECT t.name AS TableName, c.name AS ColumnName, ty.name AS DataType, c.max_length AS MaxLength, c.precision AS Precision, c.scale AS Scale, c.is_nullable AS IsNullable, c.is_identity AS IsIdentity FROM sys.tables t INNER JOIN sys.columns c ON t.object_id = c.object_id INNER JOIN sys.types ty ON c.user_type_id = ty.user_type_id WHERE t.name IN ('weather_data', 'raw_data') ORDER BY t.name, c.column_id; GO -- 5. Display constraints SELECT fk.name AS ConstraintName, OBJECT_NAME(fk.parent_object_id) AS TableName, COL_NAME(fc.parent_object_id, fc.parent_column_id) AS ColumnName, OBJECT_NAME(fk.referenced_object_id) AS ReferencedTable, COL_NAME(fc.referenced_object_id, fc.referenced_column_id) AS ReferencedColumn FROM sys.foreign_keys AS fk INNER JOIN sys.foreign_key_columns AS fc ON fk.object_id = fc.constraint_object_id WHERE fk.name = 'fk_raw_data_weather_data'; GO -- 6. Display indexes SELECT i.name AS IndexName, t.name AS TableName, i.type_desc AS IndexType, COL_NAME(ic.object_id, ic.column_id) AS ColumnName FROM sys.indexes i INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id INNER JOIN sys.tables t ON i.object_id = t.object_id WHERE t.name = 'weather_data' AND i.name = 'idx_weather_data_ts_topic' ORDER BY ic.key_ordinal; GO PRINT 'Tables created successfully and ready for use.'; PRINT 'Schema matches Oracle implementation with two-table structure:'; PRINT ' - weather_data: Main weather metrics table'; PRINT ' - raw_data: Raw JSON data table with foreign key relationship'; GO