From 6011bff444cfdfe14e2089e264cb98e341b3d2bc Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Togay=20Can=20Akyava=C5=9F?= <78424356+tcakyavas@users.noreply.github.com> Date: Mon, 18 Nov 2024 16:21:38 +0300 Subject: [PATCH] Add a print stored procedure and use it instead of select statements (#6) --- .github/workflows/demoTestsSqlCmd.yaml | 3 +- .../StoredProcedures/AssertEmptyTable.sql | 13 ++- .../StoredProcedures/AssertEqualsTable.sql | 3 +- .../Private_CompareTables.sql | 9 +- .../StoredProcedures/Private_PrintTable.sql | 107 ++++++++++++++++++ 5 files changed, 127 insertions(+), 8 deletions(-) create mode 100644 sql/tSQLt_synapse/StoredProcedures/Private_PrintTable.sql diff --git a/.github/workflows/demoTestsSqlCmd.yaml b/.github/workflows/demoTestsSqlCmd.yaml index 69bd62c..0ecc287 100644 --- a/.github/workflows/demoTestsSqlCmd.yaml +++ b/.github/workflows/demoTestsSqlCmd.yaml @@ -55,8 +55,7 @@ jobs: -ServerInstance "${{ secrets.TARGET_SERVER_URI }}" ` -Database "${{ secrets.TARGET_DATABASE_NAME }}" ` -AccessToken "${{ steps.azure_access_token.outputs.azureAccessToken }}" ` - -InputFile "SampleTests.sql" ` - -Verbose + -InputFile "SampleTests.sql" working-directory: ${{ env.WORKING_DIRECTORY }} shell: pwsh diff --git a/sql/tSQLt_synapse/StoredProcedures/AssertEmptyTable.sql b/sql/tSQLt_synapse/StoredProcedures/AssertEmptyTable.sql index 699ddbd..5f2e5e5 100644 --- a/sql/tSQLt_synapse/StoredProcedures/AssertEmptyTable.sql +++ b/sql/tSQLt_synapse/StoredProcedures/AssertEmptyTable.sql @@ -22,8 +22,17 @@ BEGIN IF (@exists = 1) BEGIN - SET @cmd = 'SELECT * FROM ' + @full_name + ';' - EXEC [sp_executesql] @cmd; + IF (OBJECT_ID(@table_name) IS NULL AND OBJECT_ID('tempdb..' + @table_name) IS NOT NULL) + BEGIN + SET @cmd = 'SELECT * FROM ' + @full_name + ';' + EXEC [sp_executesql] @cmd + END + ELSE + BEGIN + DECLARE @table_name_without_schema NVARCHAR(MAX) = OBJECT_NAME(OBJECT_ID(@table_name)); + DECLARE @schema_name NVARCHAR(MAX) = OBJECT_SCHEMA_NAME(OBJECT_ID(@table_name)); + EXEC [tSQLt_synapse].[Private_PrintTable] @schema_name, @table_name_without_schema; + END DECLARE @message NVARCHAR(MAX); SET @message = @full_name + ' was not empty'; EXEC [tSQLt_synapse].[Fail] @message; diff --git a/sql/tSQLt_synapse/StoredProcedures/AssertEqualsTable.sql b/sql/tSQLt_synapse/StoredProcedures/AssertEqualsTable.sql index 887b1e2..2cbcc2e 100644 --- a/sql/tSQLt_synapse/StoredProcedures/AssertEqualsTable.sql +++ b/sql/tSQLt_synapse/StoredProcedures/AssertEqualsTable.sql @@ -45,7 +45,8 @@ BEGIN EXEC [tSQLt_synapse].[Private_CompareTables] @Expected = @expected, @Actual = @actual, - @ResultTable = @ResultTableWithSchema, + @ResultTable = @ResultTable, + @ResultTableSchema = 'tSQLt_synapse', @ColumnList = @ColumnList, @MatchIndicatorColumnName = @ResultColumn; diff --git a/sql/tSQLt_synapse/StoredProcedures/Private_CompareTables.sql b/sql/tSQLt_synapse/StoredProcedures/Private_CompareTables.sql index 1eb5d69..dadf272 100644 --- a/sql/tSQLt_synapse/StoredProcedures/Private_CompareTables.sql +++ b/sql/tSQLt_synapse/StoredProcedures/Private_CompareTables.sql @@ -3,18 +3,20 @@ CREATE PROCEDURE [tSQLt_synapse].[Private_CompareTables] @Expected NVARCHAR(MAX), @Actual NVARCHAR(MAX), @ResultTable NVARCHAR(MAX), + @ResultTableSchema NVARCHAR(MAX), @ColumnList NVARCHAR(MAX), @MatchIndicatorColumnName NVARCHAR(MAX) AS BEGIN DECLARE @cmd NVARCHAR(MAX); + DECLARE @ResultTableWithSchema VARCHAR(MAX) = @ResultTableSchema + '.' + @ResultTable; DECLARE @RestoredRowIndexCounterColName NVARCHAR(MAX); SET @RestoredRowIndexCounterColName = @MatchIndicatorColumnName + '_RR'; SELECT @cmd = ' - INSERT INTO ' + @ResultTable + ' (' + @MatchIndicatorColumnName + ', ' + @ColumnList + ') + INSERT INTO ' + @ResultTableWithSchema + ' (' + @MatchIndicatorColumnName + ', ' + @ColumnList + ') SELECT CASE WHEN RestoredRowIndex.' + @RestoredRowIndexCounterColName + ' <= CASE WHEN [_{Left}_]<[_{Right}_] THEN [_{Left}_] ELSE [_{Right}_] END @@ -50,7 +52,7 @@ BEGIN @cmd = 'SET @r = CASE WHEN EXISTS( SELECT 1 - FROM ' + @ResultTable + FROM ' + @ResultTableWithSchema + ' WHERE ' + @MatchIndicatorColumnName + ' IN (''<'', ''>'')) THEN 1 ELSE 0 END'; @@ -59,7 +61,8 @@ BEGIN IF @UnequalRowsExist > 0 BEGIN - SET @Cmd = 'SELECT * FROM ' + @ResultTable + '; DROP TABLE ' + @ResultTable + ';' + EXEC [tSQLt_synapse].[Private_PrintTable] @ResultTableSchema, @ResultTable; + SET @Cmd = 'DROP TABLE ' + @ResultTableWithSchema + ';' EXEC [sp_executesql] @Cmd; EXEC [tSQLt_synapse].[Fail] 'There exists unequal rows!'; END; diff --git a/sql/tSQLt_synapse/StoredProcedures/Private_PrintTable.sql b/sql/tSQLt_synapse/StoredProcedures/Private_PrintTable.sql new file mode 100644 index 0000000..61bcd9b --- /dev/null +++ b/sql/tSQLt_synapse/StoredProcedures/Private_PrintTable.sql @@ -0,0 +1,107 @@ +ALTER PROCEDURE [tSQLt_synapse].[Private_PrintTable] + @SchemaName NVARCHAR(MAX), + @TableName NVARCHAR(MAX) +AS +BEGIN + -- Check if the table exists + IF + NOT EXISTS ( + SELECT 1 + FROM [INFORMATION_SCHEMA].[TABLES] + WHERE [TABLE_SCHEMA] = @SchemaName AND [TABLE_NAME] = @TableName + ) + BEGIN + PRINT 'Table not found.'; + END + ELSE + BEGIN + IF OBJECT_ID('tempdb..#column_max_len') IS NOT NULL + DROP TABLE #column_max_len; + CREATE TABLE #column_max_len ([column_name] NVARCHAR(4000), [max_len] INT, [column_id] INT); + + DECLARE + @Column VARCHAR(500), + @MaxLength INT, + @MaxLengthString VARCHAR(100), + @ColumnID INT, + @MaxColumnID INT, + @Command NVARCHAR(2000); + + SELECT + @ColumnID = MIN([clm].[column_id]), + @MaxColumnID = MAX([clm].[column_id]) + FROM [sys].[tables] AS [tbl] + INNER JOIN [sys].[columns] AS [clm] ON [tbl].[object_id] = [clm].[object_id] + WHERE + [tbl].[name] = @TableName + AND SCHEMA_NAME([tbl].[schema_id]) = @SchemaName; + + WHILE (@ColumnID <= @MaxColumnID) + BEGIN + SET @Column = NULL; + + SELECT @Column = [clm].[name] + FROM [sys].[tables] AS [tbl] + INNER JOIN [sys].[columns] AS [clm] ON [tbl].[object_id] = [clm].[object_id] + WHERE + [tbl].[name] = @TableName + AND SCHEMA_NAME([tbl].[schema_id]) = @SchemaName + AND [clm].[column_id] = @ColumnID; + + IF (@Column IS NOT NULL) + BEGIN + SET @Command = N' + INSERT INTO #column_max_len(column_name, max_len, column_id) + SELECT ''' + @Column + ''' + ,MAX(LEN(CAST([' + @Column + '] as VARCHAR(8000)))) + ,' + CAST(@ColumnID AS NVARCHAR(MAX)) + ' + FROM [' + @SchemaName + '].[' + @TableName + '] + WHERE [' + @Column + '] IS NOT NULL'; + EXEC (@Command); + END + SET @ColumnID = @ColumnID + 1; + END + + DECLARE @ColumnList NVARCHAR(MAX) = ''; + SELECT + @ColumnList = STRING_AGG( + QUOTENAME([column_name]) + + SPACE(GREATEST([max_len], LEN(QUOTENAME([column_name]))) - LEN(QUOTENAME([column_name])) + 1), + ' ' + ) WITHIN GROUP (ORDER BY [column_id] ASC) + FROM #column_max_len; + + -- Print column headers + PRINT @ColumnList; + + -- Create tbl list of columns cast to NVARCHAR(MAX) + DECLARE @ColumnCastList NVARCHAR(MAX) = ''; + SELECT + @ColumnCastList = STRING_AGG( + 'ISNULL(CAST(' + QUOTENAME([column_name]) + + ' AS NVARCHAR(MAX)),'''') + SPACE(GREATEST(' + + CAST([max_len] AS NVARCHAR(MAX)) + + ',LEN(QUOTENAME(''' + + [column_name] + + '''))) - ISNULL(LEN(' + + [column_name] + + '),0))', + ',' + ) WITHIN GROUP (ORDER BY [column_id] ASC) + FROM #column_max_len; + + PRINT REPLICATE('-', LEN(@ColumnList)); + + SET @Command = N' + DECLARE @Output NVARCHAR(MAX); + SELECT @Output = STRING_AGG(RowText, CHAR(10)) + FROM ( + SELECT CONCAT_WS('', '', ' + @ColumnCastList + ') AS RowText + FROM [' + @SchemaName + '].[' + @TableName + '] + ) t; + PRINT @Output;'; + + -- Execute the dynamic SQL + EXEC [sp_executesql] @Command; + END +END;