USE [DD_SYS] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- [PRDD_TEST_PERFORMANCE] -- ================================================================= -- Runs a configurable performance smoke test: creates a table, inserts data and queries it. -- Minimum requirement: MS SQL Server 2016 -- -- Returns: INT Value - 0 = Everything worked well -- ================================================================= -- Copyright (c) 2025 by Digital Data GmbH -- -- Digital Data GmbH Ludwig-Rinn-Strasse 16 D-35452 Heuchelheim -- Tel.: 0641/202360 E-Mail: info-flow@digitaldata.works -- ================================================================= -- Creation Date / Author: 15.12.2025 / MK -- Version Date / Editor: 23.12.2025 / MK -- Version Number: 1.1.0.1 -- ================================================================= -- History: -- 15.12.2025 / MK - First Version -- 23.12.2025 / MK - Add DATA_COMPRESSION = PAGE to log table PK, fix minor formatting, add pRANDOMDATA parameter CREATE OR ALTER PROCEDURE [dbo].[PRDD_TEST_PERFORMANCE] ( @pTARGETDB NVARCHAR(128) = NULL, -- Database to run the test against (defaults to current database) @pSCHEMA NVARCHAR(128) = 'dbo', -- Schema of the test table @pTABLENAME NVARCHAR(128) = 'TBDD_TEST_PERFORMANCE', -- Name of the test table to create/use @pROWCOUNT BIGINT = 1000000, -- Number of rows to insert @pBATCHSIZE BIGINT = 100000, -- Rows per batch; controls transaction size/log impact @pPADLENGTH INT = 100, -- Length of the CHAR padding column @pRANDOMDATA BIT = 0, -- 1 = insert randomized Payload/Pad values @pDROPANDRECREATE BIT = 1, -- Set to 1 to drop/recreate the table before inserting, otherwise reuse existing table @pLOGLEVEL NVARCHAR(25) = 'INFO' -- Set to 'INFO','WARN' or 'ERROR' (or NULL to disable) logging to table: [TBDD_TEST_PERFORMANCE_LOG] ) AS BEGIN --================================================-- Set session options --===============================================-- SET NOCOUNT ON; ---------------------------------------------------------------------------------------------------------------------------- --=========================================-- Parameter copies (avoid sniffing) --========================================-- DECLARE @TARGETDB NVARCHAR(128) = LTRIM(RTRIM(ISNULL(@pTARGETDB,DB_NAME()))), @SCHEMA NVARCHAR(128) = LTRIM(RTRIM(ISNULL(@pSCHEMA,'dbo'))), @TABLENAME NVARCHAR(128) = LTRIM(RTRIM(ISNULL(@pTABLENAME,'TBDD_TEST_PERFORMANCE'))), @ROWCOUNT BIGINT = ISNULL(@pROWCOUNT,1000000), @BATCHSIZE BIGINT = ISNULL(@pBATCHSIZE,100000), @PADLENGTH INT = ISNULL(@pPADLENGTH,100), @RANDOMDATA BIT = ISNULL(@pRANDOMDATA,0), @DROPANDRECREATE BIT = ISNULL(@pDROPANDRECREATE,1), @LOGLEVEL NVARCHAR(25) = UPPER(LTRIM(RTRIM(ISNULL(@pLOGLEVEL,'INFO')))); ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Declare runtime variables --========================================-- DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID); DECLARE @QualifiedTable NVARCHAR(300) = QUOTENAME(@SCHEMA) + '.' + QUOTENAME(@TABLENAME), @FullTable NVARCHAR(400) = QUOTENAME(@TARGETDB) + '.' + QUOTENAME(@SCHEMA) + '.' + QUOTENAME(@TABLENAME), @ProductVersion sql_variant, @ProductMainVersion INT, @ProductLevel sql_variant, @ProductEdition sql_variant, @SQLCommand NVARCHAR(MAX) = NULL, @RowsRemaining BIGINT = 0, @RowsInserted BIGINT = 0, @BatchStart BIGINT = 1, @BatchNumber INT = 0, @InsertStart DATETIME2(3) = NULL, @InsertEnd DATETIME2(3) = NULL, @return_status INT = 0, @return_status_text NVARCHAR(MAX) = 'START PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120), @return_error_text NVARCHAR(MAX) = ''; ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Failsafe settings --=================================================-- IF (@ROWCOUNT < 0) SET @ROWCOUNT = 0; IF (@BATCHSIZE <= 0) SET @BATCHSIZE = @ROWCOUNT; IF (@PADLENGTH < 1) SET @PADLENGTH = 1; IF (@LOGLEVEL NOT IN ('INFO','WARN','ERROR')) SET @LOGLEVEL = 'ERROR'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Output parameters --================================================-- PRINT '===================================================================================================='; PRINT @return_status_text; PRINT ''; PRINT 'PARAMETER01 - @TARGETDB: ' + CONVERT(NVARCHAR(128),@TARGETDB); PRINT 'PARAMETER02 - @SCHEMA: ' + CONVERT(NVARCHAR(128),@SCHEMA); PRINT 'PARAMETER03 - @TABLENAME: ' + CONVERT(NVARCHAR(128),@TABLENAME); PRINT 'PARAMETER04 - @ROWCOUNT: ' + CONVERT(NVARCHAR(100),@ROWCOUNT); PRINT 'PARAMETER05 - @BATCHSIZE: ' + CONVERT(NVARCHAR(100),@BATCHSIZE); PRINT 'PARAMETER06 - @PADLENGTH: ' + CONVERT(NVARCHAR(100),@PADLENGTH); PRINT 'PARAMETER07 - @RANDOMDATA: ' + CONVERT(NVARCHAR(1),@RANDOMDATA); PRINT 'PARAMETER08 - @DROPANDRECREATE: ' + CONVERT(NVARCHAR(1),@DROPANDRECREATE); PRINT 'PARAMETER09 - @LOGLEVEL: ' + CONVERT(NVARCHAR(25),@LOGLEVEL); PRINT ''; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Get server infos --==================================================-- SELECT @ProductVersion = SERVERPROPERTY('productversion'), @ProductLevel = SERVERPROPERTY ('productlevel'), @ProductEdition = SERVERPROPERTY ('edition'); SET @ProductMainVersion = ISNULL(LEFT(convert(NVARCHAR(100),@ProductVersion), CHARINDEX('.', convert(NVARCHAR(100),@ProductVersion)) - 1),0); PRINT 'Informations about this Server:'; PRINT '@MySessionID: ' + CONVERT(NVARCHAR(100),@@SPID); PRINT '@ProductVersion: ' + CONVERT(NVARCHAR(100),@ProductVersion); PRINT '@ProductMainVersion: ' + CONVERT(NVARCHAR(100),@ProductMainVersion); PRINT '@ProductLevel: ' + CONVERT(NVARCHAR(100),@ProductLevel); PRINT '@ProductEdition: ' + CONVERT(NVARCHAR(100),@ProductEdition); ----------------------------------------------------------------------------------------------------------------------------- --==============================================-- Prepare the log table --================================================-- IF (@LOGLEVEL is not NULL) BEGIN PRINT ''; IF EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_TEST_PERFORMANCE_LOG') BEGIN PRINT 'INFO: Log table already exists'; END; ELSE BEGIN PRINT 'INFO: Log table does not exist, trying to create...'; CREATE TABLE [dbo].[TBDD_TEST_PERFORMANCE_LOG]( [GUID] [bigint] IDENTITY(1,1) NOT NULL, [LOG_LEVEL] [NVARCHAR](25) NOT NULL, [MESSAGE1] [NVARCHAR](max) NOT NULL, [MESSAGE2] [NVARCHAR](max) NULL, [MESSAGE3] [NVARCHAR](max) NULL, [MESSAGE4] [NVARCHAR](max) NULL, [MESSAGE5] [NVARCHAR](max) NULL, [COMMENT] [NVARCHAR](max) NULL, [ADDED_WHO] [NVARCHAR](50) NOT NULL, [ADDED_WHEN] [datetime] NOT NULL, CONSTRAINT [PK_TBDD_TEST_PERFORMANCE_LOG_GUID] PRIMARY KEY CLUSTERED ( [GUID] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = PAGE) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; ALTER TABLE [dbo].[TBDD_TEST_PERFORMANCE_LOG] ADD CONSTRAINT [DF_TBDD_TEST_PERFORMANCE_LOG_ADDED_WHO] DEFAULT (suser_sname()) FOR [ADDED_WHO]; ALTER TABLE [dbo].[TBDD_TEST_PERFORMANCE_LOG] ADD CONSTRAINT [DF_TBDD_TEST_PERFORMANCE_LOG_ADDED_WHEN] DEFAULT (sysdatetime()) FOR [ADDED_WHEN]; END; END; ELSE BEGIN PRINT ''; PRINT 'WARN: Skipping Logging to log table!'; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Check for log table --================================================-- IF NOT EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_TEST_PERFORMANCE_LOG') BEGIN SET @LOGLEVEL = 'NONE'; PRINT 'ERROR: Because the log table [TBDD_TEST_PERFORMANCE_LOG] does not exist, logging is disabled for this run!'; END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Log start to table --=================================================-- IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL,'preparing', 'procedure', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --===============================================-- Validate target database --============================================-- IF NOT EXISTS (SELECT 1 FROM [sys].[databases] WHERE [name] = @TARGETDB) BEGIN SET @return_status = 10; SET @return_status_text = 'ERROR: Target database [' + @TARGETDB + '] does not exist!'; PRINT @return_status_text; IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'validation', 'database', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; RETURN @return_status; END; ----------------------------------------------------------------------------------------------------------------------------- BEGIN TRY --======================================-- Drop and recreate or ensure table --==========================================-- IF (@DROPANDRECREATE = 1) BEGIN SET @return_status_text = 'INFO: Dropping and recreating table ' + @FullTable; PRINT @return_status_text; SET @SQLCommand = N'USE ' + QUOTENAME(@TARGETDB) + N'; IF OBJECT_ID(''' + @QualifiedTable + ''',''U'') IS NOT NULL DROP TABLE ' + @QualifiedTable + N'; CREATE TABLE ' + @QualifiedTable + N'( [Id] INT IDENTITY(1,1) NOT NULL PRIMARY KEY, [Payload] BIGINT NOT NULL, [CreatedAt] DATETIME2(3) NOT NULL DEFAULT SYSUTCDATETIME(), [Pad] CHAR(' + CONVERT(NVARCHAR(10),@PADLENGTH) + N') NOT NULL DEFAULT REPLICATE(''X'',' + CONVERT(NVARCHAR(10),@PADLENGTH) + N') );'; END; ELSE BEGIN SET @return_status_text = 'INFO: Ensuring table ' + @FullTable + ' exists (DROPANDRECREATE = 0)'; PRINT @return_status_text; SET @SQLCommand = N'USE ' + QUOTENAME(@TARGETDB) + N'; IF NOT EXISTS (SELECT 1 FROM sys.tables WHERE [name] = N''' + @TABLENAME + N''' AND [schema_id] = SCHEMA_ID(N''' + @SCHEMA + N''')) BEGIN CREATE TABLE ' + @QualifiedTable + N'( [Id] INT IDENTITY(1,1) NOT NULL PRIMARY KEY, [Payload] BIGINT NOT NULL, [CreatedAt] DATETIME2(3) NOT NULL DEFAULT SYSUTCDATETIME(), [Pad] CHAR(' + CONVERT(NVARCHAR(10),@PADLENGTH) + N') NOT NULL DEFAULT REPLICATE(''X'',' + CONVERT(NVARCHAR(10),@PADLENGTH) + N') ); END;'; END; EXEC @return_status = sp_executesql @SQLCommand; IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'table', @FullTable, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- --================================================-- Insert test data --=================================================-- IF (@ROWCOUNT > 0) and (@return_status = 0) BEGIN SET @RowsRemaining = @ROWCOUNT; SET @RowsInserted = 0; SET @BatchStart = 1; SET @BatchNumber = 0; SET @InsertStart = SYSUTCDATETIME(); WHILE (@RowsRemaining > 0) AND (@return_status = 0) BEGIN DECLARE @CurrentBatch BIGINT = CASE WHEN @RowsRemaining > @BATCHSIZE THEN @BATCHSIZE ELSE @RowsRemaining END; SET @BatchNumber = @BatchNumber + 1; SET @SQLCommand = N'USE ' + QUOTENAME(@TARGETDB) + N'; SET NOCOUNT ON; ;WITH Numbers AS ( SELECT TOP (@BatchSize) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS n FROM sys.all_objects a CROSS JOIN sys.all_objects b CROSS JOIN sys.all_objects c ) INSERT INTO ' + @QualifiedTable + N' ([Payload],[CreatedAt],[Pad]) SELECT CASE WHEN @RandomData = 1 THEN ABS(CAST(CHECKSUM(NEWID()) AS BIGINT)) ELSE @BatchStart + n - 1 END, DATEADD(SECOND, @BatchStart + n - 1, SYSUTCDATETIME()), CASE WHEN @RandomData = 1 THEN LEFT(REPLICATE(REPLACE(CONVERT(VARCHAR(36), NEWID()), ''-'', ''''), CAST(CEILING(@PadLength / 32.0) AS INT)), @PadLength) ELSE REPLICATE(''X'', @PadLength) END FROM Numbers;'; EXEC @return_status = sp_executesql @SQLCommand, N'@BatchSize BIGINT, @PadLength INT, @BatchStart BIGINT, @RandomData BIT', @BatchSize = @CurrentBatch, @PadLength = @PADLENGTH, @BatchStart = @BatchStart, @RandomData = @RANDOMDATA; IF (@return_status = 0) BEGIN SET @RowsRemaining = @RowsRemaining - @CurrentBatch; SET @BatchStart = @BatchStart + @CurrentBatch; SET @RowsInserted = @RowsInserted + @CurrentBatch; SET @return_status_text = 'INFO: Batch ' + CONVERT(NVARCHAR(20),@BatchNumber) + ' inserted ' + CONVERT(NVARCHAR(20),@CurrentBatch) + ' rows (total ' + CONVERT(NVARCHAR(20),@RowsInserted) + ').'; PRINT @return_status_text; IF (@LOGLEVEL in ('INFO','WARN')) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', 'insert_batch', @FullTable, @RowsInserted, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END; ELSE BEGIN SET @return_error_text = 'ERROR: Insert batch ' + CONVERT(NVARCHAR(20),@BatchNumber) + ' failed!'; PRINT @return_error_text; IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'insert_batch', @FullTable, @return_error_text, @MY_PROCEDURE_NAME, GetDate()); END; END; END; SET @InsertEnd = SYSUTCDATETIME(); IF (@return_status = 0) BEGIN SET @return_status_text = 'INFO: Inserted ' + CONVERT(NVARCHAR(50),@RowsInserted) + ' rows in ' + CONVERT(NVARCHAR(50),CAST(DATEDIFF(MILLISECOND,@InsertStart,@InsertEnd)/1000.0 AS DECIMAL(18,2))) + ' seconds.'; PRINT @return_status_text; IF (@LOGLEVEL in ('INFO','WARN')) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', 'insert_total', @FullTable, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END; END; ELSE BEGIN SET @return_status_text = 'WARN: ROWCOUNT was 0, skipping insert!'; PRINT @return_status_text; IF (@LOGLEVEL in ('INFO','WARN')) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES ('WARN', 'insert_total', @FullTable, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- --================================================-- Query the test data --================================================-- IF (@return_status = 0) BEGIN SET @return_status_text = 'INFO: Running query phase for table ' + @FullTable; PRINT @return_status_text; SET @SQLCommand = N'USE ' + QUOTENAME(@TARGETDB) + N'; SELECT COUNT(*) AS TotalRows, MIN(Id) AS MinId, MAX(Id) AS MaxId FROM ' + @QualifiedTable + N'; SELECT TOP (10) * FROM ' + @QualifiedTable + N' ORDER BY Id DESC; SELECT AVG(CONVERT(FLOAT, [Payload])) AS AvgPayload FROM ' + @QualifiedTable + N';'; EXEC @return_status = sp_executesql @SQLCommand; IF (@LOGLEVEL in ('INFO','WARN','ERROR')) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'query', @FullTable, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END; ----------------------------------------------------------------------------------------------------------------------------- END TRY BEGIN CATCH -- Handle any errors that occur during the process. SELECT @return_status = ERROR_NUMBER(), @return_error_text = ERROR_MESSAGE(); SET @return_status_text = 'ERROR: ' + @return_error_text; PRINT @return_status_text; IF ((@LOGLEVEL in ('INFO','WARN','ERROR')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', 'catch', @FullTable, @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; END CATCH; ----------------------------------------------------------------------------------------------------------------------------- SET @return_status_text = 'END PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120); --================================================-- Log end to table --===================================================-- IF ((@LOGLEVEL in ('INFO')) and (@return_status is not null) and (@return_status_text is not null)) BEGIN INSERT INTO [TBDD_TEST_PERFORMANCE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [MESSAGE4], [ADDED_WHO], [ADDED_WHEN]) VALUES (@LOGLEVEL, 'closing', 'procedure', @return_status, @return_status_text, @MY_PROCEDURE_NAME, GetDate()); END; ----------------------------------------------------------------------------------------------------------------------------- PRINT ''; PRINT @return_status_text; PRINT '===================================================================================================='; Return @return_status; END; GO -- Example execution: -- EXEC dbo.PRDD_TEST_PERFORMANCE @pTARGETDB = 'DD_ECM', @pROWCOUNT = 1000000, @pBATCHSIZE = 100000, @pDROPANDRECREATE = 1;