MSSQL Support
This commit is contained in:
48
mssql-setup/01_create_database.sql
Normal file
48
mssql-setup/01_create_database.sql
Normal file
@@ -0,0 +1,48 @@
|
||||
-- MS SQL Server Database Setup for Weather Connect
|
||||
-- Run this as a user with CREATE DATABASE privileges (e.g., sa or sysadmin role)
|
||||
-- This script creates the database and sets it up for use with Always On Availability Groups
|
||||
|
||||
-- 1. Check current server and database status
|
||||
SELECT @@SERVERNAME AS ServerName, @@VERSION AS SQLVersion;
|
||||
GO
|
||||
|
||||
-- 2. Create the database
|
||||
-- Note: For Always On Availability Groups, the database must be created with FULL recovery model
|
||||
IF NOT EXISTS (SELECT name FROM sys.databases WHERE name = 'WeatherDB')
|
||||
BEGIN
|
||||
CREATE DATABASE WeatherDB;
|
||||
PRINT 'Database WeatherDB created successfully.';
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
PRINT 'Database WeatherDB already exists.';
|
||||
END
|
||||
GO
|
||||
|
||||
-- 3. Set recovery model to FULL (required for Always On AG)
|
||||
ALTER DATABASE WeatherDB SET RECOVERY FULL;
|
||||
GO
|
||||
|
||||
-- 4. Verify database creation and settings
|
||||
SELECT
|
||||
name AS DatabaseName,
|
||||
recovery_model_desc AS RecoveryModel,
|
||||
state_desc AS State,
|
||||
compatibility_level AS CompatibilityLevel
|
||||
FROM sys.databases
|
||||
WHERE name = 'WeatherDB';
|
||||
GO
|
||||
|
||||
-- 5. Take a full backup (required before adding to Always On AG)
|
||||
-- Modify the backup path as needed for your environment
|
||||
BACKUP DATABASE WeatherDB
|
||||
TO DISK = 'WeatherDB_Full.bak'
|
||||
WITH FORMAT, INIT, NAME = 'WeatherDB Full Backup';
|
||||
GO
|
||||
|
||||
PRINT 'Database WeatherDB is ready for use.';
|
||||
PRINT 'If you plan to add this database to an Always On Availability Group:';
|
||||
PRINT ' 1. Ensure full backup has been taken (done above)';
|
||||
PRINT ' 2. Take a transaction log backup';
|
||||
PRINT ' 3. Add the database to your AG using the AG wizard or T-SQL';
|
||||
GO
|
||||
80
mssql-setup/02_create_user.sql
Normal file
80
mssql-setup/02_create_user.sql
Normal file
@@ -0,0 +1,80 @@
|
||||
-- MS SQL Server User Setup for Weather Connect
|
||||
-- Run this as a user with appropriate privileges (e.g., sa or sysadmin role)
|
||||
-- This creates a SQL Server login and database user
|
||||
|
||||
USE master;
|
||||
GO
|
||||
|
||||
-- 1. Create SQL Server Login (if it doesn't exist)
|
||||
IF NOT EXISTS (SELECT name FROM sys.server_principals WHERE name = 'weather_user')
|
||||
BEGIN
|
||||
CREATE LOGIN weather_user WITH PASSWORD = 'Weather123!';
|
||||
PRINT 'Login weather_user created successfully.';
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
PRINT 'Login weather_user already exists.';
|
||||
END
|
||||
GO
|
||||
|
||||
-- 2. Switch to the WeatherDB database
|
||||
USE WeatherDB;
|
||||
GO
|
||||
|
||||
-- 3. Create database user for the login (if it doesn't exist)
|
||||
IF NOT EXISTS (SELECT name FROM sys.database_principals WHERE name = 'weather_user')
|
||||
BEGIN
|
||||
CREATE USER weather_user FOR LOGIN weather_user;
|
||||
PRINT 'User weather_user created successfully in WeatherDB.';
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
PRINT 'User weather_user already exists in WeatherDB.';
|
||||
END
|
||||
GO
|
||||
|
||||
-- 4. Grant necessary permissions to the user
|
||||
-- Grant db_datareader and db_datawriter roles
|
||||
ALTER ROLE db_datareader ADD MEMBER weather_user;
|
||||
ALTER ROLE db_datawriter ADD MEMBER weather_user;
|
||||
GO
|
||||
|
||||
-- Grant DDL permissions to create tables and indexes
|
||||
GRANT CREATE TABLE TO weather_user;
|
||||
GRANT CREATE VIEW TO weather_user;
|
||||
GRANT ALTER ON SCHEMA::dbo TO weather_user;
|
||||
GO
|
||||
|
||||
-- 5. Verify user and permissions
|
||||
SELECT
|
||||
dp.name AS UserName,
|
||||
dp.type_desc AS UserType,
|
||||
sp.name AS LoginName
|
||||
FROM sys.database_principals dp
|
||||
LEFT JOIN sys.server_principals sp ON dp.sid = sp.sid
|
||||
WHERE dp.name = 'weather_user';
|
||||
GO
|
||||
|
||||
-- Display granted permissions
|
||||
SELECT
|
||||
USER_NAME(grantee_principal_id) AS UserName,
|
||||
permission_name,
|
||||
state_desc
|
||||
FROM sys.database_permissions
|
||||
WHERE USER_NAME(grantee_principal_id) = 'weather_user'
|
||||
AND permission_name IN ('CREATE TABLE', 'CREATE VIEW', 'ALTER')
|
||||
ORDER BY permission_name;
|
||||
GO
|
||||
|
||||
-- Display role memberships
|
||||
SELECT
|
||||
USER_NAME(drm.member_principal_id) AS UserName,
|
||||
USER_NAME(drm.role_principal_id) AS RoleName
|
||||
FROM sys.database_role_members drm
|
||||
WHERE USER_NAME(drm.member_principal_id) = 'weather_user';
|
||||
GO
|
||||
|
||||
PRINT 'User weather_user is ready to use.';
|
||||
PRINT 'Connection string example:';
|
||||
PRINT 'Server=your_server;Database=WeatherDB;User Id=weather_user;Password=Weather123!;';
|
||||
GO
|
||||
113
mssql-setup/03_create_tables.sql
Normal file
113
mssql-setup/03_create_tables.sql
Normal file
@@ -0,0 +1,113 @@
|
||||
-- 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
|
||||
283
mssql-setup/README.md
Normal file
283
mssql-setup/README.md
Normal file
@@ -0,0 +1,283 @@
|
||||
# MS SQL Server Setup for Weather Connect
|
||||
|
||||
This directory contains setup scripts for configuring Microsoft SQL Server to work with the Weather Connect application. The schema mirrors the Oracle implementation with a two-table structure.
|
||||
|
||||
## Prerequisites
|
||||
|
||||
- Microsoft SQL Server 2017 or later
|
||||
- SQL Server Management Studio (SSMS) or Azure Data Studio (optional but recommended)
|
||||
- Appropriate permissions to create databases and users
|
||||
- For Always On Availability Groups: SQL Server Enterprise Edition
|
||||
|
||||
## Database Schema Overview
|
||||
|
||||
The database consists of two tables:
|
||||
|
||||
1. **weather_data** - Main table storing weather measurements
|
||||
- `id` (BIGINT, IDENTITY, PRIMARY KEY)
|
||||
- `timestamp` (DATETIME2(6))
|
||||
- `topic` (NVARCHAR(255))
|
||||
- `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))
|
||||
|
||||
2. **raw_data** - Table storing raw JSON data
|
||||
- `weather_data_id` (BIGINT, PRIMARY KEY, FOREIGN KEY)
|
||||
- `raw_data` (NVARCHAR(MAX) with JSON validation)
|
||||
|
||||
## Setup Instructions
|
||||
|
||||
### Standard SQL Server Setup
|
||||
|
||||
Run the scripts in order:
|
||||
|
||||
#### 1. Create Database
|
||||
|
||||
```bash
|
||||
sqlcmd -S your_server -U sa -P your_password -i 01_create_database.sql
|
||||
```
|
||||
|
||||
Or in SSMS/Azure Data Studio, open and execute `01_create_database.sql`.
|
||||
|
||||
This script:
|
||||
- Creates the `WeatherDB` database
|
||||
- Sets the recovery model to FULL (required for Always On AG)
|
||||
- Takes a full backup
|
||||
|
||||
#### 2. Create User and Grant Permissions
|
||||
|
||||
```bash
|
||||
sqlcmd -S your_server -U sa -P your_password -i 02_create_user.sql
|
||||
```
|
||||
|
||||
This script:
|
||||
- Creates SQL Server login `weather_user` with password `Weather123!`
|
||||
- Creates database user in WeatherDB
|
||||
- Grants necessary permissions (db_datareader, db_datawriter, CREATE TABLE, etc.)
|
||||
|
||||
**Security Note:** Change the default password in production!
|
||||
|
||||
#### 3. Create Tables
|
||||
|
||||
```bash
|
||||
sqlcmd -S your_server -U weather_user -P Weather123! -d WeatherDB -i 03_create_tables.sql
|
||||
```
|
||||
|
||||
This script:
|
||||
- Creates `weather_data` table with indexes
|
||||
- Creates `raw_data` table with foreign key constraint
|
||||
- Adds JSON validation constraint on `raw_data.raw_data` column
|
||||
|
||||
Alternatively, the application can create tables automatically on first run if the user has appropriate permissions.
|
||||
|
||||
## Always On Availability Group Setup
|
||||
|
||||
If you're using SQL Server Always On Availability Groups for high availability:
|
||||
|
||||
### Prerequisites
|
||||
- Windows Server Failover Clustering (WSFC) configured
|
||||
- Always On Availability Groups enabled on all SQL Server instances
|
||||
- Full backup of the database taken (handled by `01_create_database.sql`)
|
||||
|
||||
### Steps to Add Database to AG
|
||||
|
||||
1. **Take a transaction log backup** (after running the setup scripts):
|
||||
|
||||
```sql
|
||||
USE master;
|
||||
GO
|
||||
BACKUP LOG WeatherDB
|
||||
TO DISK = '/var/opt/mssql/data/WeatherDB_Log.trk'
|
||||
WITH FORMAT, INIT, NAME = 'WeatherDB Log Backup';
|
||||
GO
|
||||
```
|
||||
|
||||
2. **Add database to Availability Group** (on primary replica):
|
||||
|
||||
```sql
|
||||
ALTER AVAILABILITY GROUP AAGONE ADD DATABASE WeatherDB;
|
||||
GO
|
||||
```
|
||||
|
||||
3. **Restore on secondary replicas**:
|
||||
|
||||
For each secondary replica, restore the database with NORECOVERY:
|
||||
|
||||
```sql
|
||||
-- On each secondary replica
|
||||
RESTORE DATABASE WeatherDB
|
||||
FROM DISK = 'WeatherDB_Full.bak'
|
||||
WITH NORECOVERY;
|
||||
GO
|
||||
|
||||
RESTORE LOG WeatherDB
|
||||
FROM DISK = '/path/to/WeatherDB_Log.trk'
|
||||
WITH NORECOVERY;
|
||||
GO
|
||||
|
||||
-- Join the database to the AG
|
||||
ALTER DATABASE WeatherDB SET HADR AVAILABILITY GROUP = AAGONE;
|
||||
GO
|
||||
```
|
||||
|
||||
### Connection String for AG
|
||||
|
||||
When connecting to an Always On Availability Group, use the listener name:
|
||||
|
||||
```
|
||||
Server=AG_Listener_Name,1433;Database=WeatherDB;User Id=weather_user;Password=Weather123!;
|
||||
ApplicationIntent=ReadWrite;MultiSubnetFailover=True;
|
||||
```
|
||||
|
||||
## Application Configuration
|
||||
|
||||
Update your `.env` file to use MS SQL Server:
|
||||
|
||||
```env
|
||||
# Database Configuration - MS SQL Server
|
||||
DB_TYPE=mssql
|
||||
DB_HOST=your_sql_server # Or AG listener name
|
||||
DB_PORT=1433
|
||||
DB_NAME=WeatherDB
|
||||
DB_USERNAME=weather_user
|
||||
DB_PASSWORD=Weather123!
|
||||
|
||||
# MS SQL specific
|
||||
MSSQL_DRIVER=ODBC Driver 17 for SQL Server
|
||||
```
|
||||
|
||||
### ODBC Driver Installation
|
||||
|
||||
#### Ubuntu/Debian:
|
||||
```bash
|
||||
curl https://packages.microsoft.com/keys/microsoft.asc | apt-key add -
|
||||
curl https://packages.microsoft.com/config/ubuntu/$(lsb_release -rs)/prod.list > /etc/apt/sources.list.d/mssql-release.list
|
||||
apt-get update
|
||||
ACCEPT_EULA=Y apt-get install -y msodbcsql17
|
||||
```
|
||||
|
||||
#### Red Hat/CentOS:
|
||||
```bash
|
||||
curl https://packages.microsoft.com/config/rhel/8/prod.repo > /etc/yum.repos.d/mssql-release.repo
|
||||
yum remove unixODBC-utf16 unixODBC-utf16-devel
|
||||
ACCEPT_EULA=Y yum install -y msodbcsql17
|
||||
```
|
||||
|
||||
#### Windows:
|
||||
Download and install from: https://docs.microsoft.com/en-us/sql/connect/odbc/download-odbc-driver-for-sql-server
|
||||
|
||||
## Verification
|
||||
|
||||
After setup, verify the tables were created:
|
||||
|
||||
```sql
|
||||
USE WeatherDB;
|
||||
GO
|
||||
|
||||
-- Check tables
|
||||
SELECT * FROM INFORMATION_SCHEMA.TABLES
|
||||
WHERE TABLE_NAME IN ('weather_data', 'raw_data');
|
||||
|
||||
-- Check foreign keys
|
||||
SELECT * FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS
|
||||
WHERE CONSTRAINT_NAME = 'fk_raw_data_weather_data';
|
||||
|
||||
-- Check indexes
|
||||
SELECT * FROM sys.indexes
|
||||
WHERE object_id = OBJECT_ID('weather_data');
|
||||
```
|
||||
|
||||
## Testing
|
||||
|
||||
Test the connection from the application:
|
||||
|
||||
```bash
|
||||
# Start the application
|
||||
python src/wxconnect/main.py
|
||||
```
|
||||
|
||||
The application should:
|
||||
1. Connect to MS SQL Server
|
||||
2. Create tables if they don't exist (or verify existing tables)
|
||||
3. Start receiving MQTT messages
|
||||
4. Insert data into both `weather_data` and `raw_data` tables
|
||||
|
||||
## Troubleshooting
|
||||
|
||||
### Connection Issues
|
||||
|
||||
1. **Check SQL Server is listening on TCP/IP:**
|
||||
- SQL Server Configuration Manager → SQL Server Network Configuration → Protocols
|
||||
- Enable TCP/IP protocol
|
||||
- Restart SQL Server service
|
||||
|
||||
2. **Firewall rules:**
|
||||
```bash
|
||||
# Linux
|
||||
sudo firewall-cmd --add-port=1433/tcp --permanent
|
||||
sudo firewall-cmd --reload
|
||||
|
||||
# Windows
|
||||
New-NetFirewallRule -DisplayName "SQL Server" -Direction Inbound -Protocol TCP -LocalPort 1433 -Action Allow
|
||||
```
|
||||
|
||||
3. **Test connection with sqlcmd:**
|
||||
```bash
|
||||
sqlcmd -S your_server,1433 -U weather_user -P Weather123! -d WeatherDB
|
||||
```
|
||||
|
||||
### Permission Issues
|
||||
|
||||
If the application can't create tables, grant explicit permissions:
|
||||
|
||||
```sql
|
||||
USE WeatherDB;
|
||||
GO
|
||||
GRANT CREATE TABLE TO weather_user;
|
||||
GRANT ALTER ON SCHEMA::dbo TO weather_user;
|
||||
GO
|
||||
```
|
||||
|
||||
### Always On AG Issues
|
||||
|
||||
1. **Database not synchronizing:**
|
||||
- Check AG health: `SELECT * FROM sys.dm_hadr_database_replica_states;`
|
||||
- Verify network connectivity between replicas
|
||||
- Check SQL Server error log
|
||||
|
||||
2. **Automatic failover not working:**
|
||||
- Verify AG is configured with automatic failover mode
|
||||
- Check WSFC quorum configuration
|
||||
- Ensure database is in SYNCHRONIZED state
|
||||
|
||||
## Comparison with Oracle Schema
|
||||
|
||||
The MS SQL schema exactly mirrors the Oracle implementation:
|
||||
|
||||
| Feature | Oracle | MS SQL |
|
||||
|---------|--------|---------|
|
||||
| Identity column | SEQUENCE | IDENTITY |
|
||||
| Timestamp | TIMESTAMP(6) | DATETIME2(6) |
|
||||
| String | VARCHAR2 | NVARCHAR |
|
||||
| JSON storage | CLOB with IS JSON check | NVARCHAR(MAX) with ISJSON check |
|
||||
| FK cascade | ON DELETE CASCADE | ON DELETE CASCADE |
|
||||
| Index | Standard B-tree | Standard B-tree |
|
||||
|
||||
Both implementations provide:
|
||||
- Automatic ID generation
|
||||
- Foreign key relationship between tables
|
||||
- JSON validation on raw data
|
||||
- Indexed timestamp and topic columns
|
||||
- Identical application-level interface
|
||||
|
||||
## Support
|
||||
|
||||
For issues or questions:
|
||||
- Check application logs: `LOG_LEVEL=DEBUG` in `.env`
|
||||
- Review SQL Server error log
|
||||
- Consult Microsoft SQL Server documentation
|
||||
Reference in New Issue
Block a user