From 224497ac5b7db1ddeeeb66a1e9ffbff5beb546d3 Mon Sep 17 00:00:00 2001 From: Roland Teichert Date: Tue, 25 Nov 2025 14:57:48 +0200 Subject: [PATCH 1/6] Added the nodejs-mssql self host demo. --- demos/nodejs-mssql/.env | 25 +++ demos/nodejs-mssql/README.md | 28 ++++ demos/nodejs-mssql/config/powersync.yaml | 29 ++++ demos/nodejs-mssql/config/sync_rules.yaml | 13 ++ demos/nodejs-mssql/docker-compose.yaml | 65 ++++++++ services/mssql/init.sql | 192 ++++++++++++++++++++++ services/mssql/mssql.yaml | 39 +++++ 7 files changed, 391 insertions(+) create mode 100644 demos/nodejs-mssql/.env create mode 100644 demos/nodejs-mssql/README.md create mode 100644 demos/nodejs-mssql/config/powersync.yaml create mode 100644 demos/nodejs-mssql/config/sync_rules.yaml create mode 100644 demos/nodejs-mssql/docker-compose.yaml create mode 100644 services/mssql/init.sql create mode 100644 services/mssql/mssql.yaml diff --git a/demos/nodejs-mssql/.env b/demos/nodejs-mssql/.env new file mode 100644 index 0000000..c4e7c14 --- /dev/null +++ b/demos/nodejs-mssql/.env @@ -0,0 +1,25 @@ +# ==================== MSSQL credentials ================================ +# "sa" (sysadmin) is the root user for MSSQL required for initial database setup +SA_PASSWORD=321strongROOTpassword! +HOSTNAME=mssql-selfhosted +APP_DB=powersync +APP_LOGIN=powersync_user +APP_PASSWORD=strongPOWERSYNCUSERpassword321! + +PS_DATA_SOURCE_URI=mssql://${APP_LOGIN}:${APP_PASSWORD}@${HOSTNAME}:1433/${APP_DB} + +# ==================== Demo config ========================================= +DEMO_BACKEND_PORT=6060 +DEMO_BACKEND_DATABASE_TYPE=mssql +DEMO_BACKEND_DATABASE_URI=${PS_DATA_SOURCE_URI} +# The front-end demo application is accessible at this port on the host machine +DEMO_CLIENT_PORT=3035 +PS_JWKS_URL=http://demo-backend:${DEMO_BACKEND_PORT}/api/auth/keys + +# These can be generated by following the instructions in the `key-generator` folder +# A temporary key will be used if these are not specified +DEMO_JWKS_PUBLIC_KEY=eyJrdHkiOiJSU0EiLCJuIjoiMlAwTWtUS1RpSmlEcEltZWl2akV6ODJTbERiRHFGblRmR1hnOXQzejZ2MUF0Y0x0X0l1T3VuaUhBQWtFbzU0Sndrc1o2bkR0RTdnbVlpTnd6Z3ROdnJaSjVhT1c1UUkxZkV4STkxc205clFoVkF4dENySlhxdVZMSnB3UmU4QkR1Yjd0QXNQZlpSc0NOYkZJQ1NVLUpoTkpwcGdGZFpUcWFBdVZsN2lRT3pBMHBGVVlONTF0Q2ItOGJUb2p6NFNtSEVRMmc2VjVsVjQwYlJ3aGcycmlpZ1JWWHI4eTdDdGhnYXRDU1p0YV80aGllT0ZUQkxPMUthZExjYzFzM0puVGxRMU5NRWE1T0hMdmFLYzAyVW83S2JKQWNOU3NQTzRidTdPTUVtMWdBeHhRWnVMZUU2OXB1anc2Z25QRXhqemwzRWpTTTlSQUJwSWpTNld4NFphRXZRIiwiZSI6IkFRQUIiLCJhbGciOiJSUzI1NiIsImtpZCI6InBvd2Vyc3luYy1kMjI0NmNiOTU4In0= +DEMO_JWKS_PRIVATE_KEY=eyJrdHkiOiJSU0EiLCJuIjoiMlAwTWtUS1RpSmlEcEltZWl2akV6ODJTbERiRHFGblRmR1hnOXQzejZ2MUF0Y0x0X0l1T3VuaUhBQWtFbzU0Sndrc1o2bkR0RTdnbVlpTnd6Z3ROdnJaSjVhT1c1UUkxZkV4STkxc205clFoVkF4dENySlhxdVZMSnB3UmU4QkR1Yjd0QXNQZlpSc0NOYkZJQ1NVLUpoTkpwcGdGZFpUcWFBdVZsN2lRT3pBMHBGVVlONTF0Q2ItOGJUb2p6NFNtSEVRMmc2VjVsVjQwYlJ3aGcycmlpZ1JWWHI4eTdDdGhnYXRDU1p0YV80aGllT0ZUQkxPMUthZExjYzFzM0puVGxRMU5NRWE1T0hMdmFLYzAyVW83S2JKQWNOU3NQTzRidTdPTUVtMWdBeHhRWnVMZUU2OXB1anc2Z25QRXhqemwzRWpTTTlSQUJwSWpTNld4NFphRXZRIiwiZSI6IkFRQUIiLCJkIjoiQkZhS1RJOG1ITnJaek5LbW82T0xjNVpCQ3dzLUgwMWRqVlJYc05yOGJlXzA1dmpob0hiNG1PWktBVW0zRzNLeHFKS2s0UGxodnpDRWhMcnJMVDN0U25tNDdTcUVUX0xZTjM4MHhmLWJRMFZfZTdmSDlXdDh2c0pvTFAtY05OU29QNUNfVjRaajRXQXBqa21HWXlNanhlRmczXzFYRUFwM1MtQ0lOazluSFMzYmkzZmtieHdET1VnRjI4MWhma0U3bzdfM3JabGJiZkhoY2FCMkgxY25CVTBqcld1ZFJUMDBKQ28walhJUnh2SGt5NldTdTZEWXVHNmh1UktYdWxoQlRDdGJINDd4cVJWQWIxcGRfWnVGSkc3dEtiU3pyT3o5TW1MLXBCTC05YmdVN1JtQzRCY0dHa1dXRlhDam9uOS1tTzJlN3JOenNHUjlWWkpST2RNUWN3IiwicCI6Il80amVZRU5WY2RIX1N4bmV3UGVmQm9oV19hTThObXNpYTRVWFF6ZTN4MThUMFY1Vl9LblRMWFp4ZHFQRi1OZnVPYkZMQjBHd1lXdlZrY1hHNWd0U3dtd090bkE5VTdwQzF6cTBfUW51THc5aGJPOXJneENGdm9pQm81dVZpNHJ0UmV1RnhITTA5czVBLXhuX241Sk9wby1yYWhIdUYyYWp4aFVlb1ZVYmpMcyIsInEiOiIyV0kxeFg2RUptOUdpR3hhMndUWnRMRFlzSGpEWUlvQW9iSFJUOHl3OWVhYzF1U0U1bXZnalZlRTZ4MWM5VUpBTl9vTHlrQktsa05oS095c0R2U3pZSi1JZlpYYzZqVE1VWWxRQ01vSV9ZQTRWMDJxM29XODNGTFNhOEk0V1RGbERINTlpUXRNNjlrQjgwaTA1Y25nYlMzMWdMUTFPdGg4OU14R0hGV0xHT2MiLCJkcCI6InljNGd1T3RVVm9CZTJzUENqS2pDV1ZsaFFnd2hLR1R4bVBKUnpjNzVfNlVSdEo2SXpfS2FpV1BwOWFVZld3ZkU1cUVpdk1kZThZRkUtRXUyYWNUMWhmX3FtcUFIZnRFeHFtSjl2dnlSczI2MUpWX3JpMldJQ2xJcDk3aU9vTmFGemx0VG1ETFgyRFpKVVVWV0FJSi1STUpmd0hRS2tVYUlfbzE5VkRJdmdMTSIsImRxIjoiYm9Wb0lVajVsekRzQTJCVHNSYi1PTWZRNDZnQ2JZcThWM2s0bWdIUDFyV3c5X0NuUVItSHcxVEQxMlhPWlVPUnN1UUdLb1lWWmVCTF9hcVdyLVBwYnk2dERteXJMTWc3T1JrLV83ajRhU3BQZXRPYUZCaWF0TW5IQWRKMUk2UGhaRURMUW1ua2FlU2pBVFh1QXdab2ZCbnB2ODNmWWxPLTlCY0hibEJ2cl9FIiwicWkiOiJEX2sxYVhmTVpscFpOc0E3ZUl3R1RHSlMyN0xwdnpJWjdFUWNEUnNqUnRjZWtPYmJueGNiM2U2WEpPV3ZLXy1IbF90VmxtLTdKZ21KWlpDSy1qVUxUYkVOUTAxMXdmZnBTRzZ5QmZuY0RXLV9ETlBWZ0E2N1g3azQzckNRTm9fck1VNERpczVwaWhoTHpoakIzUVlBbjAwek50MzFReWVXWmtNSm1mSF82YVkiLCJhbGciOiJSUzI1NiIsImtpZCI6InBvd2Vyc3luYy1kMjI0NmNiOTU4In0= +# ==================== PowerSync variables ==================== +# The PowerSync API is accessible via this port +PS_PORT=8080 diff --git a/demos/nodejs-mssql/README.md b/demos/nodejs-mssql/README.md new file mode 100644 index 0000000..78cc447 --- /dev/null +++ b/demos/nodejs-mssql/README.md @@ -0,0 +1,28 @@ +# JavaScript PowerSync + MSSQL Self Hosted Demo + +This demo contains a NodeJS + MSSQL backend and React frontend which are linked to a self hosted PowerSync instance. + +Backend code can be found [here](https://github.com/powersync-ja/powersync-nodejs-backend-todolist-demo) + +## Running + +The `.env` file contains default configuration for the services. Reference this to connect to any services locally. + +This demo can be started by running the following in this demo directory + +```bash +docker compose up +``` + +or in the root directory run + +```bash +docker compose -f demos/nodejs-mssql/docker-compose.yaml up +``` + +The frontend can be accessed at `http://localhost:3035` in a browser. + +## Configuration + +See [MSSQL Configuration](../../services/mssql/mssql.yaml) for the SQL server configuration +The SQL server is initialized with the [init](../../services/mssql/init.sql) script. diff --git a/demos/nodejs-mssql/config/powersync.yaml b/demos/nodejs-mssql/config/powersync.yaml new file mode 100644 index 0000000..d5dfaba --- /dev/null +++ b/demos/nodejs-mssql/config/powersync.yaml @@ -0,0 +1,29 @@ +# yaml-language-server: $schema=https://unpkg.com/@powersync/service-schema@latest/json-schema/powersync-config.json +telemetry: + # Opt out of reporting anonymized usage metrics to PowerSync telemetry service + disable_telemetry_sharing: false + +# Settings for source database replication +replication: + connections: + - type: mssql + uri: !env PS_DATA_SOURCE_URI + +# Connection settings for sync bucket storage +storage: + type: mongodb + uri: !env PS_MONGO_URI + +# The port which the PowerSync API server will listen on +port: !env PS_PORT + +# Specify sync rules +sync_rules: + path: sync_rules.yaml + +# Client (application end user) authentication settings +client_auth: + # JWKS URIs can be specified here + jwks_uri: !env PS_JWKS_URL + + audience: ["powersync-dev", "powersync"] diff --git a/demos/nodejs-mssql/config/sync_rules.yaml b/demos/nodejs-mssql/config/sync_rules.yaml new file mode 100644 index 0000000..14178e7 --- /dev/null +++ b/demos/nodejs-mssql/config/sync_rules.yaml @@ -0,0 +1,13 @@ +# yaml-language-server: $schema=https://unpkg.com/@powersync/service-sync-rules@latest/schema/sync_rules.json +# +# See Documentation for more information: +# https://docs.powersync.com/usage/sync-rules +# +# Note that changes to this file are not watched. +# The service needs to be restarted for changes to take effect. + +bucket_definitions: + global: + data: + - select * from lists + - select * from todos diff --git a/demos/nodejs-mssql/docker-compose.yaml b/demos/nodejs-mssql/docker-compose.yaml new file mode 100644 index 0000000..e6b5547 --- /dev/null +++ b/demos/nodejs-mssql/docker-compose.yaml @@ -0,0 +1,65 @@ +# Include syntax requires Docker compose > 2.20.3 +# https://docs.docker.com/compose/release-notes/#2203 +include: + # Creates a MongoDB replica set. This is used for internal and data storage + - path: ../../services/mongo.yaml + + # MSSQL Data source configuration + - path: ../../services/mssql/mssql.yaml + +services: + # Extend PowerSync with Mongo and MSSQL healthchecks + powersync: + extends: + file: ../../services/powersync.yaml + service: powersync + depends_on: + mssql-selfhosted: + condition: service_healthy + mssql-selfhosted-setup: + condition: service_completed_successfully + mongo-rs-init: + condition: service_completed_successfully + volumes: + - ./config:/config + + # Demo NodeJS backend server and front-end web client copied from ps-nodejs-demo.yaml + # so that the demo backend depend_on could be overriden to wait for MSSQL to be ready + # An example demo app which is linked to the PowerSync instance above + demo-client: + build: + context: ../nodejs/demo-app + dockerfile: Dockerfile + args: + # This is from the perspective of the client running in a local machine's browser + VITE_POWERSYNC_URL: http://localhost:${PS_PORT} + # From the demo-backend defined below + VITE_BACKEND_URL: http://localhost:${DEMO_BACKEND_PORT} + VITE_CHECKPOINT_MODE: managed + ports: + - ${DEMO_CLIENT_PORT}:4173 + + # A backend which provides basic authentication and CRUD access to the Postgress DB from the client + demo-backend: + build: + context: https://github.com/powersync-ja/powersync-nodejs-backend-todolist-demo.git + depends_on: + mssql-selfhosted: + condition: service_healthy + mssql-selfhosted-setup: + condition: service_completed_successfully + environment: + DATABASE_TYPE: ${DEMO_BACKEND_DATABASE_TYPE} + DATABASE_URI: ${DEMO_BACKEND_DATABASE_URI} + # From the PowerSync service name + # This is just used to populate the JWT audience + POWERSYNC_URL: powersync-dev + + # Keys here for demonstration + POWERSYNC_PUBLIC_KEY: ${DEMO_JWKS_PUBLIC_KEY} + POWERSYNC_PRIVATE_KEY: ${DEMO_JWKS_PRIVATE_KEY} + JWT_ISSUER: powersync-dev + + PORT: ${DEMO_BACKEND_PORT} + ports: + - ${DEMO_BACKEND_PORT}:${DEMO_BACKEND_PORT} diff --git a/services/mssql/init.sql b/services/mssql/init.sql new file mode 100644 index 0000000..0a65682 --- /dev/null +++ b/services/mssql/init.sql @@ -0,0 +1,192 @@ +-- Create database (idempotent) +DECLARE @db sysname = '$(APP_DB)'; +IF DB_ID(@db) IS NULL +BEGIN + DECLARE @sql nvarchar(max) = N'CREATE DATABASE [' + @db + N'];'; +EXEC(@sql); +END +GO + +-- Enable CDC at the database level (idempotent) +DECLARE @db sysname = '$(APP_DB)'; +DECLARE @cmd nvarchar(max) = N'USE [' + @db + N']; +IF EXISTS (SELECT 1 FROM sys.databases WHERE name = ''' + @db + N''' AND is_cdc_enabled = 0) + EXEC sys.sp_cdc_enable_db;'; +EXEC(@cmd); +GO + + +-- Create a SQL login (server) and user (db), then grant CDC read access +-- Note: 'cdc_reader' role is auto-created when CDC is enabled on the DB. +DECLARE @db sysname = '$(APP_DB)'; +DECLARE @login sysname = '$(APP_LOGIN)'; +DECLARE @password nvarchar(128) = '$(APP_PASSWORD)'; +-- Create login if missing +IF NOT EXISTS (SELECT 1 FROM sys.server_principals WHERE name = @login) +BEGIN + DECLARE @mklogin nvarchar(max) = N'CREATE LOGIN [' + @login + N'] WITH PASSWORD = ''' + @password + N''', CHECK_POLICY = ON;'; +EXEC(@mklogin); +END; + +-- Create user in DB if missing +DECLARE @mkuser nvarchar(max) = N'USE [' + @db + N']; +IF NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE name = ''' + @login + N''') + CREATE USER [' + @login + N'] FOR LOGIN [' + @login + N'];'; +EXEC(@mkuser); +GO + +USE [MASTER]; +GRANT VIEW SERVER PERFORMANCE STATE TO [$(APP_LOGIN)]; +GO + +USE [$(APP_DB)]; +GRANT VIEW DATABASE PERFORMANCE STATE TO [$(APP_LOGIN)]; +GO + +-- Create PowerSync checkpoints table +USE [$(APP_DB)]; +IF OBJECT_ID('dbo._powersync_checkpoints', 'U') IS NULL +BEGIN + CREATE TABLE dbo._powersync_checkpoints ( + id INT IDENTITY PRIMARY KEY, + last_updated DATETIME NOT NULL DEFAULT (GETDATE()) + ); +END; + +GRANT INSERT, UPDATE ON dbo._powersync_checkpoints TO [$(APP_LOGIN)]; + +-- Enable CDC for checkpoints table +DECLARE @enableCheckpointsTable nvarchar(max) = +'IF NOT EXISTS ( + SELECT 1 + FROM cdc.change_tables + WHERE source_object_id = OBJECT_ID(N''dbo._powersync_checkpoints'') +) +BEGIN + EXEC sys.sp_cdc_enable_table + @source_schema = N''dbo'', + @source_name = N''_powersync_checkpoints'', + @role_name = N''cdc_reader'', + @supports_net_changes = 1; +END;'; +EXEC(@enableCheckpointsTable); +GO + +-- Wait until capture job exists +DECLARE @tries int = 10; +WHILE @tries > 0 AND NOT EXISTS ( + SELECT 1 FROM msdb.dbo.cdc_jobs WHERE job_type = N'capture' +) +BEGIN + WAITFOR DELAY '00:00:01'; + SET @tries -= 1; +END; + +-- Set the CDC capture job polling interval to 1 second (default is 5 seconds) +-- Stops cdc job and restarts cdc job for new polling interval to take affect +-- Now it's safe +EXEC sys.sp_cdc_change_job @job_type = N'capture', @pollinginterval = 1; +GO + +/* ----------------------------------------------------------- + Create tables and enable CDC on them. + You must enable CDC per table to actually capture changes. + Example below creates the demo tables and enables CDC on it. +------------------------------------------------------------*/ + +DECLARE @db sysname = '$(APP_DB)'; +EXEC(N'USE [' + @db + N']; +IF OBJECT_ID(''dbo.lists'', ''U'') IS NULL +BEGIN + CREATE TABLE dbo.lists ( + id UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(), -- GUID (36 characters), + created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME(), + name NVARCHAR(MAX) NOT NULL, + owner_id UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT PK_lists PRIMARY KEY (id) + ); +END; +'); + +GRANT INSERT, UPDATE, DELETE ON dbo.lists TO [$(APP_LOGIN)]; + +EXEC(N'USE [' + @db + N']; +IF OBJECT_ID(''dbo.todos'', ''U'') IS NULL +BEGIN + CREATE TABLE dbo.todos ( + id UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(), -- GUID (36 characters) + created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME(), + completed_at DATETIME2 NULL, + description NVARCHAR(MAX) NOT NULL, + completed BIT NOT NULL DEFAULT 0, + created_by UNIQUEIDENTIFIER NULL, + completed_by UNIQUEIDENTIFIER NULL, + list_id UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT PK_todos PRIMARY KEY (id), + CONSTRAINT FK_todos_lists FOREIGN KEY (list_id) REFERENCES dbo.lists(id) ON DELETE CASCADE + ); +END; +'); + +GRANT INSERT, UPDATE, DELETE ON dbo.todos TO [$(APP_LOGIN)]; +GO + +-- Enable CDC for dbo.lists (idempotent guard) +DECLARE @db sysname = '$(APP_DB)'; +DECLARE @login sysname = '$(APP_LOGIN)'; +DECLARE @enableListsTable nvarchar(max) = N'USE [' + @db + N']; +IF NOT EXISTS ( + SELECT 1 + FROM cdc.change_tables + WHERE source_object_id = OBJECT_ID(N''dbo.lists'') +) +BEGIN + EXEC sys.sp_cdc_enable_table + @source_schema = N''dbo'', + @source_name = N''lists'', + @role_name = N''cdc_reader'', + @supports_net_changes = 1; +END;'; +EXEC(@enableListsTable); + +-- Enable CDC for dbo.todos (idempotent guard) +DECLARE @enableTodosTable nvarchar(max) = N'USE [' + @db + N']; +IF NOT EXISTS ( + SELECT 1 + FROM cdc.change_tables + WHERE source_object_id = OBJECT_ID(N''dbo.todos'') +) +BEGIN + EXEC sys.sp_cdc_enable_table + @source_schema = N''dbo'', + @source_name = N''todos'', + @role_name = N''cdc_reader'', + @supports_net_changes = 1; +END;'; +EXEC(@enableTodosTable); + +-- Grant minimal rights to read CDC data: +-- 1) read access to base tables (db_datareader) +-- 2) membership in cdc_reader (allows selecting from CDC change tables & functions) +-- 3) the cdc_reader role is only available once CDC is enabled on the database and some tables have been enabled for CDC +DECLARE @grant nvarchar(max) = N'USE [' + @db + N']; +IF NOT EXISTS (SELECT 1 FROM sys.database_role_members rm + JOIN sys.database_principals r ON rm.role_principal_id = r.principal_id AND r.name = ''db_datareader'' + JOIN sys.database_principals u ON rm.member_principal_id = u.principal_id AND u.name = ''' + @login + N''') + ALTER ROLE db_datareader ADD MEMBER [' + @login + N']; + +IF NOT EXISTS (SELECT 1 FROM sys.database_role_members rm + JOIN sys.database_principals r ON rm.role_principal_id = r.principal_id AND r.name = ''cdc_reader'' + JOIN sys.database_principals u ON rm.member_principal_id = u.principal_id AND u.name = ''' + @login + N''') + ALTER ROLE cdc_reader ADD MEMBER [' + @login + N'];'; +EXEC(@grant); +GO + +DECLARE @db sysname = '$(APP_DB)'; +EXEC(N'USE [' + @db + N']; +BEGIN + INSERT INTO dbo.lists (id, name, owner_id) + VALUES (NEWID(), ''Do a demo'', NEWID()); +END; +'); +GO \ No newline at end of file diff --git a/services/mssql/mssql.yaml b/services/mssql/mssql.yaml new file mode 100644 index 0000000..935dbbf --- /dev/null +++ b/services/mssql/mssql.yaml @@ -0,0 +1,39 @@ +name: mssql-selfhosted-db +services: + mssql-selfhosted: + platform: linux/amd64 + image: mcr.microsoft.com/mssql/server:2022-latest # 2025 Can also be used, but not on Mac 26 Tahoe due to this issue: https://github.com/microsoft/mssql-docker/issues/942 + container_name: mssql-selfhosted + ports: + - "1433:1433" + environment: + ACCEPT_EULA: "Y" + MSSQL_SA_PASSWORD: "${SA_PASSWORD}" + MSSQL_PID: "Developer" + MSSQL_AGENT_ENABLED: "true" # required for CDC capture/cleanup jobs + volumes: + - mssql-selfhosted-data:/var/opt/mssql + healthcheck: + test: [ "CMD-SHELL", "/opt/mssql-tools18/bin/sqlcmd -C -S localhost -U sa -P \"$${MSSQL_SA_PASSWORD}\" -Q \"SELECT 1;\" || exit 1" ] + interval: 5s + timeout: 3s + retries: 30 + + mssql-selfhosted-setup: + platform: linux/amd64 + image: mcr.microsoft.com/mssql/server:2022-latest + container_name: mssql-selfhosted-setup + depends_on: + mssql-selfhosted: + condition: service_healthy + environment: + SA_PASSWORD: "${SA_PASSWORD}" + APP_DB: "${APP_DB}" + APP_LOGIN: "${APP_LOGIN}" + APP_PASSWORD: "${APP_PASSWORD}" + volumes: + - ./init.sql:/scripts/init.sql:ro + entrypoint: ["/bin/bash", "-lc", "/opt/mssql-tools18/bin/sqlcmd -C -S mssql-selfhosted,1433 -U sa -P \"$SA_PASSWORD\" -i /scripts/init.sql && echo '✅ MSSQL init done'"] + +volumes: + mssql-selfhosted-data: From c9a5d9cb3631670efe97cf63f559de9037d6cb50 Mon Sep 17 00:00:00 2001 From: Roland Teichert Date: Tue, 25 Nov 2025 14:59:32 +0200 Subject: [PATCH 2/6] Added changelog entry --- CHANGELOG.md | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/CHANGELOG.md b/CHANGELOG.md index 974bf8d..068327e 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,9 @@ # PowerSync Self Hosted Example +## 2025-11-25 + +- Created the MSSQL Self host demo and configuration. + ## 2025-05-13 - Updated YAML config files to use published schema From 2565bdf349b3eef8cdbfaa3994a058ea6e51208e Mon Sep 17 00:00:00 2001 From: Roland Teichert Date: Wed, 26 Nov 2025 11:13:21 +0200 Subject: [PATCH 3/6] Simplified mssql init script and renamed env variables for clarity --- demos/nodejs-mssql/.env | 13 +- demos/nodejs-mssql/README.md | 2 +- services/mssql/.env.template | 4 + services/mssql/init.sql | 242 +++++++++++++++-------------------- services/mssql/mssql.yaml | 16 +-- 5 files changed, 121 insertions(+), 156 deletions(-) create mode 100644 services/mssql/.env.template diff --git a/demos/nodejs-mssql/.env b/demos/nodejs-mssql/.env index c4e7c14..600e936 100644 --- a/demos/nodejs-mssql/.env +++ b/demos/nodejs-mssql/.env @@ -1,19 +1,18 @@ # ==================== MSSQL credentials ================================ -# "sa" (sysadmin) is the root user for MSSQL required for initial database setup -SA_PASSWORD=321strongROOTpassword! +ROOT_PASSWORD=321strongROOTpassword! HOSTNAME=mssql-selfhosted -APP_DB=powersync -APP_LOGIN=powersync_user -APP_PASSWORD=strongPOWERSYNCUSERpassword321! +DATABASE=powersync +DB_USER=powersync_user +DB_USER_PASSWORD=strongPOWERSYNCUSERpassword321! -PS_DATA_SOURCE_URI=mssql://${APP_LOGIN}:${APP_PASSWORD}@${HOSTNAME}:1433/${APP_DB} +PS_DATA_SOURCE_URI=mssql://${DB_USER}:${DB_USER_PASSWORD}@${HOSTNAME}:1433/${DATABASE} # ==================== Demo config ========================================= DEMO_BACKEND_PORT=6060 DEMO_BACKEND_DATABASE_TYPE=mssql DEMO_BACKEND_DATABASE_URI=${PS_DATA_SOURCE_URI} # The front-end demo application is accessible at this port on the host machine -DEMO_CLIENT_PORT=3035 +DEMO_CLIENT_PORT=3036 PS_JWKS_URL=http://demo-backend:${DEMO_BACKEND_PORT}/api/auth/keys # These can be generated by following the instructions in the `key-generator` folder diff --git a/demos/nodejs-mssql/README.md b/demos/nodejs-mssql/README.md index 78cc447..60c114a 100644 --- a/demos/nodejs-mssql/README.md +++ b/demos/nodejs-mssql/README.md @@ -20,7 +20,7 @@ or in the root directory run docker compose -f demos/nodejs-mssql/docker-compose.yaml up ``` -The frontend can be accessed at `http://localhost:3035` in a browser. +The frontend can be accessed at `http://localhost:3036` in a browser. ## Configuration diff --git a/services/mssql/.env.template b/services/mssql/.env.template new file mode 100644 index 0000000..2e20e87 --- /dev/null +++ b/services/mssql/.env.template @@ -0,0 +1,4 @@ +ROOT_PASSWORD=321strongROOTpassword! +DATABASE=powersync +DB_USER=powersync_user +DB_USER_PASSWORD=strongPOWERSYNCUSERpassword321! \ No newline at end of file diff --git a/services/mssql/init.sql b/services/mssql/init.sql index 0a65682..73b5ac0 100644 --- a/services/mssql/init.sql +++ b/services/mssql/init.sql @@ -1,192 +1,154 @@ -- Create database (idempotent) -DECLARE @db sysname = '$(APP_DB)'; -IF DB_ID(@db) IS NULL +IF DB_ID('$(DATABASE)') IS NULL BEGIN - DECLARE @sql nvarchar(max) = N'CREATE DATABASE [' + @db + N'];'; -EXEC(@sql); + CREATE DATABASE [$(DATABASE)]; END GO -- Enable CDC at the database level (idempotent) -DECLARE @db sysname = '$(APP_DB)'; -DECLARE @cmd nvarchar(max) = N'USE [' + @db + N']; -IF EXISTS (SELECT 1 FROM sys.databases WHERE name = ''' + @db + N''' AND is_cdc_enabled = 0) - EXEC sys.sp_cdc_enable_db;'; -EXEC(@cmd); +USE [$(DATABASE)]; +IF (SELECT is_cdc_enabled FROM sys.databases WHERE name = '$(DATABASE)') = 0 +BEGIN +EXEC sys.sp_cdc_enable_db; +END GO - --- Create a SQL login (server) and user (db), then grant CDC read access --- Note: 'cdc_reader' role is auto-created when CDC is enabled on the DB. -DECLARE @db sysname = '$(APP_DB)'; -DECLARE @login sysname = '$(APP_LOGIN)'; -DECLARE @password nvarchar(128) = '$(APP_PASSWORD)'; --- Create login if missing -IF NOT EXISTS (SELECT 1 FROM sys.server_principals WHERE name = @login) +-- Create a SQL login (server) if missing +USE [master]; +IF NOT EXISTS (SELECT 1 FROM sys.server_principals WHERE name = '$(DB_USER)') BEGIN - DECLARE @mklogin nvarchar(max) = N'CREATE LOGIN [' + @login + N'] WITH PASSWORD = ''' + @password + N''', CHECK_POLICY = ON;'; -EXEC(@mklogin); -END; + CREATE LOGIN [$(DB_USER)] WITH PASSWORD = '$(DB_USER_PASSWORD)', CHECK_POLICY = ON; +END +GO --- Create user in DB if missing -DECLARE @mkuser nvarchar(max) = N'USE [' + @db + N']; -IF NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE name = ''' + @login + N''') - CREATE USER [' + @login + N'] FOR LOGIN [' + @login + N'];'; -EXEC(@mkuser); +-- Create DB user for the app DB if missing +USE [$(DATABASE)]; +IF NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE name = '$(DB_USER)') +BEGIN + CREATE USER [$(DB_USER)] FOR LOGIN [$(DB_USER)]; +END GO -USE [MASTER]; -GRANT VIEW SERVER PERFORMANCE STATE TO [$(APP_LOGIN)]; +-- Required for PowerSync to access the sys.dm_db_log_stats DMV +USE [master]; +GRANT VIEW SERVER PERFORMANCE STATE TO [$(DB_USER)]; GO -USE [$(APP_DB)]; -GRANT VIEW DATABASE PERFORMANCE STATE TO [$(APP_LOGIN)]; +-- Required for PowerSync to access the sys.dm_db_log_stats DMV and the sys.dm_db_partition_stats DMV +USE [$(DATABASE)]; +GRANT VIEW DATABASE PERFORMANCE STATE TO [$(DB_USER)]; GO -- Create PowerSync checkpoints table -USE [$(APP_DB)]; +-- Powersync requires this table to ensure regular checkpoints appear in CDC IF OBJECT_ID('dbo._powersync_checkpoints', 'U') IS NULL BEGIN - CREATE TABLE dbo._powersync_checkpoints ( - id INT IDENTITY PRIMARY KEY, - last_updated DATETIME NOT NULL DEFAULT (GETDATE()) - ); -END; +CREATE TABLE dbo._powersync_checkpoints ( + id INT IDENTITY PRIMARY KEY, + last_updated DATETIME NOT NULL DEFAULT (GETDATE()) +); +END -GRANT INSERT, UPDATE ON dbo._powersync_checkpoints TO [$(APP_LOGIN)]; +GRANT INSERT, UPDATE ON dbo._powersync_checkpoints TO [$(DB_USER)]; +GO --- Enable CDC for checkpoints table -DECLARE @enableCheckpointsTable nvarchar(max) = -'IF NOT EXISTS ( - SELECT 1 - FROM cdc.change_tables - WHERE source_object_id = OBJECT_ID(N''dbo._powersync_checkpoints'') -) +-- Enable CDC for the powersync checkpoints table +IF NOT EXISTS (SELECT 1 FROM cdc.change_tables WHERE source_object_id = OBJECT_ID(N'dbo._powersync_checkpoints')) BEGIN - EXEC sys.sp_cdc_enable_table - @source_schema = N''dbo'', - @source_name = N''_powersync_checkpoints'', - @role_name = N''cdc_reader'', - @supports_net_changes = 1; -END;'; -EXEC(@enableCheckpointsTable); +EXEC sys.sp_cdc_enable_table + @source_schema = N'dbo', + @source_name = N'_powersync_checkpoints', + @role_name = N'cdc_reader', + @supports_net_changes = 0; +END GO --- Wait until capture job exists +-- Wait until capture job exists - usually takes a few seconds after enabling CDC on a table for the first time DECLARE @tries int = 10; -WHILE @tries > 0 AND NOT EXISTS ( - SELECT 1 FROM msdb.dbo.cdc_jobs WHERE job_type = N'capture' -) +WHILE @tries > 0 AND NOT EXISTS (SELECT 1 FROM msdb.dbo.cdc_jobs WHERE job_type = N'capture') BEGIN WAITFOR DELAY '00:00:01'; SET @tries -= 1; END; -- Set the CDC capture job polling interval to 1 second (default is 5 seconds) --- Stops cdc job and restarts cdc job for new polling interval to take affect --- Now it's safe EXEC sys.sp_cdc_change_job @job_type = N'capture', @pollinginterval = 1; GO /* ----------------------------------------------------------- - Create tables and enable CDC on them. - You must enable CDC per table to actually capture changes. - Example below creates the demo tables and enables CDC on it. + Create demo lists and todos tables and enables CDC on them. + CDC must be enabled per table to actually capture changes. ------------------------------------------------------------*/ - -DECLARE @db sysname = '$(APP_DB)'; -EXEC(N'USE [' + @db + N']; -IF OBJECT_ID(''dbo.lists'', ''U'') IS NULL +IF OBJECT_ID('dbo.lists', 'U') IS NULL BEGIN - CREATE TABLE dbo.lists ( - id UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(), -- GUID (36 characters), - created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME(), - name NVARCHAR(MAX) NOT NULL, - owner_id UNIQUEIDENTIFIER NOT NULL, - CONSTRAINT PK_lists PRIMARY KEY (id) - ); -END; -'); +CREATE TABLE dbo.lists ( + id UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(), + created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME(), + name NVARCHAR(MAX) NOT NULL, + owner_id UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT PK_lists PRIMARY KEY (id) +); +END -GRANT INSERT, UPDATE, DELETE ON dbo.lists TO [$(APP_LOGIN)]; +GRANT INSERT, UPDATE, DELETE ON dbo.lists TO [$(DB_USER)]; +GO -EXEC(N'USE [' + @db + N']; -IF OBJECT_ID(''dbo.todos'', ''U'') IS NULL +IF OBJECT_ID('dbo.todos', 'U') IS NULL BEGIN - CREATE TABLE dbo.todos ( - id UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(), -- GUID (36 characters) - created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME(), - completed_at DATETIME2 NULL, - description NVARCHAR(MAX) NOT NULL, - completed BIT NOT NULL DEFAULT 0, - created_by UNIQUEIDENTIFIER NULL, - completed_by UNIQUEIDENTIFIER NULL, - list_id UNIQUEIDENTIFIER NOT NULL, - CONSTRAINT PK_todos PRIMARY KEY (id), - CONSTRAINT FK_todos_lists FOREIGN KEY (list_id) REFERENCES dbo.lists(id) ON DELETE CASCADE - ); -END; -'); +CREATE TABLE dbo.todos ( + id UNIQUEIDENTIFIER NOT NULL DEFAULT NEWID(), + created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME(), + completed_at DATETIME2 NULL, + description NVARCHAR(MAX) NOT NULL, + completed BIT NOT NULL DEFAULT 0, + created_by UNIQUEIDENTIFIER NULL, + completed_by UNIQUEIDENTIFIER NULL, + list_id UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT PK_todos PRIMARY KEY (id), + CONSTRAINT FK_todos_lists FOREIGN KEY (list_id) REFERENCES dbo.lists(id) ON DELETE CASCADE +); +END -GRANT INSERT, UPDATE, DELETE ON dbo.todos TO [$(APP_LOGIN)]; +GRANT INSERT, UPDATE, DELETE ON dbo.todos TO [$(DB_USER)]; GO -- Enable CDC for dbo.lists (idempotent guard) -DECLARE @db sysname = '$(APP_DB)'; -DECLARE @login sysname = '$(APP_LOGIN)'; -DECLARE @enableListsTable nvarchar(max) = N'USE [' + @db + N']; -IF NOT EXISTS ( - SELECT 1 - FROM cdc.change_tables - WHERE source_object_id = OBJECT_ID(N''dbo.lists'') -) +IF NOT EXISTS (SELECT 1 FROM cdc.change_tables WHERE source_object_id = OBJECT_ID(N'dbo.lists')) BEGIN - EXEC sys.sp_cdc_enable_table - @source_schema = N''dbo'', - @source_name = N''lists'', - @role_name = N''cdc_reader'', - @supports_net_changes = 1; -END;'; -EXEC(@enableListsTable); +EXEC sys.sp_cdc_enable_table + @source_schema = N'dbo', + @source_name = N'lists', + @role_name = N'cdc_reader', + @supports_net_changes = 0; +END +GO -- Enable CDC for dbo.todos (idempotent guard) -DECLARE @enableTodosTable nvarchar(max) = N'USE [' + @db + N']; -IF NOT EXISTS ( - SELECT 1 - FROM cdc.change_tables - WHERE source_object_id = OBJECT_ID(N''dbo.todos'') -) +IF NOT EXISTS (SELECT 1 FROM cdc.change_tables WHERE source_object_id = OBJECT_ID(N'dbo.todos')) BEGIN - EXEC sys.sp_cdc_enable_table - @source_schema = N''dbo'', - @source_name = N''todos'', - @role_name = N''cdc_reader'', - @supports_net_changes = 1; -END;'; -EXEC(@enableTodosTable); - --- Grant minimal rights to read CDC data: --- 1) read access to base tables (db_datareader) --- 2) membership in cdc_reader (allows selecting from CDC change tables & functions) --- 3) the cdc_reader role is only available once CDC is enabled on the database and some tables have been enabled for CDC -DECLARE @grant nvarchar(max) = N'USE [' + @db + N']; -IF NOT EXISTS (SELECT 1 FROM sys.database_role_members rm - JOIN sys.database_principals r ON rm.role_principal_id = r.principal_id AND r.name = ''db_datareader'' - JOIN sys.database_principals u ON rm.member_principal_id = u.principal_id AND u.name = ''' + @login + N''') - ALTER ROLE db_datareader ADD MEMBER [' + @login + N']; - -IF NOT EXISTS (SELECT 1 FROM sys.database_role_members rm - JOIN sys.database_principals r ON rm.role_principal_id = r.principal_id AND r.name = ''cdc_reader'' - JOIN sys.database_principals u ON rm.member_principal_id = u.principal_id AND u.name = ''' + @login + N''') - ALTER ROLE cdc_reader ADD MEMBER [' + @login + N'];'; -EXEC(@grant); +EXEC sys.sp_cdc_enable_table + @source_schema = N'dbo', + @source_name = N'todos', + @role_name = N'cdc_reader', + @supports_net_changes = 0; +END GO -DECLARE @db sysname = '$(APP_DB)'; -EXEC(N'USE [' + @db + N']; +-- Grant minimal rights to read CDC data +IF IS_ROLEMEMBER('db_datareader', '$(DB_USER)') = 0 BEGIN - INSERT INTO dbo.lists (id, name, owner_id) - VALUES (NEWID(), ''Do a demo'', NEWID()); -END; -'); + ALTER ROLE db_datareader ADD MEMBER [$(DB_USER)]; +END + +IF IS_ROLEMEMBER('cdc_reader', '$(DB_USER)') = 0 +BEGIN + ALTER ROLE cdc_reader ADD MEMBER [$(DB_USER)]; +END +GO + +-- Add demo data +BEGIN +INSERT INTO dbo.lists (id, name, owner_id) +VALUES (NEWID(), 'Do a demo', NEWID()); +END GO \ No newline at end of file diff --git a/services/mssql/mssql.yaml b/services/mssql/mssql.yaml index 935dbbf..31e8b72 100644 --- a/services/mssql/mssql.yaml +++ b/services/mssql/mssql.yaml @@ -8,11 +8,11 @@ services: - "1433:1433" environment: ACCEPT_EULA: "Y" - MSSQL_SA_PASSWORD: "${SA_PASSWORD}" + MSSQL_SA_PASSWORD: "${ROOT_PASSWORD}" MSSQL_PID: "Developer" MSSQL_AGENT_ENABLED: "true" # required for CDC capture/cleanup jobs volumes: - - mssql-selfhosted-data:/var/opt/mssql + - data:/var/opt/mssql healthcheck: test: [ "CMD-SHELL", "/opt/mssql-tools18/bin/sqlcmd -C -S localhost -U sa -P \"$${MSSQL_SA_PASSWORD}\" -Q \"SELECT 1;\" || exit 1" ] interval: 5s @@ -27,13 +27,13 @@ services: mssql-selfhosted: condition: service_healthy environment: - SA_PASSWORD: "${SA_PASSWORD}" - APP_DB: "${APP_DB}" - APP_LOGIN: "${APP_LOGIN}" - APP_PASSWORD: "${APP_PASSWORD}" + MSSQL_SA_PASSWORD: "${ROOT_PASSWORD}" + DATABASE: "${DATABASE}" + DB_USER: "${DB_USER}" + DB_USER_PASSWORD: "${DB_USER_PASSWORD}" volumes: - ./init.sql:/scripts/init.sql:ro - entrypoint: ["/bin/bash", "-lc", "/opt/mssql-tools18/bin/sqlcmd -C -S mssql-selfhosted,1433 -U sa -P \"$SA_PASSWORD\" -i /scripts/init.sql && echo '✅ MSSQL init done'"] + entrypoint: ["/bin/bash", "-lc", "/opt/mssql-tools18/bin/sqlcmd -C -S mssql-selfhosted,1433 -U sa -P \"$${MSSQL_SA_PASSWORD}\" -i /scripts/init.sql && echo '✅ MSSQL init done'"] volumes: - mssql-selfhosted-data: + data: From 66b8ec8d083413f54657db23932abfc31b426733 Mon Sep 17 00:00:00 2001 From: Roland Teichert Date: Wed, 26 Nov 2025 11:19:32 +0200 Subject: [PATCH 4/6] Updated readme --- demos/nodejs-mssql/README.md | 14 ++++++++++++++ 1 file changed, 14 insertions(+) diff --git a/demos/nodejs-mssql/README.md b/demos/nodejs-mssql/README.md index 60c114a..d492510 100644 --- a/demos/nodejs-mssql/README.md +++ b/demos/nodejs-mssql/README.md @@ -26,3 +26,17 @@ The frontend can be accessed at `http://localhost:3036` in a browser. See [MSSQL Configuration](../../services/mssql/mssql.yaml) for the SQL server configuration The SQL server is initialized with the [init](../../services/mssql/init.sql) script. + +The initialization script (`init.sql`) performs the following setup steps: + +1. **Database Creation**: Creates the application database +2. **CDC Setup**: Enables Change Data Capture at the database level +3. **User Creation**: Creates a SQL Server login and database user with appropriate permissions +4. **Create PowerSync Checkpoints table**: Creates the required `_powersync_checkpoints` table. +5. **Self Host Demo Tables**: Creates the demo tables (`lists` and `todos`) +6. **Enable Table CDC**: Enables CDC tracking on the demo tables +7. **Permissions**: Grants `db_datareader` and `cdc_reader` roles to the application user +8. **Sample Data**: Inserts initial test data into the `lists` table + +All operations are idempotent, so they can safely be re-run without errors. + From 029089a1c5bae9a4aaff173d50b830c73df92309 Mon Sep 17 00:00:00 2001 From: Roland Teichert Date: Wed, 26 Nov 2025 14:33:50 +0200 Subject: [PATCH 5/6] Update mssql powersync.yaml config file --- demos/nodejs-mssql/config/powersync.yaml | 2 ++ 1 file changed, 2 insertions(+) diff --git a/demos/nodejs-mssql/config/powersync.yaml b/demos/nodejs-mssql/config/powersync.yaml index d5dfaba..9fbd7a3 100644 --- a/demos/nodejs-mssql/config/powersync.yaml +++ b/demos/nodejs-mssql/config/powersync.yaml @@ -8,6 +8,8 @@ replication: connections: - type: mssql uri: !env PS_DATA_SOURCE_URI + schema: dbo + trustServerCertificate: true # Connection settings for sync bucket storage storage: From 1cdc439e78b1c024847b16b0cc03a2a47c458784 Mon Sep 17 00:00:00 2001 From: Roland Teichert Date: Fri, 28 Nov 2025 12:46:36 +0200 Subject: [PATCH 6/6] Added additional config to mssql powersync.yaml --- demos/nodejs-mssql/config/powersync.yaml | 3 ++- services/mssql/init.sql | 1 + 2 files changed, 3 insertions(+), 1 deletion(-) diff --git a/demos/nodejs-mssql/config/powersync.yaml b/demos/nodejs-mssql/config/powersync.yaml index 9fbd7a3..a9bb994 100644 --- a/demos/nodejs-mssql/config/powersync.yaml +++ b/demos/nodejs-mssql/config/powersync.yaml @@ -9,7 +9,8 @@ replication: - type: mssql uri: !env PS_DATA_SOURCE_URI schema: dbo - trustServerCertificate: true + additionalConfig: + trustServerCertificate: true # Connection settings for sync bucket storage storage: diff --git a/services/mssql/init.sql b/services/mssql/init.sql index 73b5ac0..2bb0c63 100644 --- a/services/mssql/init.sql +++ b/services/mssql/init.sql @@ -147,6 +147,7 @@ END GO -- Add demo data +IF NOT EXISTS (SELECT 1 FROM dbo.lists) BEGIN INSERT INTO dbo.lists (id, name, owner_id) VALUES (NEWID(), 'Do a demo', NEWID());