diff --git a/.gitattributes b/.gitattributes
index 017792a2..7b4d1130 100644
--- a/.gitattributes
+++ b/.gitattributes
@@ -16,7 +16,7 @@
*.manifest text
*.bat text
*.cmd text
-*.sh text
+*.sh text eol=lf
*.txt text
*.dat text
*.rc text
diff --git a/Directory.Packages.props b/Directory.Packages.props
index 664aeee1..54b5cc70 100644
--- a/Directory.Packages.props
+++ b/Directory.Packages.props
@@ -105,4 +105,9 @@
+
+
+
+
+
\ No newline at end of file
diff --git a/Eventuous.slnx b/Eventuous.slnx
index 922154cf..10772665 100644
--- a/Eventuous.slnx
+++ b/Eventuous.slnx
@@ -134,9 +134,11 @@
+
+
diff --git a/nuget.config b/nuget.config
new file mode 100644
index 00000000..765346e5
--- /dev/null
+++ b/nuget.config
@@ -0,0 +1,7 @@
+
+
+
+
+
+
+
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Eventuous.SqlServer.Database.csproj b/src/SqlServer/src/Eventuous.SqlServer.Database/Eventuous.SqlServer.Database.csproj
new file mode 100644
index 00000000..ba9cc4b5
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Eventuous.SqlServer.Database.csproj
@@ -0,0 +1,27 @@
+
+
+ net8.0
+ Database
+ True
+ Sql160
+ True
+ True
+ True
+
+
+
+
+
+ all
+ runtime; build; native; contentfiles; analyzers; buildtransitive
+
+
+ all
+ runtime; build; native; contentfiles; analyzers; buildtransitive
+
+
+
+
+
+
+
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/append_events.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/append_events.sql
new file mode 100644
index 00000000..c60edd20
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/append_events.sql
@@ -0,0 +1,111 @@
+CREATE PROCEDURE eventuous.append_events
+ @stream_name NVARCHAR(850),
+ @expected_version INT,
+ @created DATETIME2(7) NULL,
+ @messages eventuous.StreamMessage READONLY
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ -- Note: This procedure is wrapped in a transaction by the caller. This explains why there is no explicit transaction here within the procedure.
+
+ DECLARE
+ @current_version INT,
+ @stream_id INT,
+ @position BIGINT,
+ @count_messages INT,
+ @new_version INT;
+
+ -- capture inserted rows to compute final position
+ DECLARE @inserted TABLE (
+ GlobalPosition BIGINT
+ );
+
+ SELECT @count_messages = COUNT(1) FROM @messages;
+
+ EXEC eventuous.check_stream
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @current_version = @current_version OUTPUT,
+ @stream_id = @stream_id OUTPUT;
+
+ SET @new_version = @current_version + @count_messages;
+
+ BEGIN TRY
+
+ /*
+ If another writer raced us, the unique constraint (StreamId,StreamPosition) will throw here.
+ Translate to WrongExpectedVersion in the CATCH below.
+ */
+ INSERT INTO eventuous.Messages (
+ MessageId,
+ MessageType,
+ StreamId,
+ StreamPosition,
+ JsonData,
+ JsonMetadata,
+ Created
+ )
+ OUTPUT inserted.GlobalPosition
+ INTO @inserted (GlobalPosition)
+ SELECT
+ message_id,
+ message_type,
+ @stream_id,
+ @current_version + CAST(ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS INT),
+ json_data,
+ json_metadata,
+ ISNULL(@created, SYSUTCDATETIME())
+ FROM @messages;
+
+ UPDATE s
+ SET [Version] = @new_version
+ FROM eventuous.Streams s
+ WHERE s.StreamId = @stream_id
+ AND s.[Version] = @current_version;
+
+ IF @@ROWCOUNT = 0
+ BEGIN
+ DECLARE @streamUpdateErrorMessage NVARCHAR(4000) = CONCAT(
+ N'WrongExpectedVersion: concurrent update detected for stream ',
+ CAST(@stream_id AS NVARCHAR(20))
+ );
+ ;THROW 50000, @streamUpdateErrorMessage, 1;
+ END
+
+ END TRY
+ BEGIN CATCH
+ DECLARE @errmsg NVARCHAR(2048) = ERROR_MESSAGE();
+
+ IF ERROR_NUMBER() IN (
+ 2627, -- Violation of PRIMARY KEY or UNIQUE constraint
+ 2601 -- Cannot insert duplicate key row in object with unique index
+ )
+ AND (@errmsg LIKE N'%UQ_StreamIdAndStreamPosition%')
+ BEGIN
+ -- Must BEGIN with "WrongExpectedVersion" for the client detection of OptimisticConcurrencyException
+ DECLARE @clientMsg NVARCHAR(4000) =
+ N'WrongExpectedVersion: duplicate append for stream '
+ + CAST(@stream_id AS NVARCHAR(20))
+ + N' with expected_version=' + CAST(@expected_version AS NVARCHAR(20))
+ + N'. SQL: ' + @errmsg;
+
+ THROW 50000, @clientMsg, 1;
+ END;
+ ELSE
+ BEGIN
+ ;THROW;
+ END;
+ END CATCH;
+
+ -- final GlobalPosition value to return
+ SELECT @position = (
+ SELECT MAX(GlobalPosition)
+ FROM @inserted
+ );
+
+ SELECT
+ @new_version current_version,
+ @position position;
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/check_stream.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/check_stream.sql
new file mode 100644
index 00000000..34c710e0
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/check_stream.sql
@@ -0,0 +1,61 @@
+CREATE PROCEDURE eventuous.check_stream
+ @stream_name NVARCHAR(850),
+ @expected_version INT,
+ @current_version INT OUTPUT,
+ @stream_id INT OUTPUT
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ DECLARE @customErrorMessage NVARCHAR(200);
+
+ SELECT
+ @current_version = [Version],
+ @stream_id = StreamId
+ FROM eventuous.Streams
+ WHERE StreamName = @stream_name;
+
+ IF @stream_id IS NULL
+ BEGIN
+ IF @expected_version = -2 -- Any
+ OR @expected_version = -1 -- NoStream
+ BEGIN
+ BEGIN TRY
+ SET @current_version = -1;
+ INSERT INTO eventuous.Streams (
+ StreamName,
+ [Version]
+ ) VALUES (
+ @stream_name,
+ @current_version
+ );
+
+ SET @stream_id = SCOPE_IDENTITY();
+ END TRY
+ BEGIN CATCH
+ IF (ERROR_NUMBER() = 2627 OR ERROR_NUMBER() = 2601) AND (SELECT CHARINDEX(N'UQ_StreamName', ERROR_MESSAGE())) > 0
+ BEGIN
+ SELECT @customErrorMessage = FORMATMESSAGE(N'WrongExpectedVersion %i, stream already exists', @expected_version);
+ THROW 50000, @customErrorMessage, 1;
+ END;
+ ELSE
+ BEGIN
+ ;THROW;
+ END;
+ END CATCH;
+ END;
+ ELSE
+ BEGIN
+ ;THROW 50001, N'StreamNotFound', 1;
+ END;
+ END
+ ELSE
+ BEGIN
+ IF @expected_version != -2 AND @expected_version != @current_version
+ BEGIN
+ SELECT @customErrorMessage = FORMATMESSAGE(N'WrongExpectedVersion %i, current version %i', @expected_version, @current_version);
+ THROW 50000, @customErrorMessage, 1;
+ END;
+ END;
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_all_forwards.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_all_forwards.sql
new file mode 100644
index 00000000..7af4a056
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_all_forwards.sql
@@ -0,0 +1,22 @@
+CREATE PROCEDURE eventuous.read_all_forwards
+ @from_position BIGINT,
+ @count INT
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ SELECT TOP (@count)
+ m.MessageId,
+ m.MessageType,
+ m.StreamPosition,
+ m.GlobalPosition,
+ m.JsonData,
+ m.JsonMetadata,
+ m.Created,
+ s.StreamName
+ FROM eventuous.Messages m
+ JOIN eventuous.Streams s ON m.StreamId = s.StreamId
+ WHERE m.GlobalPosition >= @from_position
+ ORDER BY m.GlobalPosition;
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_backwards.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_backwards.sql
new file mode 100644
index 00000000..79881816
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_backwards.sql
@@ -0,0 +1,50 @@
+CREATE PROCEDURE eventuous.read_stream_backwards
+ @stream_name NVARCHAR(850),
+ @from_position INT,
+ @count INT
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ DECLARE
+ @current_version INT,
+ @stream_id INT;
+
+ SELECT
+ @current_version = [Version],
+ @stream_id = StreamId
+ FROM eventuous.Streams
+ WHERE StreamName = @stream_name;
+
+ IF @stream_id IS NULL
+ BEGIN
+ ;THROW 50001, 'StreamNotFound', 1;
+ END;
+
+ -- nothing to read / invalid request
+ IF @count <= 0
+ BEGIN
+ RETURN;
+ END;
+
+ -- Validate the starting position for backwards read.
+ IF @from_position < 0 -- A negative starting position is invalid
+ OR @from_position > @current_version -- A starting position greater than the current version means we're trying to read from beyond the head of the stream
+ BEGIN
+ RETURN;
+ END;
+
+ SELECT TOP (@count)
+ MessageId,
+ MessageType,
+ StreamPosition,
+ GlobalPosition,
+ JsonData,
+ JsonMetadata,
+ Created
+ FROM eventuous.Messages
+ WHERE StreamId = @stream_id
+ AND StreamPosition <= @from_position
+ ORDER BY StreamPosition DESC;
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_forwards.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_forwards.sql
new file mode 100644
index 00000000..8328dfa5
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_forwards.sql
@@ -0,0 +1,43 @@
+CREATE PROCEDURE eventuous.read_stream_forwards
+ @stream_name NVARCHAR(850),
+ @from_position INT,
+ @count INT
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ DECLARE
+ @current_version INT,
+ @stream_id INT;
+
+ SELECT
+ @current_version = [Version],
+ @stream_id = StreamId
+ FROM eventuous.Streams
+ WHERE StreamName = @stream_name;
+
+ IF @stream_id IS NULL
+ BEGIN
+ ;THROW 50001, 'StreamNotFound', 1;
+ END;
+
+ IF @current_version < @from_position
+ BEGIN
+ RETURN;
+ END;
+
+ SELECT TOP (@count)
+ MessageId,
+ MessageType,
+ StreamPosition,
+ GlobalPosition,
+ JsonData,
+ JsonMetadata,
+ Created
+ FROM eventuous.Messages
+ WHERE StreamId = @stream_id
+ AND StreamPosition >= @from_position
+ ORDER BY StreamPosition;
+
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_sub.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_sub.sql
new file mode 100644
index 00000000..16cb2c66
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/read_stream_sub.sql
@@ -0,0 +1,24 @@
+CREATE PROCEDURE eventuous.read_stream_sub
+ @stream_id INT,
+ @stream_name NVARCHAR(850),
+ @from_position INT,
+ @count INT
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ SELECT TOP (@count)
+ MessageId,
+ MessageType,
+ StreamPosition,
+ GlobalPosition,
+ JsonData,
+ JsonMetadata,
+ Created,
+ @stream_name StreamName
+ FROM eventuous.Messages
+ WHERE StreamId = @stream_id
+ AND StreamPosition >= @from_position
+ ORDER BY GlobalPosition;
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/truncate_stream.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/truncate_stream.sql
new file mode 100644
index 00000000..09d23d80
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Procedures/truncate_stream.sql
@@ -0,0 +1,41 @@
+CREATE PROCEDURE eventuous.truncate_stream
+ @stream_name NVARCHAR(850),
+ @expected_version INT,
+ @position INT
+AS
+BEGIN
+ SET NOCOUNT ON;
+ SET XACT_ABORT ON;
+
+ DECLARE
+ @current_version INT,
+ @stream_id INT;
+
+ SELECT
+ @current_version = [Version],
+ @stream_id = StreamId
+ FROM eventuous.Streams
+ WHERE StreamName = @stream_name;
+
+ IF @stream_id IS NULL
+ BEGIN
+ ;THROW 50001, 'StreamNotFound', 1;
+ END;
+
+ IF @current_version < @position
+ BEGIN
+ RETURN;
+ END;
+
+ IF @expected_version != -2 AND @expected_version != @current_version
+ BEGIN
+ DECLARE @customMessage NVARCHAR(4000);
+ SELECT @customMessage = FORMATMESSAGE(N'WrongExpectedVersion %i, current version %i', @expected_version, @current_version);
+ ;THROW 50000, @customMessage, 1;
+ END;
+
+ DELETE m
+ FROM eventuous.Messages m
+ WHERE m.StreamId = @stream_id
+ AND m.StreamPosition < @position;
+END;
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Schemas/Eventuous.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Schemas/Eventuous.sql
new file mode 100644
index 00000000..5ee4a74a
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Schemas/Eventuous.sql
@@ -0,0 +1,2 @@
+CREATE SCHEMA eventuous AUTHORIZATION dbo;
+GO
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/StaticCodeAnalysis.SuppressMessages.xml b/src/SqlServer/src/Eventuous.SqlServer.Database/StaticCodeAnalysis.SuppressMessages.xml
new file mode 100644
index 00000000..3d7e1ecf
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/StaticCodeAnalysis.SuppressMessages.xml
@@ -0,0 +1,24 @@
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Checkpoints.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Checkpoints.sql
new file mode 100644
index 00000000..f65fcd28
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Checkpoints.sql
@@ -0,0 +1,6 @@
+CREATE TABLE eventuous.Checkpoints (
+ Id NVARCHAR(128) NOT NULL,
+ Position BIGINT NULL,
+ CONSTRAINT PK_Checkpoints PRIMARY KEY CLUSTERED (Id),
+);
+GO
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Messages.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Messages.sql
new file mode 100644
index 00000000..b90f4339
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Messages.sql
@@ -0,0 +1,19 @@
+CREATE TABLE eventuous.Messages (
+ MessageId UNIQUEIDENTIFIER NOT NULL,
+ MessageType NVARCHAR(128) NOT NULL,
+ StreamId INT NOT NULL,
+ StreamPosition INT NOT NULL,
+ GlobalPosition BIGINT IDENTITY (0,1) NOT NULL,
+ JsonData NVARCHAR(MAX) NOT NULL,
+ JsonMetadata NVARCHAR(MAX) NOT NULL,
+ Created DATETIME2(7) NOT NULL,
+ CONSTRAINT PK_Events PRIMARY KEY CLUSTERED (GlobalPosition) WITH (OPTIMIZE_FOR_SEQUENTIAL_KEY = ON),
+ CONSTRAINT FK_MessageStreamId FOREIGN KEY (StreamId) REFERENCES eventuous.Streams (StreamId),
+ CONSTRAINT UQ_StreamIdAndStreamPosition UNIQUE NONCLUSTERED (StreamId, StreamPosition),
+ CONSTRAINT UQ_StreamIdAndMessageId UNIQUE NONCLUSTERED (StreamId, MessageId),
+ CONSTRAINT CK_StreamPositionGteZero CHECK (StreamPosition >= 0),
+ CONSTRAINT CK_JsonDataIsJson CHECK (ISJSON(JsonData) = 1),
+ CONSTRAINT CK_JsonMetadataIsJson CHECK (ISJSON(JsonMetadata) = 1),
+ INDEX IDX_EventsStream (StreamId)
+);
+GO
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Streams.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Streams.sql
new file mode 100644
index 00000000..ebc5b194
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Tables/Streams.sql
@@ -0,0 +1,9 @@
+CREATE TABLE eventuous.Streams (
+ StreamId INT IDENTITY (1,1) NOT NULL,
+ StreamName NVARCHAR(850) NOT NULL,
+ [Version] INT DEFAULT (-1) NOT NULL,
+ CONSTRAINT PK_Streams PRIMARY KEY CLUSTERED (StreamId) WITH (OPTIMIZE_FOR_SEQUENTIAL_KEY = ON),
+ CONSTRAINT UQ_StreamName UNIQUE NONCLUSTERED (StreamName),
+ CONSTRAINT CK_VersionGteNegativeOne CHECK ([Version] >= -1)
+);
+GO
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/Types/StreamMessage.sql b/src/SqlServer/src/Eventuous.SqlServer.Database/Types/StreamMessage.sql
new file mode 100644
index 00000000..2bc99e08
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/Types/StreamMessage.sql
@@ -0,0 +1,7 @@
+CREATE type eventuous.StreamMessage AS TABLE (
+ message_id UNIQUEIDENTIFIER NOT NULL,
+ message_type NVARCHAR(128) NOT NULL,
+ json_data NVARCHAR(MAX) NOT NULL,
+ json_metadata NVARCHAR(MAX) NOT NULL
+);
+GO
\ No newline at end of file
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/docker/Dockerfile.db-from-dacpac b/src/SqlServer/src/Eventuous.SqlServer.Database/docker/Dockerfile.db-from-dacpac
new file mode 100644
index 00000000..3fa2c4b5
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/docker/Dockerfile.db-from-dacpac
@@ -0,0 +1,53 @@
+FROM mcr.microsoft.com/dotnet/sdk:8.0-alpine AS publish
+WORKDIR /src
+
+# System deps in one layer, no cache files
+# package required for:
+# building DacFx-style dacpac
+# bash is added to run entrypoint.sh
+RUN apk add --no-cache \
+ bash \
+ krb5-libs
+
+COPY Directory.Packages.props ./Directory.Packages.props
+COPY src/SqlServer/src/Eventuous.SqlServer.Database /src/Eventuous.SqlServer.Database
+
+# Build Eventuous.SqlServer.Database project.
+# Eventuous.SqlServer.Database.dacpac will land in the /output directory as a result.
+RUN dotnet restore /src/Eventuous.SqlServer.Database/Eventuous.SqlServer.Database.csproj && \
+ dotnet build /src/Eventuous.SqlServer.Database/Eventuous.SqlServer.Database.csproj \
+ -c Release \
+ -o /output \
+ --no-restore
+
+FROM mcr.microsoft.com/mssql/server:2022-CU21-ubuntu-22.04
+
+ENV MSSQL_SA_PASSWORD=Password1! \
+ ACCEPT_EULA=Y
+
+USER root
+
+ADD https://aka.ms/sqlpackage-linux /tmp/sqlpackage.zip
+
+RUN apt-get update && \
+ apt-get install -y --no-install-recommends \
+ curl dotnet-runtime-8.0 gnupg p7zip-full && \
+ curl -fsSL https://packages.microsoft.com/keys/microsoft.asc | gpg --dearmor -o /usr/share/keyrings/ms.gpg && \
+ echo "deb [signed-by=/usr/share/keyrings/ms.gpg] https://packages.microsoft.com/ubuntu/22.04/prod jammy main" > /etc/apt/sources.list.d/msprod.list && \
+ apt-get update && \
+ ACCEPT_EULA=Y apt-get install -y --no-install-recommends msodbcsql18 mssql-tools18 && \
+ rm -rf /var/lib/apt/lists/*
+
+ENV PATH="/opt/mssql-tools18/bin:${PATH}"
+
+ADD https://aka.ms/sqlpackage-linux /tmp/sqlpackage.zip
+RUN mkdir -p /opt/sqlpackage && 7z x /tmp/sqlpackage.zip -o/opt/sqlpackage && \
+ chmod +x /opt/sqlpackage/sqlpackage && rm /tmp/sqlpackage.zip
+
+# Copying the entrypoint.sh script.
+COPY --chmod=755 src/SqlServer/src/Eventuous.SqlServer.Database/docker/entrypoint.sh /entrypoint.sh
+
+# Copy the built .dacpac from the first stage
+COPY --from=publish /output/*.dacpac /tmp/db/
+
+ENTRYPOINT ["bash", "/entrypoint.sh"]
diff --git a/src/SqlServer/src/Eventuous.SqlServer.Database/docker/entrypoint.sh b/src/SqlServer/src/Eventuous.SqlServer.Database/docker/entrypoint.sh
new file mode 100644
index 00000000..9fd86430
--- /dev/null
+++ b/src/SqlServer/src/Eventuous.SqlServer.Database/docker/entrypoint.sh
@@ -0,0 +1,88 @@
+#!/usr/bin/env bash
+set -euo pipefail
+
+# ANSI colors
+RED='\033[0;31m'
+GREEN='\033[0;32m'
+YELLOW='\033[1;33m'
+CYAN='\033[0;36m'
+RESET='\033[0m'
+
+# Get SA password from environment
+MSSQL_SA_PASSWORD=${MSSQL_SA_PASSWORD:?"${RED}Missing MSSQL_SA_PASSWORD environment variable${RESET}"}
+
+# Ensure SQL Server's persistent directories exist on a fresh/empty volume.
+# Without these, redirection to /var/opt/mssql/log/... will fail and SQL won't start.
+mkdir -p /var/opt/mssql/{data,log}
+
+# Make sure the mssql user owns the directories so sqlservr can read/write.
+# Keep this if the container starts as root; you can omit it if you run as the mssql user.
+chown -R mssql:mssql /var/opt/mssql
+
+
+# Start SQL Server and grab its PID
+echo -e "${CYAN}[entrypoint] Launching SQL Server...${RESET}"
+
+# SQL Server is extremely verbose during bootup, we we're just going to completely silence it here.
+/opt/mssql/bin/sqlservr >/var/opt/mssql/log/sqlservr.console 2>&1 &
+SQL_PID=$!
+
+# However, we still want to be notified when problems occur.
+tail -F /var/opt/mssql/log/errorlog --pid $SQL_PID -v 2> /dev/null | grep -E 'Error:|Severity:' >&2 &
+
+# Poll until the server is ready
+echo -e "${YELLOW}[entrypoint] Waiting for SQL Server to accept connections...${RESET}"
+until /opt/mssql-tools18/bin/sqlcmd \
+ -S localhost \
+ -U sa \
+ -P "$MSSQL_SA_PASSWORD" \
+ -C \
+ -d master \
+ -Q "SELECT 1" &>/dev/null; do
+ sleep 1
+ echo -e "${YELLOW}[entrypoint] Retrying SQL Server connection...${RESET}"
+done
+
+echo -e "${GREEN}[entrypoint] SQL Server is ready!${RESET}"
+
+# Configure and create DB
+echo -e "${CYAN}[entrypoint] Applying configuration and creating database...${RESET}"
+EXECUTE_SQL="/opt/mssql-tools18/bin/sqlcmd -C -I -b -S localhost -U sa -P $MSSQL_SA_PASSWORD"
+$EXECUTE_SQL -d master -Q "
+ EXEC sp_configure 'clr enabled', 1;
+ EXEC sp_configure 'show advanced options', 1;
+ RECONFIGURE;
+ EXEC sp_configure 'clr strict security', 0;
+ RECONFIGURE;
+
+ IF DB_ID('Eventuous') IS NULL
+ BEGIN
+ CREATE DATABASE Eventuous;
+ END;
+"
+
+# Publish the DACPAC
+echo -e "${CYAN}[entrypoint] Database Eventuous created. Publishing DACPAC...${RESET}"
+cd /opt/sqlpackage
+./sqlpackage /q:True /a:Publish \
+ /tsn:localhost /tdn:Eventuous \
+ /tu:sa /tp:$MSSQL_SA_PASSWORD \
+ /sf:/tmp/db/Eventuous.SqlServer.Database.dacpac \
+ /TargetEncryptConnection:False /ttsc:true \
+ /p:ExcludeObjectTypes="Assemblies;Files;Logins;Users;Credentials;ApplicationRoles;DatabaseRoles;RoleMembership;ServerRoleMembership;ServerRoles;Certificates;MasterKeys;SymmetricKeys;DatabaseOptions;Permissions;" \
+ /p:DropObjectsNotInSource=True \
+ /p:BlockOnPossibleDataLoss=False
+
+# Mark health
+echo -e "${GREEN}[entrypoint] Eventuous database DACPAC publication complete.${RESET}"
+touch /tmp/db/.ready
+
+# Keep container alive
+echo -e "\n${CYAN}[entrypoint] Waiting indefinitely. You can connect to this database server in SSMS now, as needed.${RESET}"
+echo -e "${CYAN}[entrypoint] SSMS connect to:${RESET}"
+echo -e " ${YELLOW}Server: localhost,11433${RESET}"
+echo -e " ${YELLOW}Username: sa${RESET}"
+echo -e " ${YELLOW}Password: $MSSQL_SA_PASSWORD${RESET}"
+echo -e "\n${CYAN}Ctrl+C to stop the server and exit the container${RESET}"
+
+exec bash # interactive shell
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/.gitignore b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/.gitignore
new file mode 100644
index 00000000..5238404f
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/.gitignore
@@ -0,0 +1 @@
+/Post-Deployment/AutoGeneratedPostDeploy.sql
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Eventuous.Tests.SqlServer.Database.csproj b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Eventuous.Tests.SqlServer.Database.csproj
new file mode 100644
index 00000000..e7822f47
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Eventuous.Tests.SqlServer.Database.csproj
@@ -0,0 +1,44 @@
+
+
+ net8.0
+ Sql160
+
+
+ Post-Deployment
+
+ AutoGeneratedPostDeploy.sql
+
+ $(PostDeployFolder)\$(AutoPostDeployFile)
+
+
+ C:\Program Files\Git\bin\bash.exe
+
+ /bin/bash
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Post-Deployment/generate-postdeploy.sh b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Post-Deployment/generate-postdeploy.sh
new file mode 100644
index 00000000..cfa89065
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Post-Deployment/generate-postdeploy.sh
@@ -0,0 +1,24 @@
+#!/usr/bin/env bash
+set -euo pipefail
+
+# where this script lives
+SCRIPT_DIR="$(cd "$(dirname "$0")" && pwd)"
+# one level up is your project root
+ROOT_DIR="$(cd "$SCRIPT_DIR/.." && pwd)"
+
+OUT_FILE="${1:-$SCRIPT_DIR/AutoGeneratedPostDeploy.sql}"
+TARGET_DIR="$(dirname "$OUT_FILE")"
+
+mkdir -p "$TARGET_DIR"
+
+cat <<'EOF' > "$OUT_FILE"
+-- This file is auto-generated by running generate-postdeploy.sh; do NOT hand-edit
+EOF
+
+find "$ROOT_DIR/Tests" -type f -name '*.sql' | sort \
+ | while IFS= read -r file; do
+ rel="${file#"$ROOT_DIR/Tests"/}"
+ echo ":r ../Tests/$rel" >> "$OUT_FILE"
+ done
+
+echo "✅ Wrote $OUT_FILE"
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Checkpoints.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Checkpoints.sql
new file mode 100644
index 00000000..96720308
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Checkpoints.sql
@@ -0,0 +1,26 @@
+EXEC tSQLt.NewTestClass 'Checkpoints';
+GO
+
+CREATE PROCEDURE Checkpoints.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Checkpoints';
+END;
+GO
+
+CREATE PROCEDURE Checkpoints.[Test UQ_eventuous_Checkpoints_Id violation ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Checkpoints','PK_Checkpoints';
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'Violation of PRIMARY KEY constraint ''PK_Checkpoints''. Cannot insert duplicate key in object ''eventuous.Checkpoints''. The duplicate key value is (1).';
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Checkpoints (Id)
+ VALUES (1), (1);
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'Checkpoints' -- Don't check in
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Messages.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Messages.sql
new file mode 100644
index 00000000..699e8412
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Messages.sql
@@ -0,0 +1,88 @@
+EXEC tSQLt.NewTestClass 'Messages';
+GO
+
+CREATE PROCEDURE Messages.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE Messages.[Test StreamPosition is invalid json ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Messages','CK_StreamPositionGteZero';
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'The INSERT statement conflicted with the CHECK constraint "CK_StreamPositionGteZero". The conflict occurred in database "Eventuous", table "eventuous.Messages", column ''StreamPosition''.'
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Messages (StreamPosition)
+ VALUES (-1);
+END;
+GO
+
+CREATE PROCEDURE Messages.[Test CK_eventuous_Messages_JsonData violation ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Messages','CK_JsonDataIsJson';
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'The INSERT statement conflicted with the CHECK constraint "CK_JsonDataIsJson". The conflict occurred in database "Eventuous", table "eventuous.Messages", column ''JsonData''.'
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Messages (JsonData)
+ VALUES (N'invalid');
+END;
+GO
+
+CREATE PROCEDURE Messages.[Test CK_eventuous_Messages_JsonMetadata violation ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Messages','CK_JsonMetadataIsJson';
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'The INSERT statement conflicted with the CHECK constraint "CK_JsonMetadataIsJson". The conflict occurred in database "Eventuous", table "eventuous.Messages", column ''JsonMetadata''.'
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Messages (JsonMetadata)
+ VALUES (N'invalid');
+END;
+GO
+
+CREATE PROCEDURE Messages.[Test UQ_eventuous_Messages_StreamId_StreamPosition violoation ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Messages','UQ_StreamIdAndStreamPosition';
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'Violation of UNIQUE KEY constraint ''UQ_StreamIdAndStreamPosition''. Cannot insert duplicate key in object ''eventuous.Messages''. The duplicate key value is (1, 0).'
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Messages (StreamId, StreamPosition)
+ VALUES (1, 0), (1, 0);
+END;
+GO
+
+CREATE PROCEDURE Messages.[Test UQ_eventuous_Messages_StreamId_MessageId violation ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Messages','UQ_StreamIdAndMessageId';
+
+ DECLARE @messageId UNIQUEIDENTIFIER = NEWID();
+
+ DECLARE @ExpectedMessage VARCHAR(256) = CONCAT('Violation of UNIQUE KEY constraint ''UQ_StreamIdAndMessageId''. Cannot insert duplicate key in object ''eventuous.Messages''. The duplicate key value is (1, ', @messageId, ').');
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Messages (StreamId, MessageId)
+ VALUES (1, @messageId), (1, @messageId);
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'Messages' -- Don't check in
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Streams.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Streams.sql
new file mode 100644
index 00000000..3f1e7abf
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/Streams.sql
@@ -0,0 +1,26 @@
+EXEC tSQLt.NewTestClass 'Streams';
+GO
+
+CREATE PROCEDURE Streams.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE Streams.[Test CK_eventuous_Streams_Version violation ExpectExcepton]
+AS
+BEGIN
+
+ EXEC tSQLt.ApplyConstraint 'eventuous.Streams','CK_VersionGteNegativeOne';
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'The INSERT statement conflicted with the CHECK constraint "CK_VersionGteNegativeOne". The conflict occurred in database "Eventuous", table "eventuous.Streams", column ''Version''.';
+ EXEC tSQLt.ExpectException @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ INSERT INTO eventuous.Streams ([Version])
+ VALUES (-2);
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'Streams' -- Don't check in
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/append_events.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/append_events.sql
new file mode 100644
index 00000000..d43c5924
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/append_events.sql
@@ -0,0 +1,170 @@
+EXEC tSQLt.NewTestClass 'append_events';
+GO
+
+CREATE PROCEDURE append_events.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams', @Identity = 1;
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE append_events.[Test single message]
+AS
+BEGIN
+ DECLARE
+ @stream_name VARCHAR(850) = 'Receipt-1',
+ @expected_version INT = -1, -- NoStream
+ @created DATETIME2(7) = SYSUTCDATETIME(),
+ @messages eventuous.StreamMessage;
+
+ INSERT INTO @messages (message_id, message_type, json_data, json_metadata)
+ VALUES
+ (
+ NEWID(),
+ N'V1.Receipt.Started',
+ N'{"userId":201}', N'{"trace-id":"f685468b5c11308e025ef8fbb88b2719","span-id":"46fdb35780d6a129","parent-span-id":"88859bf9294597b6"}'
+ );
+
+ EXEC eventuous.append_events
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @created = @created,
+ @messages = @messages;
+
+ SELECT StreamName,
+ Version
+ INTO #ActualStreams
+ FROM eventuous.Streams;
+
+ SELECT TOP (0) *
+ INTO #ExpectedStreams
+ FROM #ActualStreams;
+
+ INSERT INTO #ExpectedStreams (StreamName, Version)
+ VALUES (@stream_name, 0);
+
+ SELECT GlobalPosition,
+ MessageId,
+ MessageType,
+ StreamId,
+ StreamPosition,
+ JsonData,
+ JsonMetadata,
+ Created
+ INTO #ActualMessages
+ FROM eventuous.Messages;
+
+ SELECT TOP (0) *
+ INTO #ExpectedMessages
+ FROM #ActualMessages;
+
+ INSERT INTO #ExpectedMessages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ SELECT
+ message_id,
+ message_type,
+ 1,
+ 0,
+ json_data,
+ json_metadata,
+ @created
+ FROM @messages;
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedStreams', @Actual = N'#ActualStreams';
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedMessages', @Actual = N'#ActualMessages';
+
+END;
+GO
+
+CREATE PROCEDURE append_events.[Test multiple messages]
+AS
+BEGIN
+
+ DECLARE
+ @stream_name VARCHAR(850) = 'Receipt-1',
+ @expected_version INT = -1, -- NoStream
+ @created DATETIME2(7) = SYSUTCDATETIME(),
+ @messages eventuous.StreamMessage;
+
+ INSERT INTO @messages (message_id, message_type, json_data, json_metadata)
+ VALUES
+ (
+ NEWID(),
+ N'V1.Receipt.Started',
+ N'{"userId":201}',
+ N'{"trace-id":"f685468b5c11308e025ef8fbb88b2719","span-id":"46fdb35780d6a129","parent-span-id":"88859bf9294597b6"}'
+ ),
+
+ (
+ NEWID(),
+ N'V1.Receipt.LineAdjusted',
+ N'{"userId":201,"itemId":8,"quantity":20,"binDescription":"CheckIn"}',
+ N'{"trace-id":"3cd6a40c9a41735df627244506a9c6b3","span-id":"0497917daefb11e4","parent-span-id":"194f872000aacabe"}'
+ );
+
+ EXEC eventuous.append_events
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @created = @created,
+ @messages = @messages;
+
+ /* Assert Streams */
+ SELECT StreamName,
+ [Version]
+ INTO #ActualStreams
+ FROM eventuous.Streams;
+
+ SELECT TOP (0) *
+ INTO #ExpectedStreams
+ FROM #ActualStreams;
+
+ INSERT INTO #ExpectedStreams (StreamName, [Version])
+ VALUES (@stream_name, 1);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedStreams', @Actual = N'#ActualStreams';
+
+ /* Assert Messages */
+ SELECT GlobalPosition,
+ MessageId,
+ MessageType,
+ StreamId,
+ StreamPosition,
+ JsonData,
+ JsonMetadata,
+ Created
+ INTO #ActualMessages
+ FROM eventuous.Messages;
+
+ SELECT TOP (0) *
+ INTO #ExpectedMessages
+ FROM #ActualMessages;
+
+ INSERT INTO #ExpectedMessages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ SELECT
+ message_id,
+ message_type,
+ 1,
+ 0, -- 0
+ json_data,
+ json_metadata,
+ @created
+ FROM @messages
+ WHERE message_type = 'V1.Receipt.Started';
+
+ INSERT INTO #ExpectedMessages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ SELECT
+ message_id,
+ message_type,
+ 1,
+ 1, -- 1
+ json_data,
+ json_metadata,
+ @created
+ FROM @messages
+ WHERE message_type = 'V1.Receipt.LineAdjusted';
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedMessages', @Actual = N'#ActualMessages';
+
+END;
+GO
+-- EXEC tsqlt.RunTestClass 'append_events' -- Don't check in
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/check_stream.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/check_stream.sql
new file mode 100644
index 00000000..90e79843
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/check_stream.sql
@@ -0,0 +1,130 @@
+EXEC tSQLt.NewTestClass 'check_stream';
+GO
+
+CREATE PROCEDURE check_stream.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE check_stream.[Test happy path Any]
+AS
+BEGIN
+ DECLARE
+ @stream_name VARCHAR(850) = 'Receipt-1',
+ @expected_version INT = -2, -- Any
+ @current_version INT,
+ @stream_id INT;
+
+ EXEC eventuous.check_stream
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @current_version = @current_version,
+ @stream_id = @stream_id;
+
+ /* Assert Streams */
+ SELECT StreamName,
+ [Version]
+ INTO #ActualStreams
+ FROM eventuous.Streams;
+
+ SELECT TOP (0) *
+ INTO #ExpectedStreams
+ FROM #ActualStreams;
+
+ INSERT INTO #ExpectedStreams (StreamName, [Version])
+ VALUES (@stream_name, -1);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedStreams', @Actual = N'#ActualStreams';
+
+END;
+GO
+
+CREATE PROCEDURE check_stream.[Test happy path NoStream]
+AS
+BEGIN
+ DECLARE
+ @stream_name VARCHAR(850) = 'Receipt-1',
+ @expected_version INT = -1, -- NoStream
+ @current_version INT,
+ @stream_id INT;
+
+ EXEC eventuous.check_stream
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @current_version = @current_version,
+ @stream_id = @stream_id;
+
+ /* Assert Streams */
+ SELECT StreamName,
+ [Version]
+ INTO #ActualStreams
+ FROM eventuous.Streams;
+
+ SELECT TOP (0) *
+ INTO #ExpectedStreams
+ FROM #ActualStreams;
+
+ INSERT INTO #ExpectedStreams (StreamName, [Version])
+ VALUES (@stream_name, -1);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedStreams', @Actual = N'#ActualStreams';
+
+END;
+GO
+
+CREATE PROCEDURE check_stream.[Test stream not found ExpectException]
+AS
+BEGIN
+ DECLARE
+ @stream_name VARCHAR(850) = 'Receipt-1',
+ @expected_version INT = -500, --trouble
+ @current_version INT,
+ @stream_id INT;
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'StreamNotFound'
+ EXEC tSQLt.ExpectException
+ @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+
+ EXEC eventuous.check_stream
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @current_version = @current_version,
+ @stream_id = @stream_id;
+END;
+GO
+
+CREATE PROCEDURE check_stream.[Test stream exists wrong version ExpectExcepton]
+AS
+BEGIN
+ DECLARE
+ @stream_name VARCHAR(850) = 'Receipt-1',
+ @expected_version INT = 20, --trouble
+ @current_version INT = 21, --trouble
+ @stream_id INT;
+
+ INSERT INTO eventuous.Streams (StreamName, [Version])
+ VALUES(
+ @stream_name,
+ @expected_version + 1 -- Trouble
+ );
+
+ DECLARE @ExpectedMessage VARCHAR(256) = CONCAT('WrongExpectedVersion ', @expected_version, ', current version ', @current_version)
+ EXEC tSQLt.ExpectException
+ @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+
+ EXEC eventuous.check_stream
+ @stream_name = @stream_name,
+ @expected_version = @expected_version,
+ @current_version = @current_version,
+ @stream_id = @stream_id;
+
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'check_stream' -- Don't check in
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_all_forwards.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_all_forwards.sql
new file mode 100644
index 00000000..0ea865f4
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_all_forwards.sql
@@ -0,0 +1,83 @@
+EXEC tSQLt.NewTestClass 'read_all_forwards';
+GO
+
+CREATE PROCEDURE read_all_forwards.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams';
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE read_all_forwards.[Test single message]
+AS
+BEGIN
+
+ DECLARE
+ @streamName_1 NVARCHAR (850) = 'Receipt-1',
+ @streamId_1 INT = 1,
+ @streamName_2 NVARCHAR (850) = 'Bin-8',
+ @streamId_2 INT = 2;
+
+ INSERT INTO eventuous.Streams (StreamId, StreamName)
+ VALUES
+ (@streamId_1, @streamName_1),
+ (@streamId_2, @streamName_2);
+
+ INSERT INTO eventuous.Messages (MessageType, StreamId, StreamPosition)
+ VALUES
+ ('First', @streamId_1, 0),
+ ('First', @streamId_2, 0),
+ ('Second', @streamId_2, 1),
+ ('Second', @streamId_1, 1);
+
+
+ CREATE TABLE #ProcResult (
+ MessageId UNIQUEIDENTIFIER,
+ MessageType NVARCHAR(128),
+ StreamPosition INT,
+ GlobalPosition BIGINT,
+ JsonData NVARCHAR(MAX),
+ JsonMetadata NVARCHAR(MAX),
+ Created DATETIME2(7),
+ StreamName NVARCHAR(850)
+ );
+
+ -- Starting at 1 and getting 2 Messages means we will only get the middle 2 eventuous.Messages that we inserted above. Assert that.
+ DECLARE
+ @from_position BIGINT = 1,
+ @count INT = 2;
+
+ INSERT INTO #ProcResult
+ EXEC eventuous.read_all_forwards
+ @from_position = @from_position,
+ @count = @count;
+
+ SELECT
+ --MessageId, not asserting the GUID
+ MessageType,
+ StreamPosition,
+ GlobalPosition,
+ JsonData,
+ JsonMetadata,
+ -- Created, -- not asserting the SYSUTCDATETIME()
+ StreamName
+ INTO #ActualResult
+ FROM #ProcResult;
+
+ SELECT TOP (0) *
+ INTO #ExpectedResult
+ FROM #ActualResult;
+
+ -- we will only get the middle 2 eventuous.Messages that we inserted above
+ INSERT INTO #ExpectedResult (MessageType, StreamPosition, GlobalPosition, StreamName)
+ VALUES
+ ('First', 0, 1, @streamName_2),
+ ('Second', 1, 2, @streamName_2);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedResult', @Actual = N'#ActualResult';
+
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'read_all_forwards' -- Don't check in
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_backwards.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_backwards.sql
new file mode 100644
index 00000000..59e4c36e
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_backwards.sql
@@ -0,0 +1,80 @@
+EXEC tSQLt.NewTestClass 'read_stream_backwards';
+GO
+
+CREATE PROCEDURE read_stream_backwards.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams';
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE read_stream_backwards.[Test happy path reading backwards]
+AS
+BEGIN
+
+ DECLARE
+ @streamName_1 NVARCHAR (850) = 'Receipt-1',
+ @streamId_1 INT = 1,
+ @streamName_2 NVARCHAR (850) = 'Bin-8',
+ @streamId_2 INT = 2;
+
+ INSERT INTO eventuous.Streams (StreamId, StreamName, [Version])
+ VALUES
+ (@streamId_1, @streamName_1, 1),
+ (@streamId_2, @streamName_2, 1);
+
+ INSERT INTO eventuous.Messages (MessageType, StreamId, StreamPosition)
+ VALUES
+ ('First', @streamId_1, 0),
+ ('First', @streamId_2, 0),
+ ('Second', @streamId_2, 1),
+ ('Second', @streamId_1, 1);
+
+ CREATE TABLE #ProcResult (
+ MessageId UNIQUEIDENTIFIER,
+ MessageType NVARCHAR(128),
+ StreamPosition INT,
+ GlobalPosition BIGINT,
+ JsonData NVARCHAR(MAX),
+ JsonMetadata NVARCHAR(MAX),
+ Created DATETIME2(7)
+ );
+
+ -- Starting at 1 and getting 2 Messages means we will only get the middle 2 eventuous.Messages that we inserted above. Assert that.
+ DECLARE
+ @stream_name NVARCHAR(850) = 'Bin-8',
+ @from_position BIGINT = 1,
+ @count INT = 2;
+
+ INSERT INTO #ProcResult
+ EXEC eventuous.read_stream_backwards
+ @stream_name = @stream_name,
+ @from_position = @from_position,
+ @count = @count;
+
+ SELECT
+ --MessageId, not asserting the GUID
+ MessageType,
+ StreamPosition,
+ GlobalPosition
+ -- Created, -- not asserting the SYSUTCDATETIME()
+ INTO #ActualResult
+ FROM #ProcResult;
+
+ SELECT TOP (0) *
+ INTO #ExpectedResult
+ FROM #ActualResult;
+
+ -- we will only get the middle 2 eventuous.Messages that we inserted above
+ INSERT INTO #ExpectedResult (MessageType, StreamPosition, GlobalPosition)
+ VALUES
+ ('First', 0, 1),
+ ('Second', 1, 2);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedResult', @Actual = N'#ActualResult';
+
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'read_stream_backwards' -- Don't check in
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_forwards.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_forwards.sql
new file mode 100644
index 00000000..e2a17328
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_forwards.sql
@@ -0,0 +1,79 @@
+EXEC tSQLt.NewTestClass 'read_stream_forwards';
+GO
+
+CREATE PROCEDURE read_stream_forwards.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams';
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE read_stream_forwards.[Test happy path reading forwards]
+AS
+BEGIN
+
+ DECLARE
+ @streamName_1 NVARCHAR (850) = 'Receipt-1',
+ @streamId_1 INT = 1,
+ @streamName_2 NVARCHAR (850) = 'Bin-8',
+ @streamId_2 INT = 2;
+
+ INSERT INTO eventuous.Streams (StreamId, StreamName, [Version])
+ VALUES
+ (@streamId_1, @streamName_1, 1),
+ (@streamId_2, @streamName_2, 1);
+
+ INSERT INTO eventuous.Messages (MessageType, StreamId, StreamPosition)
+ VALUES
+ ('First', @streamId_1, 0),
+ ('First', @streamId_2, 0),
+ ('Second', @streamId_2, 1),
+ ('Second', @streamId_1, 1);
+
+ CREATE TABLE #ProcResult (
+ MessageId UNIQUEIDENTIFIER,
+ MessageType NVARCHAR(128),
+ StreamPosition INT,
+ GlobalPosition BIGINT,
+ JsonData NVARCHAR(MAX),
+ JsonMetadata NVARCHAR(MAX),
+ Created DATETIME2(7)
+ );
+
+ -- Starting at 1 and getting 2 Messages means we will only get 1 eventuous.Messages that we inserted above. Assert that.
+ DECLARE
+ @stream_name NVARCHAR(850) = 'Bin-8',
+ @from_position BIGINT = 1,
+ @count INT = 2;
+
+ INSERT INTO #ProcResult
+ EXEC eventuous.read_stream_forwards
+ @stream_name = @stream_name,
+ @from_position = @from_position,
+ @count = @count;
+
+ SELECT
+ --MessageId, not asserting the GUID
+ MessageType,
+ StreamPosition,
+ GlobalPosition
+ -- Created, -- not asserting the SYSUTCDATETIME()
+ INTO #ActualResult
+ FROM #ProcResult;
+
+ SELECT TOP (0) *
+ INTO #ExpectedResult
+ FROM #ActualResult;
+
+ -- we will only get 1 eventuous.Messages that we inserted above
+ INSERT INTO #ExpectedResult (MessageType, StreamPosition, GlobalPosition)
+ VALUES
+ ('Second', 1, 2);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedResult', @Actual = N'#ActualResult';
+
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'read_stream_forwards' -- Don't check in
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_sub.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_sub.sql
new file mode 100644
index 00000000..357c1d32
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/read_stream_sub.sql
@@ -0,0 +1,92 @@
+EXEC tSQLt.NewTestClass 'read_stream_sub';
+GO
+
+CREATE PROCEDURE read_stream_sub.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams';
+ -- Preserve identity so GlobalPosition auto-increments from the real seed (0)
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE read_stream_sub.[Test happy path subscription window]
+AS
+BEGIN
+ -- Arrange
+ DECLARE
+ @streamName_1 NVARCHAR (850) = 'Receipt-1',
+ @streamId_1 INT = 1,
+ @streamName_2 NVARCHAR (850) = 'Bin-8',
+ @streamId_2 INT = 2;
+
+ INSERT INTO eventuous.Streams (StreamId, StreamName, [Version])
+ VALUES
+ (@streamId_1, @streamName_1, 1),
+ (@streamId_2, @streamName_2, 1);
+
+ /*
+ Insert order determines GlobalPosition (seed 0):
+ GlobalPosition=0: (First, @streamId_1, pos 0)
+ GlobalPosition=1: (First, @streamId_2, pos 0)
+ GlobalPosition=2: (Second, @streamId_2, pos 1)
+ GlobalPosition=3: (Second, @streamId_1, pos 1)
+ */
+ INSERT INTO eventuous.Messages (MessageType, StreamId, StreamPosition)
+ VALUES
+ ('First', @streamId_1, 0),
+ ('First', @streamId_2, 0),
+ ('Second', @streamId_2, 1),
+ ('Second', @streamId_1, 1);
+
+ CREATE TABLE #ProcResult
+ (
+ MessageId UNIQUEIDENTIFIER,
+ MessageType NVARCHAR(128),
+ StreamPosition INT,
+ GlobalPosition BIGINT,
+ JsonData NVARCHAR(MAX),
+ JsonMetadata NVARCHAR(MAX),
+ Created DATETIME2(7),
+ StreamName NVARCHAR(850)
+ );
+
+ DECLARE
+ @stream_id INT = @streamId_1,
+ @stream_name NVARCHAR(850)= @streamName_1,
+ @from_position INT = 0,
+ @count INT = 2;
+
+ -- Act
+ INSERT INTO #ProcResult
+ EXEC eventuous.read_stream_sub
+ @stream_id = @stream_id,
+ @stream_name = @stream_name,
+ @from_position = @from_position,
+ @count = @count;
+
+ -- Project only the columns we want to assert
+ SELECT
+ MessageType,
+ StreamPosition,
+ GlobalPosition,
+ StreamName
+ INTO #ActualResult
+ FROM #ProcResult;
+
+ SELECT TOP (0) *
+ INTO #ExpectedResult
+ FROM #ActualResult;
+
+ -- Expect the two events from Receipt-1 at positions >= 0, in GlobalPosition order
+ INSERT INTO #ExpectedResult (MessageType, StreamPosition, GlobalPosition, StreamName)
+ VALUES
+ ('First', 0, 0, @stream_name), -- GlobalPosition 0
+ ('Second', 1, 3, @stream_name); -- GlobalPosition 3
+
+ -- Assert
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedResult', @Actual = N'#ActualResult';
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'read_stream_sub' -- Don't check in
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/truncate_stream.sql b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/truncate_stream.sql
new file mode 100644
index 00000000..ba6f41c4
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Tests/eventuous/truncate_stream.sql
@@ -0,0 +1,139 @@
+EXEC tSQLt.NewTestClass 'truncate_stream';
+GO
+
+CREATE PROCEDURE truncate_stream.Setup
+AS
+BEGIN
+ EXEC tSQLt.FakeTable 'eventuous.Streams', @Identity = 1;
+ EXEC tSQLt.FakeTable 'eventuous.Messages', @Identity = 1;
+END;
+GO
+
+CREATE PROCEDURE truncate_stream.[Test happy path to truncate a stream]
+AS
+BEGIN
+ DECLARE
+ @stream_name_1 VARCHAR(850) = 'Receipt-1',
+ @stream_name_2 VARCHAR(850) = 'Receipt-2',
+ @expected_version INT = 3,
+ @position INT = 2; -- keep messages at this position and greater than this position
+
+ INSERT eventuous.Streams (StreamName, Version)
+ VALUES
+ (@stream_name_1, @expected_version),
+ (@stream_name_2, 8);
+
+ INSERT INTO eventuous.Messages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ VALUES
+ (NEWID(), N'whatever', 1, 0, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 1, 1, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 1, 2, N'{}', N'{}', SYSUTCDATETIME());
+
+ INSERT INTO eventuous.Messages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ VALUES
+ (NEWID(), N'whatever', 2, 0, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 1, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 2, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 3, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 4, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 5, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 6, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 7, N'{}', N'{}', SYSUTCDATETIME());
+
+ EXEC eventuous.truncate_stream
+ @stream_name = @stream_name_1,
+ @expected_version = @expected_version,
+ @position = 2;
+
+ /* Assert Messages */
+ SELECT StreamId,
+ StreamPosition
+ INTO #ActualMessages
+ FROM eventuous.Messages;
+
+ SELECT TOP (0) *
+ INTO #ExpectedMessages
+ FROM #ActualMessages;
+
+ INSERT INTO #ExpectedMessages (StreamId, StreamPosition)
+ VALUES
+ --(1, 0), was truncated ✔️
+ --(1, 1), was truncated ✔️
+ (1, 2),
+ (2, 0),
+ (2, 1),
+ (2, 2),
+ (2, 3),
+ (2, 4),
+ (2, 5),
+ (2, 6),
+ (2, 7);
+
+ EXEC tSQLt.AssertEqualsTable @Expected = N'#ExpectedMessages', @Actual = N'#ActualMessages';
+
+END;
+GO
+
+CREATE PROCEDURE truncate_stream.[Test wrong expected version ExpectException]
+AS
+BEGIN
+ DECLARE
+ @stream_name_1 VARCHAR(850) = 'Receipt-1',
+ @stream_name_2 VARCHAR(850) = 'Receipt-2',
+ @current_version INT = 3,
+ @expected_version INT = 8,
+ @position INT = 2;
+
+ INSERT eventuous.Streams (StreamName, Version)
+ VALUES
+ (@stream_name_1, @current_version),
+ (@stream_name_2, 8);
+
+ INSERT INTO eventuous.Messages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ VALUES
+ (NEWID(), N'whatever', 1, 0, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 1, 1, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 1, 2, N'{}', N'{}', SYSUTCDATETIME());
+
+ INSERT INTO eventuous.Messages (MessageId, MessageType, StreamId, StreamPosition, JsonData, JsonMetadata, Created)
+ VALUES
+ (NEWID(), N'whatever', 2, 0, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 1, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 2, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 3, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 4, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 5, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 6, N'{}', N'{}', SYSUTCDATETIME()),
+ (NEWID(), N'whatever', 2, 7, N'{}', N'{}', SYSUTCDATETIME());
+
+ DECLARE @ExpectedMessage VARCHAR(256) = CONCAT('WrongExpectedVersion ', @expected_version, ', current version ', @current_version)
+ EXEC tSQLt.ExpectException
+ @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ EXEC eventuous.truncate_stream
+ @stream_name = @stream_name_1,
+ @expected_version = @expected_version,
+ @position = 2;
+
+END;
+GO
+
+CREATE PROCEDURE truncate_stream.[Test stream not found ExpectException]
+AS
+BEGIN
+
+ DECLARE @ExpectedMessage VARCHAR(256) = 'StreamNotFound'
+ EXEC tSQLt.ExpectException
+ @ExpectedMessage = @ExpectedMessage,
+ @ExpectedSeverity = NULL,
+ @ExpectedState = NULL;
+ EXEC eventuous.truncate_stream
+ @stream_name = 'Unknown',
+ @expected_version = 561,
+ @position = 87;
+
+END;
+GO
+
+-- EXEC tsqlt.RunTestClass 'truncate_stream' -- Don't check in
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/Dockerfile.eventuous-db-tsqlt-runner b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/Dockerfile.eventuous-db-tsqlt-runner
new file mode 100644
index 00000000..53b34491
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/Dockerfile.eventuous-db-tsqlt-runner
@@ -0,0 +1,91 @@
+FROM mcr.microsoft.com/dotnet/sdk:8.0-alpine AS publish
+WORKDIR /src
+
+# System deps in one layer, no cache files
+# package required for:
+# building DacFx-style dacpac
+# bash is added for the Eventuous.Tests.SqlServer.Database build, so that BeforeBuild generate-postdeploy.sh script can be run.
+RUN apk add --no-cache \
+ bash \
+ krb5-libs
+
+COPY nuget.config ./nuget.config
+COPY Directory.Packages.props ./Directory.Packages.props
+COPY src/SqlServer/src/Eventuous.SqlServer.Database /src/SqlServer/src/Eventuous.SqlServer.Database
+COPY src/SqlServer/test/Eventuous.Tests.SqlServer.Database /src/SqlServer/test/Eventuous.Tests.SqlServer.Database
+
+# Build Eventuous.Tests.SqlServer.Database project. The Eventuous.SqlServer.Database is a project reference so it is also built.
+# Eventuous.SqlServer.Database.dacpac and Eventuous.Tests.SqlServer.Database.dacpac will land in the /output directory as a result.
+RUN dotnet restore /src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Eventuous.Tests.SqlServer.Database.csproj \
+ --configfile nuget.config && \
+ dotnet build /src/SqlServer/test/Eventuous.Tests.SqlServer.Database/Eventuous.Tests.SqlServer.Database.csproj \
+ -c Release \
+ -o /output \
+ --no-restore
+
+# Clean up all source files now that /output holds everything we need
+WORKDIR /
+RUN rm -rf /src
+
+FROM mcr.microsoft.com/mssql/server:2022-CU21-ubuntu-22.04
+
+# allow SA password to be passed at build or runtime
+ARG MSSQL_SA_PASSWORD
+ENV ACCEPT_EULA=Y \
+ MSSQL_SA_PASSWORD=${MSSQL_SA_PASSWORD}
+
+USER root
+
+RUN apt-get update && \
+ apt-get install -y --no-install-recommends \
+ dotnet-runtime-8.0 \
+ p7zip-full && \
+ rm -rf /var/lib/apt/lists/*
+
+# SQL Package is required for installing the dacpacs
+# allow easy updates and proper cache busting when the URL or version changes
+ARG SQLPACKAGE_URL="https://aka.ms/sqlpackage-linux"
+RUN set -eux; \
+ # download only when URL or ARG changes
+ wget -qO /tmp/sqlpackage.zip "$SQLPACKAGE_URL"; \
+ mkdir -p /opt/sqlpackage; \
+ # extract only once, keep layer small by removing ZIP immediately
+ 7z x /tmp/sqlpackage.zip -o/opt/sqlpackage; \
+ rm /tmp/sqlpackage.zip; \
+ # fix permissions in one shot
+ chmod +x /opt/sqlpackage/sqlpackage
+
+# sqlfilter is used to facilitate these 2 existing sqlpackage params:
+# /p:AdditionalDeploymentContributors=AgileSqlClub.DeploymentFilterContributor /p:AdditionalDeploymentContributorArguments="SqlPackageFilter0=IgnoreSchema(tSQLt);"
+ARG SQLFILTER_URL="https://github.com/GoEddie/DeploymentContributorFilterer/releases/download/1.5.3/AgileSqlClub.SqlPackageFilter.1.5.3-netstandard2.1.zip"
+RUN set -eux; \
+ # download the filterer zip
+ wget -qO /tmp/sqlfilter.zip "${SQLFILTER_URL}"; \
+ # extract only once into a temp dir
+ 7z x /tmp/sqlfilter.zip -o/tmp; \
+ # ensure target exists and move in the DLLs
+ mkdir -p /opt/sqlpackage; \
+ mv /tmp/AgileSqlClub.SqlPackageFilter.1.5.3-netstandard2.1/* /opt/sqlpackage/; \
+ # clean up everything under /tmp
+ rm -rf /tmp/sqlfilter.zip /tmp/AgileSqlClub.SqlPackageFilter.1.5.3-netstandard2.1
+
+# tsqlt downloaded for a few sql files to be installed on the databases
+ADD https://tsqlt.org/download/tsqlt/ /tmp/tsqlt.zip
+
+RUN 7z x /tmp/tsqlt.zip \
+ tSQLt.class.sql \
+ PrepareServer.sql \
+ -o/opt/tsqlt && \
+ chown -R mssql:mssql /opt/tsqlt && \
+ rm /tmp/tsqlt.zip
+
+COPY src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/entrypoint.sh /entrypoint.sh
+RUN chmod +x /entrypoint.sh
+
+# pull files out of the earlier "publish" stage and into the current image
+# These dacpacs are then used within entrypoint.sh: Eventuous.SqlServer.Database.dacpac and Eventuous.Tests.SqlServer.Database.dacpac
+COPY --from=publish /output/Eventuous.SqlServer.Database.dacpac /tmp/db/Eventuous.SqlServer.Database.dacpac
+COPY --from=publish /output/Eventuous.Tests.SqlServer.Database.dacpac /tmp/db/Eventuous.Tests.SqlServer.Database.dacpac
+COPY --from=publish /output/master.dacpac /tmp/db/master.dacpac
+
+ENTRYPOINT ["/entrypoint.sh"]
\ No newline at end of file
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/README.md b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/README.md
new file mode 100644
index 00000000..de091f0a
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/README.md
@@ -0,0 +1,41 @@
+from `src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker`
+run the following:
+
+```sh
+docker compose up --build -d
+```
+
+You can then use SSMS to connect to the database:
+
+- Server: localhost,11433
+- Username: sa
+- Password: Password1!
+
+In another window from `src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker`
+run the following
+
+`run-class`
+```bash
+# Run all tests in a specific class
+docker compose run \
+ --rm --build \
+ eventuous-db-test-runner run-class append_events
+```
+
+`run`
+Run a single test by full test name
+```bash
+# Run a single test by full test name
+docker compose run \
+ --rm --build \
+ eventuous-db-test-runner run "[append_events].[Test multiple messages]"
+```
+
+`run-all`
+**not recommended** as it takes minutes to run all tests. Leave that up to CI build agents unless you really want to run all tests locally.
+```bash
+# Run all tSQLt tests
+docker compose run \
+ --rm --build \
+ eventuous-db-test-runner run-all
+```
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/docker-compose.yml b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/docker-compose.yml
new file mode 100644
index 00000000..f9df894a
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/docker-compose.yml
@@ -0,0 +1,41 @@
+services:
+ eventuous-db-from-dacpac:
+ build:
+ context: ../../../../../ # repo root (adjust depth to your tree)
+ dockerfile: src/SqlServer/src/Eventuous.SqlServer.Database/docker/Dockerfile.db-from-dacpac
+ image: eventuous-db-from-dacpac:latest
+ ports:
+ - 11433:1433
+ environment:
+ ACCEPT_EULA: Y
+ MSSQL_SA_PASSWORD: Password1!
+ tty: true
+ stdin_open: true
+ healthcheck:
+ test: ["CMD-SHELL", "test -f /tmp/db/.ready"]
+ interval: 10s
+ timeout: 5s
+ start_period: 30s
+ retries: 10
+ volumes:
+ - eventuous-db-from-dacpac_mssql:/var/opt/mssql
+ restart: unless-stopped
+ eventuous-db-test-runner:
+ build:
+ context: ../../../../../ # repo root (adjust depth to your tree)
+ dockerfile: src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/Dockerfile.eventuous-db-tsqlt-runner
+ depends_on:
+ eventuous-db-from-dacpac:
+ condition: service_healthy
+ profiles:
+ - testing
+ image: eventuous-db-tsqlt-runner:latest
+ environment:
+ MSSQL_SA_PASSWORD: Password1!
+ DB_SERVER: eventuous-db-from-dacpac
+ DB_PORT: 1433
+ tty: true # allocate a TTY so you can `run ... sh`
+ stdin_open: true # keep STDIN open
+
+volumes:
+ eventuous-db-from-dacpac_mssql:
diff --git a/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/entrypoint.sh b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/entrypoint.sh
new file mode 100644
index 00000000..a6512f7b
--- /dev/null
+++ b/src/SqlServer/test/Eventuous.Tests.SqlServer.Database/docker/entrypoint.sh
@@ -0,0 +1,127 @@
+#!/usr/bin/env bash
+set -euo pipefail
+
+
+# ANSI colors
+RED='\033[0;31m'
+GREEN='\033[0;32m'
+YELLOW='\033[1;33m'
+CYAN='\033[0;36m'
+RESET='\033[0m'
+
+# Get SA password from environment
+MSSQL_SA_PASSWORD=${MSSQL_SA_PASSWORD:?"${RED}Missing MSSQL_SA_PASSWORD environment variable${RESET}"}
+
+# Pick the command (default to run-all)
+MODE=${1:-run-all}
+shift || true # drop it if present
+
+echo -e "${CYAN}[entrypoint] Mode: ${MODE}${RESET}"
+
+# Determine SQL command
+case "$MODE" in
+ run-all)
+ SQL="EXEC tSQLt.RunAll"
+ ;;
+ run-class)
+ if [ -z "${1-}" ]; then
+ echo -e "${RED}[entrypoint] ERROR: you must supply a test class name${RESET}" >&2
+ echo -e "${YELLOW}Usage: $0 run-class ${RESET}" >&2
+ exit 1
+ fi
+ SQL="EXEC tSQLt.RunTestClass '$1'"
+ ;;
+ run)
+ if [ -z "${1-}" ]; then
+ echo -e "${RED}[entrypoint] ERROR: you must supply a test name${RESET}" >&2
+ echo -e "${YELLOW}Usage: $0 run ${RESET}" >&2
+ exit 1
+ fi
+ SQL="EXEC tSQLt.Run '$1'"
+ ;;
+ *)
+
+ cat <&2
+${YELLOW}Usage: $0 [run-all|run-class CLASS_NAME|run TEST_NAME]
+
+ run-all — execute EXEC tSQLt.RunAll
+ run-class NAME — execute EXEC tSQLt.RunTestClass 'NAME'
+ run NAME — execute EXEC tSQLt.Run 'NAME'${RESET}
+EOF
+ exit 1
+ ;;
+esac
+
+# Configure and create DB
+echo -e "${CYAN}[entrypoint] Applying configuration and creating database...${RESET}"
+EXECUTE_SQL="/opt/mssql-tools18/bin/sqlcmd -C -I -b -S $DB_SERVER,$DB_PORT -U sa -P $MSSQL_SA_PASSWORD"
+$EXECUTE_SQL -d master -Q "EXEC sp_configure 'clr enabled', 1; RECONFIGURE;"
+$EXECUTE_SQL -d master -Q "EXEC sp_configure 'show advanced options', 1; RECONFIGURE;"
+$EXECUTE_SQL -d master -Q "EXEC sp_configure 'clr strict security', 0; RECONFIGURE;"
+$EXECUTE_SQL -d master -Q "IF DB_ID('Eventuous') IS NULL BEGIN CREATE DATABASE Eventuous; END;"
+
+echo -e "${CYAN}[entrypoint] Running tSQLt PrepareServer.sql${RESET}"
+$EXECUTE_SQL -i /opt/tsqlt/PrepareServer.sql
+
+# Install tSQLt schema if missing
+for DB in Eventuous; do
+ echo -e "${YELLOW}[entrypoint] Checking for tSQLt schema in ${DB}${RESET}"
+ EXISTS=$(
+ $EXECUTE_SQL -d "${DB}" -h -1 -W \
+ -Q "SET NOCOUNT ON; IF EXISTS (SELECT 1 FROM sys.schemas WHERE name = N'tSQLt') SELECT 1 ELSE SELECT 0"
+ )
+ if [ "${EXISTS}" -eq 0 ]; then
+ echo -e "${GREEN}[entrypoint] Installing tSQLt into ${DB}${RESET}"
+ $EXECUTE_SQL -d "${DB}" -i /opt/tsqlt/tSQLt.class.sql
+ else
+ echo -e "${CYAN}[entrypoint] tSQLt already present in ${DB}, skipping.${RESET}"
+ fi
+done
+
+# Change directory to sqlpackage location
+echo -e "${CYAN}[entrypoint] Publishing databases via sqlpackage...${RESET}"
+cd /opt/sqlpackage
+
+# Deploy Eventuous database
+# This deploys the main database schema
+echo -e "${CYAN}[entrypoint] Publishing Eventuous.SqlServer.Database.dacpac to Eventuous database...${RESET}"
+./sqlpackage /q:True /a:Publish \
+ /tsn:eventuous-db-from-dacpac /tdn:Eventuous \
+ /tu:sa /tp:$MSSQL_SA_PASSWORD \
+ /sf:/tmp/db/Eventuous.SqlServer.Database.dacpac \
+ /TargetEncryptConnection:False \
+ /ttsc:true \
+ /p:ExcludeObjectTypes="Assemblies;Files;Logins;Users;Credentials;ApplicationRoles;DatabaseRoles;RoleMembership;ServerRoleMembership;ServerRoles;Certificates;MasterKeys;SymmetricKeys;DatabaseOptions;Permissions;" \
+ /p:DropObjectsNotInSource=True \
+ /p:BlockOnPossibleDataLoss=False \
+ /p:AdditionalDeploymentContributors=AgileSqlClub.DeploymentFilterContributor \
+ /p:AdditionalDeploymentContributorArguments="SqlPackageFilter0=IgnoreSchema(tSQLt);"
+
+echo -e "${GREEN}[entrypoint] Eventuous.SqlServer.Database.dacpac published.${RESET}"
+
+# Deploy tSQLt tests to Eventuous
+# Note:
+# We cannot use `DropObjectsNotInSource=True` when publishing the UnitTest dacpac,
+# because the tSQLt tests are created via SQLCMD in a post-deployment script, and
+# therefore aren't tracked by the dacpac. If we dropped objects not in source,
+# sqlpackage would remove all tSQLt tests.
+#
+echo -e "${CYAN}[entrypoint] Publishing Eventuous.Tests.SqlServer.Database.dacpac to Eventuous database...${RESET}"
+
+./sqlpackage /q:True /a:Publish \
+ /tsn:eventuous-db-from-dacpac /tdn:Eventuous \
+ /tu:sa /tp:$MSSQL_SA_PASSWORD \
+ /sf:/tmp/db/Eventuous.Tests.SqlServer.Database.dacpac \
+ /TargetEncryptConnection:False \
+ /ttsc:true \
+ /p:ExcludeObjectTypes="Assemblies;Files;Logins;Users;Credentials;ApplicationRoles;DatabaseRoles;RoleMembership;ServerRoleMembership;ServerRoles;Certificates;MasterKeys;SymmetricKeys;DatabaseOptions;Permissions;" \
+ /p:DropObjectsNotInSource=False \
+ /p:BlockOnPossibleDataLoss=False \
+ /p:AdditionalDeploymentContributors=AgileSqlClub.DeploymentFilterContributor \
+ /p:AdditionalDeploymentContributorArguments="SqlPackageFilter0=IgnoreSchema(tSQLt);"
+
+echo -e "${GREEN}[entrypoint] Eventuous.Tests.SqlServer.Database.dacpac published.${RESET}"
+
+# Run tests
+echo -e "${CYAN}[entrypoint] Running tests: ${SQL}${RESET}"
+$EXECUTE_SQL -d Eventuous -Q "$SQL;"