diff --git a/.gitattributes b/.gitattributes index a93f2341..17b67554 100644 --- a/.gitattributes +++ b/.gitattributes @@ -1,5 +1,6 @@ # linguist overrides *.sql linguist-language=TSQL +*.sql diff # line endings for code coverage files appveyor/sqlcover/* text eol=lf \ No newline at end of file diff --git a/.gitignore b/.gitignore index 56299d8e..3e441ab4 100644 --- a/.gitignore +++ b/.gitignore @@ -1,3 +1,4 @@ .markdownlint.json node_modules/* package-lock.json +debug.log diff --git a/appveyor/build_tsqlt_tests.ps1 b/appveyor/build_tsqlt_tests.ps1 index 998041f6..a77381f7 100644 --- a/appveyor/build_tsqlt_tests.ps1 +++ b/appveyor/build_tsqlt_tests.ps1 @@ -9,6 +9,8 @@ param( $Color = "Green" ) +$ErrorActionPreference = "Stop" + Write-Host "Building tSQLt Tests..." -ForegroundColor $Color If ($IsAzureSQL) { diff --git a/appveyor/generate_combined_script.ps1 b/appveyor/generate_combined_script.ps1 index 0d0d508a..7dd70e55 100644 --- a/appveyor/generate_combined_script.ps1 +++ b/appveyor/generate_combined_script.ps1 @@ -5,4 +5,4 @@ if (Test-Path $File) { Remove-Item $File } -Get-Item $Filter | Get-Content | Out-File $File \ No newline at end of file +Get-Item $Filter | Get-Content | Out-File $File -Encoding utf8 \ No newline at end of file diff --git a/appveyor/install_dependencies.ps1 b/appveyor/install_dependencies.ps1 index f2dcc752..296d1c1a 100644 --- a/appveyor/install_dependencies.ps1 +++ b/appveyor/install_dependencies.ps1 @@ -7,8 +7,10 @@ Write-Host "Installing dependencies..." -ForegroundColor $Color # TSQLLinter # Try/Catch to stop appveyor unnecessary errors -Try { npm install tsqllint -g | Out-Null } -Catch { } +$result = npm list -g --depth=0 +If (-Not ($result -Match "tsqllint")) { + npm install tsqllint -g | Out-Null +} # SQLServer Module if (!(Get-Module -ListAvailable -Name SqlServer)) { @@ -16,4 +18,6 @@ if (!(Get-Module -ListAvailable -Name SqlServer)) { } # DbaTools Module -Install-Module DbaTools -Force -AllowClobber \ No newline at end of file +if (!(Get-Module -ListAvailable -Name DbaTools)) { + Install-Module DbaTools -Force -AllowClobber +} \ No newline at end of file diff --git a/appveyor/run_tsqllint.ps1 b/appveyor/run_tsqllint.ps1 index 1ce7ff6f..39a8d2c5 100644 --- a/appveyor/run_tsqllint.ps1 +++ b/appveyor/run_tsqllint.ps1 @@ -4,5 +4,7 @@ param( $Color = "Green" ) +$ErrorActionPreference = "Stop" + Write-Host "Running TSQLLint with config $Config..." -ForegroundColor $Color tsqllint -c $Config *.sql \ No newline at end of file diff --git a/appveyor/sqlcover/Coverage.opencoverxml b/appveyor/sqlcover/Coverage.opencoverxml index 94213391..633404b5 100644 --- a/appveyor/sqlcover/Coverage.opencoverxml +++ b/appveyor/sqlcover/Coverage.opencoverxml @@ -1,389 +1,602 @@ - + tSQLttSQLt - - + + + -[dbo].[sp_doc] - +[dbo].[sp_doc] + 01041980[dbo].[sp_doc] - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +[dbo].[sp_estindex] + + 01041980[dbo].[sp_estindex] + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + [dbo].[sp_helpme] - 01041980[dbo].[sp_helpme] + 01041980[dbo].[sp_helpme] - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + [dbo].[sp_sizeoptimiser] - 01041980[dbo].[sp_sizeoptimiser] + 01041980[dbo].[sp_sizeoptimiser] - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + diff --git a/appveyor/sqlcover/Run_SQLCover.ps1 b/appveyor/sqlcover/Run_SQLCover.ps1 index 91b27716..4e7bf411 100644 --- a/appveyor/sqlcover/Run_SQLCover.ps1 +++ b/appveyor/sqlcover/Run_SQLCover.ps1 @@ -52,7 +52,7 @@ If ($IsCoverStarted) { $tmpFile = Join-Path $env:TEMP "Coverage.html" Set-Content -Path $tmpFile -Value $coverageResults.Html2() -Force Invoke-Item $tmpFile - Start-Sleep -Seconds 1 + Start-Sleep -Seconds 3 Remove-Item $tmpFile } } diff --git a/appveyor/sqlcover/[dbo].[sp_doc] b/appveyor/sqlcover/[dbo].[sp_doc] index d290c058..e3ae8e98 100644 --- a/appveyor/sqlcover/[dbo].[sp_doc] +++ b/appveyor/sqlcover/[dbo].[sp_doc] @@ -4,6 +4,7 @@ CREATE PROCEDURE [dbo].[sp_doc] ,@ExtendedPropertyName SYSNAME = 'Description' ,@LimitStoredProcLength BIT = 1 ,@Emojis BIT = 0 + ,@Verbose BIT = 1 /* Parameters defined here for testing only */ ,@SqlMajorVersion TINYINT = 0 ,@SqlMinorVersion SMALLINT = 0 @@ -78,6 +79,11 @@ BEGIN IF (@DatabaseName IS NULL) BEGIN SET @DatabaseName = DB_NAME(); + IF (@Verbose = 1) + BEGIN; + SET @Msg = 'No database provided, assuming current database.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; END ELSE IF (DB_ID(@DatabaseName) IS NULL) BEGIN; diff --git a/appveyor/sqlcover/[dbo].[sp_estindex] b/appveyor/sqlcover/[dbo].[sp_estindex] new file mode 100644 index 00000000..f0ce2eb3 --- /dev/null +++ b/appveyor/sqlcover/[dbo].[sp_estindex] @@ -0,0 +1,762 @@ + +CREATE PROCEDURE [dbo].[sp_estindex] + @SchemaName SYSNAME = NULL + ,@TableName SYSNAME + ,@DatabaseName SYSNAME = NULL + ,@IndexColumns NVARCHAR(2048) + ,@IncludeColumns NVARCHAR(2048) = NULL + ,@IsUnique BIT = 0 + ,@Filter NVARCHAR(2048) = '' + ,@FillFactor TINYINT = 100 + ,@Verbose BIT = 0 + -- Unit testing only + ,@SqlMajorVersion TINYINT = 0 +AS +BEGIN + +SET NOCOUNT ON; + +/* +sp_estindex - Estimate a new index's size and statistics. + +Part of the DBA MultiTool http://dba-multitool.org + +Version: 20201016 + +MIT License + +Copyright (c) 2020 John McCall + +Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated +documentation files (the "Software"), to deal in the Software without restriction, including without limitation +the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, +and to permit persons to whom the Software is furnished to do so, subject to the following conditions: + +The above copyright notice and this permission notice shall be included in all copies or substantial +portions of the Software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED +TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL +THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF +CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER +DEALINGS IN THE SOFTWARE. + +-- TODO: + -- Handle clustered indexes - https://docs.microsoft.com/en-us/sql/relational-databases/databases/estimate-the-size-of-a-clustered-index?view=sql-server-ver15 + +========= + +Example: + + EXEC dbo.sp_estindex @SchemaName = 'dbo', @tableName = 'Marathon', @IndexColumns = 'racer_id, finish_time, is_disqualified'; + + EXEC dbo.sp_estindex @tableName = 'Marathon', @IndexColumns = 'racer_id, finish_time, is_disqualified', @Filter = 'WHERE racer_id IS NOT NULL', @FillFactor = 90; + +*/ + +DECLARE @Sql NVARCHAR(MAX) = N'' + ,@QualifiedTable NVARCHAR(257) + ,@IndexName SYSNAME = CONCAT('sp_estindex_hypothetical_idx_', DATEDIFF(SECOND,'1970-01-01 00:08:46', GETUTCDATE())) + ,@DropIndexSql NVARCHAR(MAX) + ,@Msg NVARCHAR(MAX) = N'' + ,@IndexType SYSNAME = 'NONCLUSTERED' + ,@IsHeap BIT + ,@IsClusterUnique BIT + ,@ObjectID INT + ,@IndexID INT + ,@ParmDefinition NVARCHAR(MAX) = N'' + ,@NumRows BIGINT + ,@UseDatabase NVARCHAR(200) + ,@UniqueSql VARCHAR(10) + ,@IncludeSql VARCHAR(2048); + +BEGIN TRY + -- Find Version + IF (@SqlMajorVersion = 0) + BEGIN; + SET @SqlMajorVersion = CAST(SERVERPROPERTY('ProductMajorVersion') AS TINYINT); + END; + + /* Validate Version */ + IF (@SqlMajorVersion < 11) + BEGIN; + SET @Msg = 'SQL Server versions below 2012 are not supported, sorry!'; + RAISERROR(@Msg, 16, 1); + END; + + /* Validate Fill Factor */ + IF (@FillFactor > 100 OR @FillFactor < 1) + BEGIN; + SET @Msg = 'Fill factor must be between 1 and 100.'; + THROW 51000, @Msg, 1; + END; + + /* Validate Database */ + IF (@DatabaseName IS NULL) + BEGIN; + SET @DatabaseName = DB_NAME(); + IF (@Verbose = 1) + BEGIN; + SET @Msg = 'No database provided, assuming current database.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + END; + ELSE IF (DB_ID(@DatabaseName) IS NULL) + BEGIN; + SET @DatabaseName = DB_NAME(); + SET @Msg = 'Database does not exist.'; + RAISERROR(@Msg, 16, 1); + END; + + /* Validate Schema */ + IF (@SchemaName IS NULL) + BEGIN; + SET @SchemaName = 'dbo'; + IF (@Verbose = 1) + BEGIN; + SET @Msg = 'No schema provided, assuming dbo.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + END; + + -- Set variables with validated params + SET @QualifiedTable = CONCAT(QUOTENAME(@SchemaName), '.', QUOTENAME(@TableName)); + SET @UseDatabase = N'USE ' + QUOTENAME(@DatabaseName) + '; '; + IF (@IsUnique = 1) + BEGIN; + SET @UniqueSql = ' UNIQUE '; + END; + IF (@IncludeColumns IS NOT NULL) + BEGIN; + SET @IncludeSql = CONCAT(' INCLUDE(', @IncludeColumns, ') '); + END; + + -- Find object id + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @ObjectID = [object_id] + FROM [sys].[all_objects] + WHERE [object_id] = OBJECT_ID(@QualifiedTable)'); + SET @ParmDefinition = N'@QualifiedTable NVARCHAR(257) + ,@ObjectID BIGINT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@QualifiedTable + ,@ObjectID OUTPUT; + + -- Determine Heap or Clustered + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @IsHeap = CASE [type] WHEN 0 THEN 1 ELSE 0 END + ,@IsClusterUnique = [is_unique] + FROM [sys].[indexes] + WHERE [object_id] = OBJECT_ID(@QualifiedTable) + AND [type] IN (1, 0)'); + SET @ParmDefinition = N'@QualifiedTable NVARCHAR(257), @IsHeap BIT OUTPUT, @IsClusterUnique BIT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@QualifiedTable + ,@IsHeap OUTPUT + ,@IsClusterUnique OUTPUT; + + -- Safety check for leftover index from previous run + SET @DropIndexSql = CONCAT(@UseDatabase, + N'IF EXISTS (SELECT 1 FROM [sys].[indexes] WHERE [object_id] = OBJECT_ID(''',@QualifiedTable,''') AND [name] = ''',@IndexName,''') + DROP INDEX ', QUOTENAME(@IndexName), ' ON ', @QualifiedTable); + EXEC sp_executesql @DropIndexSql; + + -- Fetch missing index stats before creation + IF OBJECT_ID('tempdb..##TempMissingIndex') IS NOT NULL + BEGIN; + DROP TABLE ##TempMissingIndex; + END; + + SET @Sql = CONCAT(@UseDatabase, + N'SELECT [id].[statement] + ,[id].[equality_columns] + ,[id].[inequality_columns] + ,[id].[included_columns] + ,[gs].[unique_compiles] + ,[gs].[user_seeks] + ,[gs].[user_scans] + ,[gs].[avg_total_user_cost] -- Average cost of the user queries that could be reduced + ,[gs].[avg_user_impact] -- % + INTO ##TempMissingIndex + FROM [sys].[dm_db_missing_index_group_stats] [gs] + INNER JOIN [sys].[dm_db_missing_index_groups] [ig] ON [gs].[group_handle] = [ig].[index_group_handle] + INNER JOIN [sys].[dm_db_missing_index_details] [id] ON [ig].[index_handle] = [id].[index_handle] + WHERE [id].[database_id] = DB_ID() + AND [id].[object_id] = @ObjectID + OPTION (RECOMPILE);'); + SET @ParmDefinition = N'@ObjectID INT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@ObjectID; + + -- Create the hypothetical index + SET @Sql = CONCAT(@UseDatabase, 'CREATE ', @UniqueSql, @IndexType, ' INDEX ', QUOTENAME(@IndexName), ' ON ', @QualifiedTable, ' (', @IndexColumns, ') ',@IncludeSql, @Filter, ' WITH (STATISTICS_ONLY = -1)'); + EXEC sp_executesql @Sql; + + /*******************/ + /* Get index stats */ + /*******************/ + SET @Sql = CONCAT(@UseDatabase, 'DBCC SHOW_STATISTICS ("', @QualifiedTable,'", ', QUOTENAME(@IndexName), ')'); + EXEC sp_executesql @Sql; + + /***************************/ + /* Get missing index stats */ + /***************************/ + DECLARE @QuotedKeyColumns NVARCHAR(2048) + ,@QuotedInclColumns NVARCHAR(2048); + + --Get index columns in same format as dmv table + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @QuotedKeyColumns = CASE [ic].[is_included_column] WHEN 0 + THEN COALESCE(@QuotedKeyColumns + '', '', '''') + QUOTENAME([ac].[name]) + ELSE @QuotedKeyColumns + END, + @QuotedInclColumns = CASE [ic].[is_included_column] WHEN 1 + THEN COALESCE(@QuotedInclColumns + '', '', '''') + QUOTENAME([ac].[name]) + ELSE @QuotedInclColumns + END + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1;'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID INT, @QuotedKeyColumns NVARCHAR(2048) OUTPUT, @QuotedInclColumns NVARCHAR(2048) OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@QuotedKeyColumns OUTPUT + ,@QuotedInclColumns OUTPUT; + + -- Search missing index dmv for a match + SELECT 'Missing index stats' AS [description] + ,[statement] + ,[equality_columns] + ,[inequality_columns] + ,[included_columns] + ,[unique_compiles] + ,[user_seeks] + ,[user_scans] + ,[avg_total_user_cost] + ,[avg_user_impact] + FROM ##TempMissingIndex + WHERE COALESCE([equality_columns] + ', ', '') + [inequality_columns] = @QuotedKeyColumns + AND ([included_columns] = @QuotedInclColumns OR [included_columns] IS NULL); + + IF (SELECT COUNT(*) FROM ##TempMissingIndex) = 0 AND (@Verbose = 1) + BEGIN; + SET @Msg = 'No matching missing index statistics found.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + DROP TABLE ##TempMissingIndex; + + /************************************************/ + /* Estimate index size - does NOT consider: */ + /* Partitioning, allocation pages, LOB values, */ + /* compression, or sparse columns */ + /************************************************/ + IF (@IndexType = 'NONCLUSTERED') -- http://dba-multitool.org/est-nonclustered-index-size + BEGIN; + DECLARE @NumVariableKeyCols INT = 0 + ,@MaxVarKeySize INT = 0 + ,@NumFixedKeyCols INT = 0 + ,@FixedKeySize INT = 0 + ,@NumKeyCols INT = 0 + ,@NullCols INT = 0 + ,@IndexNullBitmap INT = 0 + ,@VariableKeySize INT = 0 + ,@TotalFixedKeySize INT = 0 + ,@IndexRowSize INT = 0 + ,@IndexRowsPerPage INT = 0 + ,@ClusterNumVarKeyCols INT = 0 + ,@MaxClusterVarKeySize INT = 0 + ,@ClusterNumFixedKeyCols INT = 0 + ,@MaxClusterFixedKeySize INT = 0 + ,@ClusterNullCols INT = 0; + + /**************************/ + /* 1. Calculate variables */ + /**************************/ + -- Row count + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @NumRows = SUM([ps].[row_count]) + FROM [sys].[objects] AS [o] + INNER JOIN [sys].[dm_db_partition_stats] AS [ps] ON [o].[object_id] = [ps].[object_id] + WHERE [o].[type] = ''U'' + AND [o].[is_ms_shipped] = 0 + AND [ps].[index_id] < 2 + AND [o].[object_id] = @ObjectID + GROUP BY [o].[schema_id], [o].[name];'); + SET @ParmDefinition = N'@ObjectID BIGINT, @NumRows BIGINT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@ObjectID + ,@NumRows OUTPUT; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumRows: ', @NumRows); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + --Key types and sizes + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @NumVariableKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxVarKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN CASE [ac].[max_length] + WHEN -1 + THEN(4000 + 2) -- use same estimation as the query engine for max lenths + ELSE COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + END + ELSE 0 + END), 0), + @NumFixedKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @FixedKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + ELSE 0 + END), 0), + @NullCols = ISNULL(SUM(CAST([ac].[is_nullable] AS TINYINT)),0) + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1 + AND [ic].[is_included_column] = 0'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID BIGINT, @NumVariableKeyCols INT OUTPUT, + @MaxVarKeySize INT OUTPUT, @NumFixedKeyCols INT OUTPUT, @FixedKeySize INT OUTPUT, + @NullCols INT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@NumVariableKeyCols OUTPUT + ,@MaxVarKeySize OUTPUT + ,@NumFixedKeyCols OUTPUT + ,@FixedKeySize OUTPUT + ,@NullCols OUTPUT; + + SET @NumKeyCols = @NumVariableKeyCols + @NumFixedKeyCols; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumVariableKeyCols: ', @NumVariableKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxVarKeySize: ', @MaxVarKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumFixedKeyCols: ', @NumFixedKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('FixedKeySize: ', @FixedKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NullCols: ', @NullCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumKeyCols: ', @NumKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Account for data row locator for non-unique + IF (@IsHeap = 1 AND @IsUnique = 0) + BEGIN; + SET @NumKeyCols = @NumKeyCols + 1; + SET @NumVariableKeyCols = @NumVariableKeyCols + 1; + SET @MaxVarKeySize = @MaxVarKeySize + 8; --heap RID + END; + ELSE IF (@IsHeap = 0 AND @IsUnique = 0) + BEGIN; + --Clustered keys and sizes not included in the new index + SET @Sql = CONCAT(@UseDatabase, + N'WITH NewIndexCol AS ( + SELECT [ac].[name] + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1 + AND [ic].[is_included_column] = 0 + ) + SELECT @ClusterNumVarKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxClusterVarKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN CASE [ac].[max_length] + WHEN -1 + THEN(4000 + 2) -- use same estimation as the query engine for max lenths + ELSE COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + END + ELSE 0 + END), 0), + @ClusterNumFixedKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxClusterFixedKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + ELSE 0 + END), 0), + @ClusterNullCols = ISNULL(SUM(CAST([ac].[is_nullable] AS TINYINT)),0) + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[type] = 1 --Clustered + AND [i].[object_id] = @ObjectID + AND [ac].[name] NOT IN (SELECT [name] FROM [NewIndexCol]);'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID BIGINT, @ClusterNumVarKeyCols INT OUTPUT, + @MaxClusterVarKeySize INT OUTPUT, @ClusterNumFixedKeyCols INT OUTPUT, + @MaxClusterFixedKeySize INT OUTPUT, @ClusterNullCols INT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@ClusterNumVarKeyCols OUTPUT + ,@MaxClusterVarKeySize OUTPUT + ,@ClusterNumFixedKeyCols OUTPUT + ,@MaxClusterFixedKeySize OUTPUT + ,@ClusterNullCols OUTPUT; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('ClusterNumVarKeyCols: ', @ClusterNumVarKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('ClusterNumFixedKeyCols: ', @ClusterNumFixedKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxClusterVarKeySize: ', @MaxClusterVarKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxClusterFixedKeySize: ', @MaxClusterFixedKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('ClusterNullCols: ', @ClusterNullCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Add counts from clustered index cols + SET @NumKeyCols = @NumKeyCols + (@ClusterNumVarKeyCols + @ClusterNumFixedKeyCols); + SET @FixedKeySize = @FixedKeySize + @MaxClusterFixedKeySize; + SET @NumVariableKeyCols = @NumVariableKeyCols + @ClusterNumVarKeyCols; + SET @MaxVarKeySize = @MaxVarKeySize + @MaxClusterVarKeySize; + SET @NullCols = @NullCols + @ClusterNullCols; + + IF (@IsClusterUnique = 0) + BEGIN; + SET @MaxVarKeySize = @MaxVarKeySize + 4; + SET @NumVariableKeyCols = @NumVariableKeyCols + 1; + SET @NumKeyCols = @NumKeyCols + 1; + END; + END; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('FixedKeySize: ', @FixedKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumVariableKeyCols: ', @NumVariableKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumKeyCols: ', @NumKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxVarKeySize: ', @MaxVarKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NullCols: ', @NullCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Account for index null bitmap + IF (@NullCols > 0) + BEGIN; + SET @IndexNullBitmap = 2 + ((@NullCols + 7) / 8); + END; + + -- Calculate variable length data size + -- Assumes each col is 100% full + IF (@NumVariableKeyCols > 0) + BEGIN; + SET @VariableKeySize = 2 + (@NumVariableKeyCols * 2) + @MaxVarKeySize; --The bytes added to @MaxVarKeySize are for tracking each variable column. + END; + + -- Calculate index row size + SET @IndexRowSize = @FixedKeySize + @VariableKeySize + @IndexNullBitmap + 1 + 6; -- + 1 (for row header overhead of an index row) + 6 (for the child page ID pointer) + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('IndexRowSize: ', @IndexRowSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + --Calculate number of index rows / page + SET @IndexRowsPerPage = FLOOR(8096 / (@IndexRowSize + 2)); -- + 2 for the row's entry in the page's slot array. + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('IndexRowsPerPage: ', @IndexRowsPerPage); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + /****************************************************************************/ + /* 2. Calculate the Space Used to Store Index Information in the Leaf Level */ + /****************************************************************************/ + -- Specify the number of fixed-length and variable-length columns at the leaf level + -- and calculate the space that is required for their storage + DECLARE @NumLeafCols INT = @NumKeyCols + ,@FixedLeafSize INT = @FixedKeySize + ,@NumVariableLeafCols INT = @NumVariableKeyCols + ,@MaxVarLeafSize INT = @MaxVarKeySize + ,@LeafNullBitmap INT = 0 + ,@VariableLeafSize INT = 0 + ,@LeafRowSize INT = 0 + ,@LeafRowsPerPage INT = 0 + ,@FreeRowsPerPage INT = 0 + ,@NumLeafPages INT = 0 + ,@LeafSpaceUsed INT = 0; + + IF (@IncludeColumns IS NOT NULL) + BEGIN; + DECLARE @NumVariableInclCols INT = 0 + ,@MaxVarInclSize INT = 0 + ,@NumFixedInclCols INT = 0 + ,@FixedInclSize INT = 0; + + --Incl types and sizes + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @NumVariableInclCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxVarInclSize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN CASE [ac].[max_length] + WHEN -1 + THEN (4000 + 2) -- use same estimation as the query engine for max lenths + ELSE COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + END + ELSE 0 + END), 0), + @NumFixedInclCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @FixedInclSize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + ELSE 0 + END), 0) + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1 + AND [ic].[is_included_column] = 1;'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID BIGINT, @NumVariableInclCols INT OUTPUT, + @MaxVarInclSize INT OUTPUT, @NumFixedInclCols INT OUTPUT, @FixedInclSize INT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@NumVariableInclCols OUTPUT + ,@MaxVarInclSize OUTPUT + ,@NumFixedInclCols OUTPUT + ,@FixedInclSize OUTPUT; + + -- Add included columns to rolling totals + SET @NumLeafCols = @NumLeafCols + (@NumVariableInclCols + @NumFixedInclCols); + SET @FixedLeafSize = @FixedLeafSize + @FixedInclSize; + SET @NumVariableLeafCols = @NumVariableLeafCols + @NumVariableInclCols; + SET @MaxVarLeafSize = @MaxVarLeafSize + @MaxVarInclSize; + END; + + -- Account for data row locator for unique indexes + -- If non-unique, already accounted for above + IF (@IsUnique = 1) + BEGIN; + IF (@IsHeap = 1) + BEGIN; + SET @NumLeafCols = @NumLeafCols + 1; + SET @NumVariableLeafCols = @NumVariableLeafCols + 1; + SET @MaxVarLeafSize = @MaxVarLeafSize + 8; -- the data row locator is the heap RID (size 8 bytes). + END; + ELSE -- Clustered + BEGIN; + SET @NumLeafCols = @NumLeafCols + (@ClusterNumVarKeyCols + @ClusterNumFixedKeyCols); + SET @FixedLeafSize = @FixedLeafSize + @ClusterNumFixedKeyCols; + SET @NumVariableLeafCols = @NumVariableLeafCols + @ClusterNumVarKeyCols; + SET @MaxVarLeafSize = @MaxVarLeafSize + @MaxClusterVarKeySize; + + IF (@IsClusterUnique = 0) + BEGIN; + SET @NumLeafCols = @NumLeafCols + 1; + SET @NumVariableLeafCols = @NumVariableLeafCols + 1; + SET @MaxVarLeafSize = @MaxVarLeafSize + 4; + END; + END; + END; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumLeafCols: ', @NumLeafCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('FixedLeafSize: ', @FixedLeafSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumVariableLeafCols: ', @NumVariableLeafCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxVarLeafSize: ', @MaxVarLeafSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Account for index null bitmap + SET @LeafNullBitmap = 2 + ((@NumLeafCols + 7) / 8); + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('LeafNullBitmap: ', @LeafNullBitmap); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate variable length data size + -- Assumes each col is 100% full + IF (@NumVariableLeafCols > 0) + BEGIN; + SET @VariableLeafSize = 2 + (@NumVariableLeafCols * 2) + @MaxVarLeafSize; + END; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('VariableLeafSize: ', @VariableLeafSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate index row size + SET @LeafRowSize = @FixedLeafSize + @VariableLeafSize + @LeafNullBitmap + 1; -- +1 for row header overhead of an index row) + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('LeafRowSize: ', @LeafRowSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate number of index rows / page + SET @LeafRowsPerPage = FLOOR(8096 / (@LeafRowSize + 2)); -- + 2 for the row's entry in the page's slot array. + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('LeafRowsPerPage: ', @LeafRowsPerPage); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate free rows / page + SET @FreeRowsPerPage = 8096 * (( 100 - @FillFactor) / 100) / (@LeafRowSize + 2); -- + 2 for the row's entry in the page's slot array. + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('FreeRowsPerPage: ', @FreeRowsPerPage); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate pages for all rows + SET @NumLeafPages = CEILING(@NumRows / (@LeafRowsPerPage - @FreeRowsPerPage)); + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumLeafPages: ', @NumLeafPages); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate size of index at leaf level + SET @LeafSpaceUsed = 8192 * @NumLeafPages; + + /*********************************************************************************/ + /* 3. Calculate the Space Used to Store Index Information in the Non-leaf Levels */ + /*********************************************************************************/ + DECLARE @NonLeafLevels INT = 0, + @NumIndexPages INT = 0, + @IndexSpaceUsed INT = 0; + + -- Calculate the number of non-leaf levels in the index + SET @NonLeafLevels = CEILING(1 + LOG(@IndexRowsPerPage) * (@NumLeafPages / @IndexRowsPerPage)); + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NonLeafLevels: ', @NonLeafLevels); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + --Formula: IndexPages = ∑Level (Num_Leaf_Pages/Index_Rows_Per_Page^Level)where 1 <= Level <= Levels + WHILE (@NonLeafLevels > 1) + BEGIN + DECLARE @TempIndexPages FLOAT(30); + + -- TempIndexPages may be exceedingly small, so catch any arith overflows and call it 0 + BEGIN TRY; + SET @TempIndexPages = @NumLeafPages / POWER(@IndexRowsPerPage, @NonLeafLevels); + SET @NumIndexPages = @NumIndexPages + @TempIndexPages; + SET @NonLeafLevels = @NonLeafLevels - 1; + END TRY + BEGIN CATCH; + SET @NonLeafLevels = @NonLeafLevels - 1; + END CATCH; + END; + + -- Calculate size of the index + SET @IndexSpaceUsed = 8192 * @NumIndexPages; + + /**************************************/ + /* 4. Total index and leaf space used */ + /**************************************/ + DECLARE @Total INT = 0; + + SET @Total = @LeafSpaceUsed + @IndexSpaceUsed; + + SELECT @Total/1024 AS [Est. KB] + ,CAST(ROUND(@Total/1024.0/1024.0,2,1) AS DECIMAL(30,2)) AS [Est. MB] + ,CAST(ROUND(@Total/1024.0/1024.0/1024.0,2,1) AS DECIMAL(30,4)) AS [Est. GB]; + END; + + --Cleanup + EXEC sp_executesql @DropIndexSql; + +END TRY +BEGIN CATCH; + BEGIN; + DECLARE @ErrorNumber INT = ERROR_NUMBER(); + DECLARE @ErrorLine INT = ERROR_LINE(); + DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); + DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); + DECLARE @ErrorState INT = ERROR_STATE(); + + EXEC sp_executesql @DropIndexSql; + + SET @ErrorMessage = CONCAT(QUOTENAME(OBJECT_NAME(@@PROCID)), ': ', @ErrorMessage); + RAISERROR(@ErrorMessage, @ErrorSeverity, @ErrorState) WITH NOWAIT; + END; +END CATCH; + +END; + + diff --git a/docs/README.md b/docs/README.md index 86dddfc6..586bee89 100644 --- a/docs/README.md +++ b/docs/README.md @@ -24,9 +24,10 @@ To quickly install or update all the scripts below, use `install_dba-multitool.s | Name | Description | | ---- | ----------- | -| [sp_sizeoptimiser](sp_sizeoptimiser.md) | Recommends space saving measures for data footprints, with special checks for SQL Server Express. | -| [sp_helpme](sp_helpme.md) | A drop-in modern alternative to `sp_help`. | | [sp_doc](sp_doc.md) | Always have current documentation by generating it on the fly in markdown. | +| [sp_estindex](sp_estindex.md) | Estimate a new index's size and statistics without having to create it. | +| [sp_helpme](sp_helpme.md) | A drop-in modern alternative to `sp_help`. | +| [sp_sizeoptimiser](sp_sizeoptimiser.md) | Recommends space saving measures for data footprints, with special checks for SQL Server Express. | ## Compatibility diff --git a/docs/sp_doc.md b/docs/sp_doc.md index b376b393..a88ddfec 100644 --- a/docs/sp_doc.md +++ b/docs/sp_doc.md @@ -3,7 +3,6 @@ ![License](https://img.shields.io/github/license/LowlyDBA/dba-multitool?color=blue) ![SQL Server](https://img.shields.io/badge/SQL%20Server-2012--2019-blue?logo=microsoft-sql-server) ![Azure SQL](https://img.shields.io/badge/Azure%20SQL-vCurrent-blue?logo=data:image/svg+xml;base64,PHN2ZyBkYXRhLXNsdWctaWQ9InNxbC1kYXRhYmFzZS1ibHVlIiB4bWxucz0iaHR0cDovL3d3dy53My5vcmcvMjAwMC9zdmciIHZpZXdCb3g9IjAgMCA0OSA0OSI+DQogIDxwYXRoIGQ9Im02LjQwNDIxIDcuNDA0NDJ2MzQuMTk1NzhjMCAzLjUyNDMgNy44ODk2OSA2LjQ3NzIgMTcuNjgwMzkgNi40Nzcydi00MC42NzI5OHoiIGZpbGw9IiM4MDgwODAiLz4NCiAgPHBhdGggZD0ibTIzLjg5NDYgNDguMDc3NGguMjg1MmM5Ljc5MDcgMCAxNy42ODA0LTIuODU3NiAxNy42ODA0LTYuNDc3MnYtMzQuMTk1NzhoLTE3Ljk2NTZ6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0yMy43MDQzIDQ4LjA3NzloLjI4NTJjOS44ODU4IDAgMTcuOTY1Ni0yLjg1NzYgMTcuOTY1Ni02LjQ3NzJ2LTM0LjI5MTAxaC0xOC4xNTU3eiIgZmlsbD0iIzgwODA4MCIvPg0KICA8cGF0aCBkPSJtNDEuODU4NCA3LjQwNTUzYzAgMy41MjQzNy03Ljg4OTcgNi40NzcxNy0xNy42ODA1IDYuNDc3MTctOS43OTA3IDAtMTcuNjgwMzktMi44NTc2LTE3LjY4MDM5LTYuNDc3MTcgMC0zLjYxOTYgNy44ODk2OS02LjQ3NzE4NSAxNy42ODAzOS02LjQ3NzE4NSA5Ljc5MDggMCAxNy42ODA1IDIuOTUyODM1IDE3LjY4MDUgNi40NzcxODV6IiBmaWxsPSIjZmZmIi8+PHBhdGggZD0ibTM4LjI0ODEgNy4wMjM4YzAgMi4zODEzMi02LjI3MzcgNC4yODY0LTE0LjA2ODMgNC4yODY0cy0xNC4wNjgzLTEuOTA1MDgtMTQuMDY4My00LjI4NjQgNi4yNzM3LTQuMjg2MzcgMTQuMDY4My00LjI4NjM3IDE0LjA2ODMgMS45MDUwNSAxNC4wNjgzIDQuMjg2Mzd6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0zNS4zMDEzIDkuNTk1NjNjMS44MDYxLS43NjIwMiAyLjk0NjgtMS42MTkzIDIuOTQ2OC0yLjU3MTgzIDAtMi4zODEzMi02LjI3MzctNC4yODYzNy0xNC4wNjgzLTQuMjg2MzdzLTE0LjA2ODMgMS45MDUwNS0xNC4wNjgzIDQuMjg2MzdjMCAuOTUyNTMgMS4xNDA3IDEuOTA1MDYgMi45NDY3IDIuNTcxODMgMi41NjY1LTEuMDQ3NzggNi42NTQtMS42MTkzIDExLjEyMTYtMS42MTkzczguNTU1LjY2Njc3IDExLjEyMTUgMS42MTkzeiIgZmlsbD0iIzgwODA4MCIvPg0KICA8ZyBmaWxsPSIjZmZmIj4NCiAgICA8cGF0aCBkPSJtMTguNDc1MiAzMS4xMjJjMCAxLjA0NzgtLjM4MDMgMS45MDUxLTEuMTQwNyAyLjQ3NjYtLjc2MDUuNTcxNS0xLjgwNjEuODU3My0zLjIzMTkuODU3My0xLjE0MDcgMC0yLjA5MTMtLjE5MDUtMi44NTE3LS42NjY4di0yLjQ3NjZjLjg1NTUuNzYyMSAxLjkwMTEgMS4xNDMxIDIuOTQ2NyAxLjE0MzEuNDc1MyAwIC45NTA2LS4wOTUzIDEuMjM1OC0uMjg1OC4yODUxLS4xOTA1LjM4MDItLjQ3NjIuMzgwMi0uODU3MyAwLS4zODEtLjA5NTEtLjY2NjctLjM4MDItLjg1NzItLjI4NTItLjI4NTgtLjg1NTUtLjU3MTUtMS43MTEtLjk1MjYtMS43MTExLS43NjItMi41NjY2LTEuOTA1LTIuNTY2Ni0zLjIzODYgMC0xLjA0NzcuMzgwMy0xLjgwOTggMS4xNDA3LTIuMzgxMy43NjA1LS41NzE1IDEuNzExLS45NTI1IDIuOTQ2Ny0uOTUyNSAxLjA0NTcgMCAxLjk5NjIuMTkwNSAyLjc1NjcuNDc2M3YyLjM4MTNjLS43NjA1LS40NzYzLTEuNjE2LS43NjItMi41NjY1LS43NjItLjQ3NTMgMC0uODU1NS4wOTUyLTEuMTQwNy4yODU3cy0uMzgwMi40NzYzLS4zODAyLjg1NzMuMDk1LjY2NjguMzgwMi44NTczYy4xOTAxLjE5MDUuNjY1NC40NzYyIDEuNDI1OC44NTcyIDEuMDQ1Ni40NzYzIDEuODA2MS45NTI2IDIuMjgxNCAxLjUyNDEuMjg1MS4zODEuNDc1My45NTI1LjQ3NTMgMS43MTQ1eiIvPjxwYXRoIGQ9Im0yNy44ODY4IDI4Ljc0MTJjMC0xLjE0My0uMjg1Mi0yLjAwMDMtLjc2MDQtMi42NjcxLS40NzUzLS42NjY3LTEuMTQwNy0uOTUyNS0xLjk5NjItLjk1MjVzLTEuNjE2LjI4NTgtMi4wOTEzLjk1MjVjLS41NzAzLjY2NjgtLjc2MDQgMS41MjQxLS43NjA0IDIuNjY3MSAwIDEuMDQ3OC4yODUyIDIuMDAwMy43NjA0IDIuNjY3MS40NzUzLjY2NjggMS4yMzU4Ljk1MjUgMi4wOTEzLjk1MjVzMS41MjA5LS4yODU3IDIuMDkxMi0uOTUyNWMuMzgwMi0uNjY2OC42NjU0LTEuNTI0MS42NjU0LTIuNjY3MXptMi42NjE2LS4wOTUyYzAgMS4zMzM1LS4yODUyIDIuNDc2NS0uODU1NSAzLjQyOTEtLjU3MDQuOTUyNS0xLjQyNTkgMS42MTkzLTIuNTY2NSAyLjAwMDNsMy4yMzE5IDMuMDQ4MWgtMy4yMzE5bC0yLjI4MTQtMi41NzE5Yy0uOTUwNiAwLTEuOTAxMS0uMjg1Ny0yLjY2MTYtLjc2Mi0uNzYwNC0uNDc2My0xLjQyNTgtMS4xNDMtMS44MDYtMi4wMDAzLS40NzUzLS44NTczLS42NjU0LTEuODA5OC0uNjY1NC0yLjg1NzYgMC0xLjE0My4xOTAxLTIuMTkwOC42NjU0LTMuMTQzMy40NzUzLS45NTI2IDEuMTQwNi0xLjYxOTMgMS45OTYyLTIuMDk1Ni44NTU1LS40NzYzIDEuODA2LS43NjIgMi45NDY3LS43NjIgMS4wNDU2IDAgMS45OTYyLjE5MDUgMi43NTY2LjY2NjguODU1NS40NzYyIDEuNDI1OSAxLjE0MyAxLjkwMTEgMi4wMDAzLjM4MDMuOTUyNS41NzA0IDEuOTA1LjU3MDQgMy4wNDgxeiIvPjxwYXRoIGQ9Im0zOS4xMDM2IDM0LjI2NTNoLTYuNzQ5di0xMS4xNDQ2aDIuNTY2NnY5LjE0NDNoNC4xODI0eiIvPg0KICA8L2c+DQo8L3N2Zz4NCg==) - [![Build status](https://ci.appveyor.com/api/projects/status/bak6km5grc3j63s8?svg=true)](https://ci.appveyor.com/project/LowlyDBA/dba-multitool) ![GitHub Workflow Status (branch)](https://img.shields.io/github/workflow/status/LowlyDBA/dba-multitool/Lint%20Code%20Base/master?label=lint%20code%20master) [![codecov](https://codecov.io/gh/LowlyDBA/dba-multitool/branch/master/graph/badge.svg)](https://codecov.io/gh/LowlyDBA/dba-multitool) @@ -57,6 +56,7 @@ and plays nice with: | @ExtendedPropertyName | SYSNAME(128) | no | Key for extended properties on objects. Default is 'Description'. | | @LimitStoredProcLength | BIT | no | Limit stored procedure contents to 8000 characters, to avoid memory issues with some IDEs. Default is 1. | | @Emojis | BIT | no | Use emojis when generating documentation. Default is 0. | +| @Verbose | BIT | no | Whether or not to print additional information during the script run. Default is 0. | | @SqlMajorVersion | TINYINT | no | Used for unit testing purposes only. | | @SqlMinorVersion | SMALLINT | no | Used for unit testing purposes only. | diff --git a/docs/sp_estindex.md b/docs/sp_estindex.md new file mode 100644 index 00000000..5585c341 --- /dev/null +++ b/docs/sp_estindex.md @@ -0,0 +1,62 @@ +# sp_estindex + +![License](https://img.shields.io/github/license/LowlyDBA/dba-multitool?color=blue) +![SQL Server](https://img.shields.io/badge/SQL%20Server-2012--2019-blue?logo=microsoft-sql-server) +![Azure SQL](https://img.shields.io/badge/Azure%20SQL-vCurrent-blue?logo=data:image/svg+xml;base64,PHN2ZyBkYXRhLXNsdWctaWQ9InNxbC1kYXRhYmFzZS1ibHVlIiB4bWxucz0iaHR0cDovL3d3dy53My5vcmcvMjAwMC9zdmciIHZpZXdCb3g9IjAgMCA0OSA0OSI+DQogIDxwYXRoIGQ9Im02LjQwNDIxIDcuNDA0NDJ2MzQuMTk1NzhjMCAzLjUyNDMgNy44ODk2OSA2LjQ3NzIgMTcuNjgwMzkgNi40Nzcydi00MC42NzI5OHoiIGZpbGw9IiM4MDgwODAiLz4NCiAgPHBhdGggZD0ibTIzLjg5NDYgNDguMDc3NGguMjg1MmM5Ljc5MDcgMCAxNy42ODA0LTIuODU3NiAxNy42ODA0LTYuNDc3MnYtMzQuMTk1NzhoLTE3Ljk2NTZ6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0yMy43MDQzIDQ4LjA3NzloLjI4NTJjOS44ODU4IDAgMTcuOTY1Ni0yLjg1NzYgMTcuOTY1Ni02LjQ3NzJ2LTM0LjI5MTAxaC0xOC4xNTU3eiIgZmlsbD0iIzgwODA4MCIvPg0KICA8cGF0aCBkPSJtNDEuODU4NCA3LjQwNTUzYzAgMy41MjQzNy03Ljg4OTcgNi40NzcxNy0xNy42ODA1IDYuNDc3MTctOS43OTA3IDAtMTcuNjgwMzktMi44NTc2LTE3LjY4MDM5LTYuNDc3MTcgMC0zLjYxOTYgNy44ODk2OS02LjQ3NzE4NSAxNy42ODAzOS02LjQ3NzE4NSA5Ljc5MDggMCAxNy42ODA1IDIuOTUyODM1IDE3LjY4MDUgNi40NzcxODV6IiBmaWxsPSIjZmZmIi8+PHBhdGggZD0ibTM4LjI0ODEgNy4wMjM4YzAgMi4zODEzMi02LjI3MzcgNC4yODY0LTE0LjA2ODMgNC4yODY0cy0xNC4wNjgzLTEuOTA1MDgtMTQuMDY4My00LjI4NjQgNi4yNzM3LTQuMjg2MzcgMTQuMDY4My00LjI4NjM3IDE0LjA2ODMgMS45MDUwNSAxNC4wNjgzIDQuMjg2Mzd6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0zNS4zMDEzIDkuNTk1NjNjMS44MDYxLS43NjIwMiAyLjk0NjgtMS42MTkzIDIuOTQ2OC0yLjU3MTgzIDAtMi4zODEzMi02LjI3MzctNC4yODYzNy0xNC4wNjgzLTQuMjg2MzdzLTE0LjA2ODMgMS45MDUwNS0xNC4wNjgzIDQuMjg2MzdjMCAuOTUyNTMgMS4xNDA3IDEuOTA1MDYgMi45NDY3IDIuNTcxODMgMi41NjY1LTEuMDQ3NzggNi42NTQtMS42MTkzIDExLjEyMTYtMS42MTkzczguNTU1LjY2Njc3IDExLjEyMTUgMS42MTkzeiIgZmlsbD0iIzgwODA4MCIvPg0KICA8ZyBmaWxsPSIjZmZmIj4NCiAgICA8cGF0aCBkPSJtMTguNDc1MiAzMS4xMjJjMCAxLjA0NzgtLjM4MDMgMS45MDUxLTEuMTQwNyAyLjQ3NjYtLjc2MDUuNTcxNS0xLjgwNjEuODU3My0zLjIzMTkuODU3My0xLjE0MDcgMC0yLjA5MTMtLjE5MDUtMi44NTE3LS42NjY4di0yLjQ3NjZjLjg1NTUuNzYyMSAxLjkwMTEgMS4xNDMxIDIuOTQ2NyAxLjE0MzEuNDc1MyAwIC45NTA2LS4wOTUzIDEuMjM1OC0uMjg1OC4yODUxLS4xOTA1LjM4MDItLjQ3NjIuMzgwMi0uODU3MyAwLS4zODEtLjA5NTEtLjY2NjctLjM4MDItLjg1NzItLjI4NTItLjI4NTgtLjg1NTUtLjU3MTUtMS43MTEtLjk1MjYtMS43MTExLS43NjItMi41NjY2LTEuOTA1LTIuNTY2Ni0zLjIzODYgMC0xLjA0NzcuMzgwMy0xLjgwOTggMS4xNDA3LTIuMzgxMy43NjA1LS41NzE1IDEuNzExLS45NTI1IDIuOTQ2Ny0uOTUyNSAxLjA0NTcgMCAxLjk5NjIuMTkwNSAyLjc1NjcuNDc2M3YyLjM4MTNjLS43NjA1LS40NzYzLTEuNjE2LS43NjItMi41NjY1LS43NjItLjQ3NTMgMC0uODU1NS4wOTUyLTEuMTQwNy4yODU3cy0uMzgwMi40NzYzLS4zODAyLjg1NzMuMDk1LjY2NjguMzgwMi44NTczYy4xOTAxLjE5MDUuNjY1NC40NzYyIDEuNDI1OC44NTcyIDEuMDQ1Ni40NzYzIDEuODA2MS45NTI2IDIuMjgxNCAxLjUyNDEuMjg1MS4zODEuNDc1My45NTI1LjQ3NTMgMS43MTQ1eiIvPjxwYXRoIGQ9Im0yNy44ODY4IDI4Ljc0MTJjMC0xLjE0My0uMjg1Mi0yLjAwMDMtLjc2MDQtMi42NjcxLS40NzUzLS42NjY3LTEuMTQwNy0uOTUyNS0xLjk5NjItLjk1MjVzLTEuNjE2LjI4NTgtMi4wOTEzLjk1MjVjLS41NzAzLjY2NjgtLjc2MDQgMS41MjQxLS43NjA0IDIuNjY3MSAwIDEuMDQ3OC4yODUyIDIuMDAwMy43NjA0IDIuNjY3MS40NzUzLjY2NjggMS4yMzU4Ljk1MjUgMi4wOTEzLjk1MjVzMS41MjA5LS4yODU3IDIuMDkxMi0uOTUyNWMuMzgwMi0uNjY2OC42NjU0LTEuNTI0MS42NjU0LTIuNjY3MXptMi42NjE2LS4wOTUyYzAgMS4zMzM1LS4yODUyIDIuNDc2NS0uODU1NSAzLjQyOTEtLjU3MDQuOTUyNS0xLjQyNTkgMS42MTkzLTIuNTY2NSAyLjAwMDNsMy4yMzE5IDMuMDQ4MWgtMy4yMzE5bC0yLjI4MTQtMi41NzE5Yy0uOTUwNiAwLTEuOTAxMS0uMjg1Ny0yLjY2MTYtLjc2Mi0uNzYwNC0uNDc2My0xLjQyNTgtMS4xNDMtMS44MDYtMi4wMDAzLS40NzUzLS44NTczLS42NjU0LTEuODA5OC0uNjY1NC0yLjg1NzYgMC0xLjE0My4xOTAxLTIuMTkwOC42NjU0LTMuMTQzMy40NzUzLS45NTI2IDEuMTQwNi0xLjYxOTMgMS45OTYyLTIuMDk1Ni44NTU1LS40NzYzIDEuODA2LS43NjIgMi45NDY3LS43NjIgMS4wNDU2IDAgMS45OTYyLjE5MDUgMi43NTY2LjY2NjguODU1NS40NzYyIDEuNDI1OSAxLjE0MyAxLjkwMTEgMi4wMDAzLjM4MDMuOTUyNS41NzA0IDEuOTA1LjU3MDQgMy4wNDgxeiIvPjxwYXRoIGQ9Im0zOS4xMDM2IDM0LjI2NTNoLTYuNzQ5di0xMS4xNDQ2aDIuNTY2NnY5LjE0NDNoNC4xODI0eiIvPg0KICA8L2c+DQo8L3N2Zz4NCg==) +[![Build status](https://ci.appveyor.com/api/projects/status/bak6km5grc3j63s8?svg=true)](https://ci.appveyor.com/project/LowlyDBA/dba-multitool) +![GitHub Workflow Status (branch)](https://img.shields.io/github/workflow/status/LowlyDBA/dba-multitool/Lint%20Code%20Base/master?label=lint%20code%20master) +[![codecov](https://codecov.io/gh/LowlyDBA/dba-multitool/branch/master/graph/badge.svg)](https://codecov.io/gh/LowlyDBA/dba-multitool) + +* [Purpose](#purpose) +* [Arguments](#arguments) +* [Usage](#usage) +* [Contributing](#contributing) +* [More](#more) + +## Purpose + +In complex environments, sometimes the best ways to create indexes aren't +the most obvious. Table size, underlying statistics, missing index +recommendations, fill factors, and uniqueness are just *some* of the +factors that need to be considered. But these can be difficult to +aggregate and experiment with since index creation has a very real +cost of time and compute power in large databases. + +To make index planning easier, `sp_estindex` gives you statistics on +how an index would look without having to actually create it! + +## Arguments + +| Parameter | Type | Output | Description | +| --- | --- | --- | --- | +| @SchemaName | SYSNAME(128) | no | Target schema of the index's table. Default is 'dbo'. | +| @TableName | SYSNAME(128) | no | Target table for the index. Default is current database. | +| @DatabaseName | SYSNAME(128) | no | Target database of the index's table. | +| @IndexColumns | NVARCHAR(2048) | no | Comma separated list of key columns. | +| @IncludeColumns | NVARCHAR(2048) | no | Optional comma separated list of include columns. | +| @IsUnique | BIT | no | Whether or not the index is UNIQUE. Default is 0. | +| @Filter | NVARCHAR(2048) | no | Optional filter for the index. Default is 100. | +| @FillFactor | TINYINT | no | Optional fill factor for the index. | +| @Verbose | BIT | no | Show intermediate variables used in size calculations. Default is 0. | +| @SqlMajorVersion | TINYINT | no | For unit testing only. | + +## Usage + +```tsql +EXEC dbo.sp_estindex @SchemaName = 'dbo', @tableName = 'Marathon', @IndexColumns = 'racer_id, finish_time'; +``` + +```tsql +EXEC dbo.sp_estindex @tableName = 'Marathon', @IndexColumns = 'racer_id, finish_time', @Filter = 'WHERE racer_id IS NOT NULL', @FillFactor = 90; +``` + +## Contributing + +Missing a feature? Found a bug? Open an [issue][issue] to get some :heart: + +## More + +Check out the other scripts in the [DBA MultiTool][tool]. + +[tool]: http://dba-multitool.org +[issue]: https://github.com/LowlyDBA/dba-multitool/issues diff --git a/docs/sp_helpme.md b/docs/sp_helpme.md index 8041604e..e9adc162 100644 --- a/docs/sp_helpme.md +++ b/docs/sp_helpme.md @@ -3,7 +3,6 @@ ![License](https://img.shields.io/github/license/LowlyDBA/dba-multitool?color=blue) ![SQL Server](https://img.shields.io/badge/SQL%20Server-2012--2019-blue?logo=microsoft-sql-server) ![Azure SQL](https://img.shields.io/badge/Azure%20SQL-vCurrent-blue?logo=data:image/svg+xml;base64,PHN2ZyBkYXRhLXNsdWctaWQ9InNxbC1kYXRhYmFzZS1ibHVlIiB4bWxucz0iaHR0cDovL3d3dy53My5vcmcvMjAwMC9zdmciIHZpZXdCb3g9IjAgMCA0OSA0OSI+DQogIDxwYXRoIGQ9Im02LjQwNDIxIDcuNDA0NDJ2MzQuMTk1NzhjMCAzLjUyNDMgNy44ODk2OSA2LjQ3NzIgMTcuNjgwMzkgNi40Nzcydi00MC42NzI5OHoiIGZpbGw9IiM4MDgwODAiLz4NCiAgPHBhdGggZD0ibTIzLjg5NDYgNDguMDc3NGguMjg1MmM5Ljc5MDcgMCAxNy42ODA0LTIuODU3NiAxNy42ODA0LTYuNDc3MnYtMzQuMTk1NzhoLTE3Ljk2NTZ6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0yMy43MDQzIDQ4LjA3NzloLjI4NTJjOS44ODU4IDAgMTcuOTY1Ni0yLjg1NzYgMTcuOTY1Ni02LjQ3NzJ2LTM0LjI5MTAxaC0xOC4xNTU3eiIgZmlsbD0iIzgwODA4MCIvPg0KICA8cGF0aCBkPSJtNDEuODU4NCA3LjQwNTUzYzAgMy41MjQzNy03Ljg4OTcgNi40NzcxNy0xNy42ODA1IDYuNDc3MTctOS43OTA3IDAtMTcuNjgwMzktMi44NTc2LTE3LjY4MDM5LTYuNDc3MTcgMC0zLjYxOTYgNy44ODk2OS02LjQ3NzE4NSAxNy42ODAzOS02LjQ3NzE4NSA5Ljc5MDggMCAxNy42ODA1IDIuOTUyODM1IDE3LjY4MDUgNi40NzcxODV6IiBmaWxsPSIjZmZmIi8+PHBhdGggZD0ibTM4LjI0ODEgNy4wMjM4YzAgMi4zODEzMi02LjI3MzcgNC4yODY0LTE0LjA2ODMgNC4yODY0cy0xNC4wNjgzLTEuOTA1MDgtMTQuMDY4My00LjI4NjQgNi4yNzM3LTQuMjg2MzcgMTQuMDY4My00LjI4NjM3IDE0LjA2ODMgMS45MDUwNSAxNC4wNjgzIDQuMjg2Mzd6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0zNS4zMDEzIDkuNTk1NjNjMS44MDYxLS43NjIwMiAyLjk0NjgtMS42MTkzIDIuOTQ2OC0yLjU3MTgzIDAtMi4zODEzMi02LjI3MzctNC4yODYzNy0xNC4wNjgzLTQuMjg2MzdzLTE0LjA2ODMgMS45MDUwNS0xNC4wNjgzIDQuMjg2MzdjMCAuOTUyNTMgMS4xNDA3IDEuOTA1MDYgMi45NDY3IDIuNTcxODMgMi41NjY1LTEuMDQ3NzggNi42NTQtMS42MTkzIDExLjEyMTYtMS42MTkzczguNTU1LjY2Njc3IDExLjEyMTUgMS42MTkzeiIgZmlsbD0iIzgwODA4MCIvPg0KICA8ZyBmaWxsPSIjZmZmIj4NCiAgICA8cGF0aCBkPSJtMTguNDc1MiAzMS4xMjJjMCAxLjA0NzgtLjM4MDMgMS45MDUxLTEuMTQwNyAyLjQ3NjYtLjc2MDUuNTcxNS0xLjgwNjEuODU3My0zLjIzMTkuODU3My0xLjE0MDcgMC0yLjA5MTMtLjE5MDUtMi44NTE3LS42NjY4di0yLjQ3NjZjLjg1NTUuNzYyMSAxLjkwMTEgMS4xNDMxIDIuOTQ2NyAxLjE0MzEuNDc1MyAwIC45NTA2LS4wOTUzIDEuMjM1OC0uMjg1OC4yODUxLS4xOTA1LjM4MDItLjQ3NjIuMzgwMi0uODU3MyAwLS4zODEtLjA5NTEtLjY2NjctLjM4MDItLjg1NzItLjI4NTItLjI4NTgtLjg1NTUtLjU3MTUtMS43MTEtLjk1MjYtMS43MTExLS43NjItMi41NjY2LTEuOTA1LTIuNTY2Ni0zLjIzODYgMC0xLjA0NzcuMzgwMy0xLjgwOTggMS4xNDA3LTIuMzgxMy43NjA1LS41NzE1IDEuNzExLS45NTI1IDIuOTQ2Ny0uOTUyNSAxLjA0NTcgMCAxLjk5NjIuMTkwNSAyLjc1NjcuNDc2M3YyLjM4MTNjLS43NjA1LS40NzYzLTEuNjE2LS43NjItMi41NjY1LS43NjItLjQ3NTMgMC0uODU1NS4wOTUyLTEuMTQwNy4yODU3cy0uMzgwMi40NzYzLS4zODAyLjg1NzMuMDk1LjY2NjguMzgwMi44NTczYy4xOTAxLjE5MDUuNjY1NC40NzYyIDEuNDI1OC44NTcyIDEuMDQ1Ni40NzYzIDEuODA2MS45NTI2IDIuMjgxNCAxLjUyNDEuMjg1MS4zODEuNDc1My45NTI1LjQ3NTMgMS43MTQ1eiIvPjxwYXRoIGQ9Im0yNy44ODY4IDI4Ljc0MTJjMC0xLjE0My0uMjg1Mi0yLjAwMDMtLjc2MDQtMi42NjcxLS40NzUzLS42NjY3LTEuMTQwNy0uOTUyNS0xLjk5NjItLjk1MjVzLTEuNjE2LjI4NTgtMi4wOTEzLjk1MjVjLS41NzAzLjY2NjgtLjc2MDQgMS41MjQxLS43NjA0IDIuNjY3MSAwIDEuMDQ3OC4yODUyIDIuMDAwMy43NjA0IDIuNjY3MS40NzUzLjY2NjggMS4yMzU4Ljk1MjUgMi4wOTEzLjk1MjVzMS41MjA5LS4yODU3IDIuMDkxMi0uOTUyNWMuMzgwMi0uNjY2OC42NjU0LTEuNTI0MS42NjU0LTIuNjY3MXptMi42NjE2LS4wOTUyYzAgMS4zMzM1LS4yODUyIDIuNDc2NS0uODU1NSAzLjQyOTEtLjU3MDQuOTUyNS0xLjQyNTkgMS42MTkzLTIuNTY2NSAyLjAwMDNsMy4yMzE5IDMuMDQ4MWgtMy4yMzE5bC0yLjI4MTQtMi41NzE5Yy0uOTUwNiAwLTEuOTAxMS0uMjg1Ny0yLjY2MTYtLjc2Mi0uNzYwNC0uNDc2My0xLjQyNTgtMS4xNDMtMS44MDYtMi4wMDAzLS40NzUzLS44NTczLS42NjU0LTEuODA5OC0uNjY1NC0yLjg1NzYgMC0xLjE0My4xOTAxLTIuMTkwOC42NjU0LTMuMTQzMy40NzUzLS45NTI2IDEuMTQwNi0xLjYxOTMgMS45OTYyLTIuMDk1Ni44NTU1LS40NzYzIDEuODA2LS43NjIgMi45NDY3LS43NjIgMS4wNDU2IDAgMS45OTYyLjE5MDUgMi43NTY2LjY2NjguODU1NS40NzYyIDEuNDI1OSAxLjE0MyAxLjkwMTEgMi4wMDAzLjM4MDMuOTUyNS41NzA0IDEuOTA1LjU3MDQgMy4wNDgxeiIvPjxwYXRoIGQ9Im0zOS4xMDM2IDM0LjI2NTNoLTYuNzQ5di0xMS4xNDQ2aDIuNTY2NnY5LjE0NDNoNC4xODI0eiIvPg0KICA8L2c+DQo8L3N2Zz4NCg==) - [![Build status](https://ci.appveyor.com/api/projects/status/bak6km5grc3j63s8?svg=true)](https://ci.appveyor.com/project/LowlyDBA/dba-multitool) ![GitHub Workflow Status (branch)](https://img.shields.io/github/workflow/status/LowlyDBA/dba-multitool/Lint%20Code%20Base/master?label=lint%20code%20master) [![codecov](https://codecov.io/gh/LowlyDBA/dba-multitool/branch/master/graph/badge.svg)](https://codecov.io/gh/LowlyDBA/dba-multitool) diff --git a/docs/sp_sizeoptimiser.md b/docs/sp_sizeoptimiser.md index 1c17b448..4590d537 100644 --- a/docs/sp_sizeoptimiser.md +++ b/docs/sp_sizeoptimiser.md @@ -3,7 +3,6 @@ ![License](https://img.shields.io/github/license/LowlyDBA/dba-multitool?color=blue) ![SQL Server](https://img.shields.io/badge/SQL%20Server-2012--2019-blue?logo=microsoft-sql-server) ![Azure SQL](https://img.shields.io/badge/Azure%20SQL-vCurrent-blue?logo=data:image/svg+xml;base64,PHN2ZyBkYXRhLXNsdWctaWQ9InNxbC1kYXRhYmFzZS1ibHVlIiB4bWxucz0iaHR0cDovL3d3dy53My5vcmcvMjAwMC9zdmciIHZpZXdCb3g9IjAgMCA0OSA0OSI+DQogIDxwYXRoIGQ9Im02LjQwNDIxIDcuNDA0NDJ2MzQuMTk1NzhjMCAzLjUyNDMgNy44ODk2OSA2LjQ3NzIgMTcuNjgwMzkgNi40Nzcydi00MC42NzI5OHoiIGZpbGw9IiM4MDgwODAiLz4NCiAgPHBhdGggZD0ibTIzLjg5NDYgNDguMDc3NGguMjg1MmM5Ljc5MDcgMCAxNy42ODA0LTIuODU3NiAxNy42ODA0LTYuNDc3MnYtMzQuMTk1NzhoLTE3Ljk2NTZ6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0yMy43MDQzIDQ4LjA3NzloLjI4NTJjOS44ODU4IDAgMTcuOTY1Ni0yLjg1NzYgMTcuOTY1Ni02LjQ3NzJ2LTM0LjI5MTAxaC0xOC4xNTU3eiIgZmlsbD0iIzgwODA4MCIvPg0KICA8cGF0aCBkPSJtNDEuODU4NCA3LjQwNTUzYzAgMy41MjQzNy03Ljg4OTcgNi40NzcxNy0xNy42ODA1IDYuNDc3MTctOS43OTA3IDAtMTcuNjgwMzktMi44NTc2LTE3LjY4MDM5LTYuNDc3MTcgMC0zLjYxOTYgNy44ODk2OS02LjQ3NzE4NSAxNy42ODAzOS02LjQ3NzE4NSA5Ljc5MDggMCAxNy42ODA1IDIuOTUyODM1IDE3LjY4MDUgNi40NzcxODV6IiBmaWxsPSIjZmZmIi8+PHBhdGggZD0ibTM4LjI0ODEgNy4wMjM4YzAgMi4zODEzMi02LjI3MzcgNC4yODY0LTE0LjA2ODMgNC4yODY0cy0xNC4wNjgzLTEuOTA1MDgtMTQuMDY4My00LjI4NjQgNi4yNzM3LTQuMjg2MzcgMTQuMDY4My00LjI4NjM3IDE0LjA2ODMgMS45MDUwNSAxNC4wNjgzIDQuMjg2Mzd6IiBmaWxsPSIjODA4MDgwIi8+DQogIDxwYXRoIGQ9Im0zNS4zMDEzIDkuNTk1NjNjMS44MDYxLS43NjIwMiAyLjk0NjgtMS42MTkzIDIuOTQ2OC0yLjU3MTgzIDAtMi4zODEzMi02LjI3MzctNC4yODYzNy0xNC4wNjgzLTQuMjg2MzdzLTE0LjA2ODMgMS45MDUwNS0xNC4wNjgzIDQuMjg2MzdjMCAuOTUyNTMgMS4xNDA3IDEuOTA1MDYgMi45NDY3IDIuNTcxODMgMi41NjY1LTEuMDQ3NzggNi42NTQtMS42MTkzIDExLjEyMTYtMS42MTkzczguNTU1LjY2Njc3IDExLjEyMTUgMS42MTkzeiIgZmlsbD0iIzgwODA4MCIvPg0KICA8ZyBmaWxsPSIjZmZmIj4NCiAgICA8cGF0aCBkPSJtMTguNDc1MiAzMS4xMjJjMCAxLjA0NzgtLjM4MDMgMS45MDUxLTEuMTQwNyAyLjQ3NjYtLjc2MDUuNTcxNS0xLjgwNjEuODU3My0zLjIzMTkuODU3My0xLjE0MDcgMC0yLjA5MTMtLjE5MDUtMi44NTE3LS42NjY4di0yLjQ3NjZjLjg1NTUuNzYyMSAxLjkwMTEgMS4xNDMxIDIuOTQ2NyAxLjE0MzEuNDc1MyAwIC45NTA2LS4wOTUzIDEuMjM1OC0uMjg1OC4yODUxLS4xOTA1LjM4MDItLjQ3NjIuMzgwMi0uODU3MyAwLS4zODEtLjA5NTEtLjY2NjctLjM4MDItLjg1NzItLjI4NTItLjI4NTgtLjg1NTUtLjU3MTUtMS43MTEtLjk1MjYtMS43MTExLS43NjItMi41NjY2LTEuOTA1LTIuNTY2Ni0zLjIzODYgMC0xLjA0NzcuMzgwMy0xLjgwOTggMS4xNDA3LTIuMzgxMy43NjA1LS41NzE1IDEuNzExLS45NTI1IDIuOTQ2Ny0uOTUyNSAxLjA0NTcgMCAxLjk5NjIuMTkwNSAyLjc1NjcuNDc2M3YyLjM4MTNjLS43NjA1LS40NzYzLTEuNjE2LS43NjItMi41NjY1LS43NjItLjQ3NTMgMC0uODU1NS4wOTUyLTEuMTQwNy4yODU3cy0uMzgwMi40NzYzLS4zODAyLjg1NzMuMDk1LjY2NjguMzgwMi44NTczYy4xOTAxLjE5MDUuNjY1NC40NzYyIDEuNDI1OC44NTcyIDEuMDQ1Ni40NzYzIDEuODA2MS45NTI2IDIuMjgxNCAxLjUyNDEuMjg1MS4zODEuNDc1My45NTI1LjQ3NTMgMS43MTQ1eiIvPjxwYXRoIGQ9Im0yNy44ODY4IDI4Ljc0MTJjMC0xLjE0My0uMjg1Mi0yLjAwMDMtLjc2MDQtMi42NjcxLS40NzUzLS42NjY3LTEuMTQwNy0uOTUyNS0xLjk5NjItLjk1MjVzLTEuNjE2LjI4NTgtMi4wOTEzLjk1MjVjLS41NzAzLjY2NjgtLjc2MDQgMS41MjQxLS43NjA0IDIuNjY3MSAwIDEuMDQ3OC4yODUyIDIuMDAwMy43NjA0IDIuNjY3MS40NzUzLjY2NjggMS4yMzU4Ljk1MjUgMi4wOTEzLjk1MjVzMS41MjA5LS4yODU3IDIuMDkxMi0uOTUyNWMuMzgwMi0uNjY2OC42NjU0LTEuNTI0MS42NjU0LTIuNjY3MXptMi42NjE2LS4wOTUyYzAgMS4zMzM1LS4yODUyIDIuNDc2NS0uODU1NSAzLjQyOTEtLjU3MDQuOTUyNS0xLjQyNTkgMS42MTkzLTIuNTY2NSAyLjAwMDNsMy4yMzE5IDMuMDQ4MWgtMy4yMzE5bC0yLjI4MTQtMi41NzE5Yy0uOTUwNiAwLTEuOTAxMS0uMjg1Ny0yLjY2MTYtLjc2Mi0uNzYwNC0uNDc2My0xLjQyNTgtMS4xNDMtMS44MDYtMi4wMDAzLS40NzUzLS44NTczLS42NjU0LTEuODA5OC0uNjY1NC0yLjg1NzYgMC0xLjE0My4xOTAxLTIuMTkwOC42NjU0LTMuMTQzMy40NzUzLS45NTI2IDEuMTQwNi0xLjYxOTMgMS45OTYyLTIuMDk1Ni44NTU1LS40NzYzIDEuODA2LS43NjIgMi45NDY3LS43NjIgMS4wNDU2IDAgMS45OTYyLjE5MDUgMi43NTY2LjY2NjguODU1NS40NzYyIDEuNDI1OSAxLjE0MyAxLjkwMTEgMi4wMDAzLjM4MDMuOTUyNS41NzA0IDEuOTA1LjU3MDQgMy4wNDgxeiIvPjxwYXRoIGQ9Im0zOS4xMDM2IDM0LjI2NTNoLTYuNzQ5di0xMS4xNDQ2aDIuNTY2NnY5LjE0NDNoNC4xODI0eiIvPg0KICA8L2c+DQo8L3N2Zz4NCg==) - [![Build status](https://ci.appveyor.com/api/projects/status/bak6km5grc3j63s8?svg=true)](https://ci.appveyor.com/project/LowlyDBA/dba-multitool) ![GitHub Workflow Status (branch)](https://img.shields.io/github/workflow/status/LowlyDBA/dba-multitool/Lint%20Code%20Base/master?label=lint%20code%20master) [![codecov](https://codecov.io/gh/LowlyDBA/dba-multitool/branch/master/graph/badge.svg)](https://codecov.io/gh/LowlyDBA/dba-multitool) diff --git a/install_dba-multitool.sql b/install_dba-multitool.sql index dc88292a..c989f141 100644 Binary files a/install_dba-multitool.sql and b/install_dba-multitool.sql differ diff --git a/sp_doc.sql b/sp_doc.sql index bb8b6946..b49d80f4 100644 --- a/sp_doc.sql +++ b/sp_doc.sql @@ -46,6 +46,15 @@ IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@Emojis' , N'SCHEMA',N'd END GO +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@Verbose' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_doc', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@Verbose' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_doc'; + END +GO + +/***************************/ +/* Create stored procedure */ +/***************************/ IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[sp_doc]') AND [type] IN (N'P', N'PC')) BEGIN EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[sp_doc] AS'; @@ -57,6 +66,7 @@ ALTER PROCEDURE [dbo].[sp_doc] ,@ExtendedPropertyName SYSNAME = 'Description' ,@LimitStoredProcLength BIT = 1 ,@Emojis BIT = 0 + ,@Verbose BIT = 1 /* Parameters defined here for testing only */ ,@SqlMajorVersion TINYINT = 0 ,@SqlMinorVersion SMALLINT = 0 @@ -131,6 +141,11 @@ BEGIN IF (@DatabaseName IS NULL) BEGIN SET @DatabaseName = DB_NAME(); + IF (@Verbose = 1) + BEGIN; + SET @Msg = 'No database provided, assuming current database.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; END ELSE IF (DB_ID(@DatabaseName) IS NULL) BEGIN; @@ -1170,3 +1185,7 @@ GO EXEC sys.sp_addextendedproperty @name=N'@Emojis', @value=N'Use emojis when generating documentation. Default is 0.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_doc'; GO + +EXEC sys.sp_addextendedproperty @name=N'@Verbose', @value=N'Whether or not to print additional information during the script run. Default is 0.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_doc'; +GO + diff --git a/sp_estindex.sql b/sp_estindex.sql new file mode 100644 index 00000000..4c2e1a75 --- /dev/null +++ b/sp_estindex.sql @@ -0,0 +1,874 @@ +SET ANSI_NULLS ON; +GO + +SET QUOTED_IDENTIFIER ON; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'Description' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'Description' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@TableName' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@TableName' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@SqlMajorVersion' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@SqlMajorVersion' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@SchemaName' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@SchemaName' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IsUnique' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@IsUnique' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IndexColumns' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@IndexColumns' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IncludeColumns' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@IncludeColumns' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@Filter' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@Filter' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@FillFactor' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@FillFactor' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@DatabaseName' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@DatabaseName' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@Verbose' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_estindex', NULL,NULL)) + BEGIN; + EXEC sys.sp_dropextendedproperty @name=N'@Verbose' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; + END; +GO + +/***************************/ +/* Create stored procedure */ +/***************************/ +IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[sp_estindex]') AND [type] IN (N'P', N'PC')) + BEGIN; + EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[sp_estindex] AS'; + END +GO + +ALTER PROCEDURE [dbo].[sp_estindex] + @SchemaName SYSNAME = NULL + ,@TableName SYSNAME + ,@DatabaseName SYSNAME = NULL + ,@IndexColumns NVARCHAR(2048) + ,@IncludeColumns NVARCHAR(2048) = NULL + ,@IsUnique BIT = 0 + ,@Filter NVARCHAR(2048) = '' + ,@FillFactor TINYINT = 100 + ,@Verbose BIT = 0 + -- Unit testing only + ,@SqlMajorVersion TINYINT = 0 +AS +BEGIN + +SET NOCOUNT ON; + +/* +sp_estindex - Estimate a new index's size and statistics. + +Part of the DBA MultiTool http://dba-multitool.org + +Version: 20201016 + +MIT License + +Copyright (c) 2020 John McCall + +Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated +documentation files (the "Software"), to deal in the Software without restriction, including without limitation +the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, +and to permit persons to whom the Software is furnished to do so, subject to the following conditions: + +The above copyright notice and this permission notice shall be included in all copies or substantial +portions of the Software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED +TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL +THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF +CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER +DEALINGS IN THE SOFTWARE. + +-- TODO: + -- Handle clustered indexes - https://docs.microsoft.com/en-us/sql/relational-databases/databases/estimate-the-size-of-a-clustered-index?view=sql-server-ver15 + +========= + +Example: + + EXEC dbo.sp_estindex @SchemaName = 'dbo', @tableName = 'Marathon', @IndexColumns = 'racer_id, finish_time, is_disqualified'; + + EXEC dbo.sp_estindex @tableName = 'Marathon', @IndexColumns = 'racer_id, finish_time, is_disqualified', @Filter = 'WHERE racer_id IS NOT NULL', @FillFactor = 90; + +*/ + +DECLARE @Sql NVARCHAR(MAX) = N'' + ,@QualifiedTable NVARCHAR(257) + ,@IndexName SYSNAME = CONCAT('sp_estindex_hypothetical_idx_', DATEDIFF(SECOND,'1970-01-01 00:08:46', GETUTCDATE())) + ,@DropIndexSql NVARCHAR(MAX) + ,@Msg NVARCHAR(MAX) = N'' + ,@IndexType SYSNAME = 'NONCLUSTERED' + ,@IsHeap BIT + ,@IsClusterUnique BIT + ,@ObjectID INT + ,@IndexID INT + ,@ParmDefinition NVARCHAR(MAX) = N'' + ,@NumRows BIGINT + ,@UseDatabase NVARCHAR(200) + ,@UniqueSql VARCHAR(10) + ,@IncludeSql VARCHAR(2048); + +BEGIN TRY + -- Find Version + IF (@SqlMajorVersion = 0) + BEGIN; + SET @SqlMajorVersion = CAST(SERVERPROPERTY('ProductMajorVersion') AS TINYINT); + END; + + /* Validate Version */ + IF (@SqlMajorVersion < 11) + BEGIN; + SET @Msg = 'SQL Server versions below 2012 are not supported, sorry!'; + RAISERROR(@Msg, 16, 1); + END; + + /* Validate Fill Factor */ + IF (@FillFactor > 100 OR @FillFactor < 1) + BEGIN; + SET @Msg = 'Fill factor must be between 1 and 100.'; + THROW 51000, @Msg, 1; + END; + + /* Validate Database */ + IF (@DatabaseName IS NULL) + BEGIN; + SET @DatabaseName = DB_NAME(); + IF (@Verbose = 1) + BEGIN; + SET @Msg = 'No database provided, assuming current database.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + END; + ELSE IF (DB_ID(@DatabaseName) IS NULL) + BEGIN; + SET @DatabaseName = DB_NAME(); + SET @Msg = 'Database does not exist.'; + RAISERROR(@Msg, 16, 1); + END; + + /* Validate Schema */ + IF (@SchemaName IS NULL) + BEGIN; + SET @SchemaName = 'dbo'; + IF (@Verbose = 1) + BEGIN; + SET @Msg = 'No schema provided, assuming dbo.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + END; + + -- Set variables with validated params + SET @QualifiedTable = CONCAT(QUOTENAME(@SchemaName), '.', QUOTENAME(@TableName)); + SET @UseDatabase = N'USE ' + QUOTENAME(@DatabaseName) + '; '; + IF (@IsUnique = 1) + BEGIN; + SET @UniqueSql = ' UNIQUE '; + END; + IF (@IncludeColumns IS NOT NULL) + BEGIN; + SET @IncludeSql = CONCAT(' INCLUDE(', @IncludeColumns, ') '); + END; + + -- Find object id + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @ObjectID = [object_id] + FROM [sys].[all_objects] + WHERE [object_id] = OBJECT_ID(@QualifiedTable)'); + SET @ParmDefinition = N'@QualifiedTable NVARCHAR(257) + ,@ObjectID BIGINT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@QualifiedTable + ,@ObjectID OUTPUT; + + -- Determine Heap or Clustered + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @IsHeap = CASE [type] WHEN 0 THEN 1 ELSE 0 END + ,@IsClusterUnique = [is_unique] + FROM [sys].[indexes] + WHERE [object_id] = OBJECT_ID(@QualifiedTable) + AND [type] IN (1, 0)'); + SET @ParmDefinition = N'@QualifiedTable NVARCHAR(257), @IsHeap BIT OUTPUT, @IsClusterUnique BIT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@QualifiedTable + ,@IsHeap OUTPUT + ,@IsClusterUnique OUTPUT; + + -- Safety check for leftover index from previous run + SET @DropIndexSql = CONCAT(@UseDatabase, + N'IF EXISTS (SELECT 1 FROM [sys].[indexes] WHERE [object_id] = OBJECT_ID(''',@QualifiedTable,''') AND [name] = ''',@IndexName,''') + DROP INDEX ', QUOTENAME(@IndexName), ' ON ', @QualifiedTable); + EXEC sp_executesql @DropIndexSql; + + -- Fetch missing index stats before creation + IF OBJECT_ID('tempdb..##TempMissingIndex') IS NOT NULL + BEGIN; + DROP TABLE ##TempMissingIndex; + END; + + SET @Sql = CONCAT(@UseDatabase, + N'SELECT [id].[statement] + ,[id].[equality_columns] + ,[id].[inequality_columns] + ,[id].[included_columns] + ,[gs].[unique_compiles] + ,[gs].[user_seeks] + ,[gs].[user_scans] + ,[gs].[avg_total_user_cost] -- Average cost of the user queries that could be reduced + ,[gs].[avg_user_impact] -- % + INTO ##TempMissingIndex + FROM [sys].[dm_db_missing_index_group_stats] [gs] + INNER JOIN [sys].[dm_db_missing_index_groups] [ig] ON [gs].[group_handle] = [ig].[index_group_handle] + INNER JOIN [sys].[dm_db_missing_index_details] [id] ON [ig].[index_handle] = [id].[index_handle] + WHERE [id].[database_id] = DB_ID() + AND [id].[object_id] = @ObjectID + OPTION (RECOMPILE);'); + SET @ParmDefinition = N'@ObjectID INT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@ObjectID; + + -- Create the hypothetical index + SET @Sql = CONCAT(@UseDatabase, 'CREATE ', @UniqueSql, @IndexType, ' INDEX ', QUOTENAME(@IndexName), ' ON ', @QualifiedTable, ' (', @IndexColumns, ') ',@IncludeSql, @Filter, ' WITH (STATISTICS_ONLY = -1)'); + EXEC sp_executesql @Sql; + + /*******************/ + /* Get index stats */ + /*******************/ + SET @Sql = CONCAT(@UseDatabase, 'DBCC SHOW_STATISTICS ("', @QualifiedTable,'", ', QUOTENAME(@IndexName), ')'); + EXEC sp_executesql @Sql; + + /***************************/ + /* Get missing index stats */ + /***************************/ + DECLARE @QuotedKeyColumns NVARCHAR(2048) + ,@QuotedInclColumns NVARCHAR(2048); + + --Get index columns in same format as dmv table + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @QuotedKeyColumns = CASE [ic].[is_included_column] WHEN 0 + THEN COALESCE(@QuotedKeyColumns + '', '', '''') + QUOTENAME([ac].[name]) + ELSE @QuotedKeyColumns + END, + @QuotedInclColumns = CASE [ic].[is_included_column] WHEN 1 + THEN COALESCE(@QuotedInclColumns + '', '', '''') + QUOTENAME([ac].[name]) + ELSE @QuotedInclColumns + END + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1;'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID INT, @QuotedKeyColumns NVARCHAR(2048) OUTPUT, @QuotedInclColumns NVARCHAR(2048) OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@QuotedKeyColumns OUTPUT + ,@QuotedInclColumns OUTPUT; + + -- Search missing index dmv for a match + SELECT 'Missing index stats' AS [description] + ,[statement] + ,[equality_columns] + ,[inequality_columns] + ,[included_columns] + ,[unique_compiles] + ,[user_seeks] + ,[user_scans] + ,[avg_total_user_cost] + ,[avg_user_impact] + FROM ##TempMissingIndex + WHERE COALESCE([equality_columns] + ', ', '') + [inequality_columns] = @QuotedKeyColumns + AND ([included_columns] = @QuotedInclColumns OR [included_columns] IS NULL); + + IF (SELECT COUNT(*) FROM ##TempMissingIndex) = 0 AND (@Verbose = 1) + BEGIN; + SET @Msg = 'No matching missing index statistics found.'; + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + DROP TABLE ##TempMissingIndex; + + /************************************************/ + /* Estimate index size - does NOT consider: */ + /* Partitioning, allocation pages, LOB values, */ + /* compression, or sparse columns */ + /************************************************/ + IF (@IndexType = 'NONCLUSTERED') -- http://dba-multitool.org/est-nonclustered-index-size + BEGIN; + DECLARE @NumVariableKeyCols INT = 0 + ,@MaxVarKeySize INT = 0 + ,@NumFixedKeyCols INT = 0 + ,@FixedKeySize INT = 0 + ,@NumKeyCols INT = 0 + ,@NullCols INT = 0 + ,@IndexNullBitmap INT = 0 + ,@VariableKeySize INT = 0 + ,@TotalFixedKeySize INT = 0 + ,@IndexRowSize INT = 0 + ,@IndexRowsPerPage INT = 0 + ,@ClusterNumVarKeyCols INT = 0 + ,@MaxClusterVarKeySize INT = 0 + ,@ClusterNumFixedKeyCols INT = 0 + ,@MaxClusterFixedKeySize INT = 0 + ,@ClusterNullCols INT = 0; + + /**************************/ + /* 1. Calculate variables */ + /**************************/ + -- Row count + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @NumRows = SUM([ps].[row_count]) + FROM [sys].[objects] AS [o] + INNER JOIN [sys].[dm_db_partition_stats] AS [ps] ON [o].[object_id] = [ps].[object_id] + WHERE [o].[type] = ''U'' + AND [o].[is_ms_shipped] = 0 + AND [ps].[index_id] < 2 + AND [o].[object_id] = @ObjectID + GROUP BY [o].[schema_id], [o].[name];'); + SET @ParmDefinition = N'@ObjectID BIGINT, @NumRows BIGINT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@ObjectID + ,@NumRows OUTPUT; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumRows: ', @NumRows); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + --Key types and sizes + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @NumVariableKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxVarKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN CASE [ac].[max_length] + WHEN -1 + THEN(4000 + 2) -- use same estimation as the query engine for max lenths + ELSE COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + END + ELSE 0 + END), 0), + @NumFixedKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @FixedKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + ELSE 0 + END), 0), + @NullCols = ISNULL(SUM(CAST([ac].[is_nullable] AS TINYINT)),0) + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1 + AND [ic].[is_included_column] = 0'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID BIGINT, @NumVariableKeyCols INT OUTPUT, + @MaxVarKeySize INT OUTPUT, @NumFixedKeyCols INT OUTPUT, @FixedKeySize INT OUTPUT, + @NullCols INT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@NumVariableKeyCols OUTPUT + ,@MaxVarKeySize OUTPUT + ,@NumFixedKeyCols OUTPUT + ,@FixedKeySize OUTPUT + ,@NullCols OUTPUT; + + SET @NumKeyCols = @NumVariableKeyCols + @NumFixedKeyCols; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumVariableKeyCols: ', @NumVariableKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxVarKeySize: ', @MaxVarKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumFixedKeyCols: ', @NumFixedKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('FixedKeySize: ', @FixedKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NullCols: ', @NullCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumKeyCols: ', @NumKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Account for data row locator for non-unique + IF (@IsHeap = 1 AND @IsUnique = 0) + BEGIN; + SET @NumKeyCols = @NumKeyCols + 1; + SET @NumVariableKeyCols = @NumVariableKeyCols + 1; + SET @MaxVarKeySize = @MaxVarKeySize + 8; --heap RID + END; + ELSE IF (@IsHeap = 0 AND @IsUnique = 0) + BEGIN; + --Clustered keys and sizes not included in the new index + SET @Sql = CONCAT(@UseDatabase, + N'WITH NewIndexCol AS ( + SELECT [ac].[name] + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1 + AND [ic].[is_included_column] = 0 + ) + SELECT @ClusterNumVarKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxClusterVarKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN CASE [ac].[max_length] + WHEN -1 + THEN(4000 + 2) -- use same estimation as the query engine for max lenths + ELSE COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + END + ELSE 0 + END), 0), + @ClusterNumFixedKeyCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxClusterFixedKeySize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + ELSE 0 + END), 0), + @ClusterNullCols = ISNULL(SUM(CAST([ac].[is_nullable] AS TINYINT)),0) + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[type] = 1 --Clustered + AND [i].[object_id] = @ObjectID + AND [ac].[name] NOT IN (SELECT [name] FROM [NewIndexCol]);'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID BIGINT, @ClusterNumVarKeyCols INT OUTPUT, + @MaxClusterVarKeySize INT OUTPUT, @ClusterNumFixedKeyCols INT OUTPUT, + @MaxClusterFixedKeySize INT OUTPUT, @ClusterNullCols INT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@ClusterNumVarKeyCols OUTPUT + ,@MaxClusterVarKeySize OUTPUT + ,@ClusterNumFixedKeyCols OUTPUT + ,@MaxClusterFixedKeySize OUTPUT + ,@ClusterNullCols OUTPUT; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('ClusterNumVarKeyCols: ', @ClusterNumVarKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('ClusterNumFixedKeyCols: ', @ClusterNumFixedKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxClusterVarKeySize: ', @MaxClusterVarKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxClusterFixedKeySize: ', @MaxClusterFixedKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('ClusterNullCols: ', @ClusterNullCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Add counts from clustered index cols + SET @NumKeyCols = @NumKeyCols + (@ClusterNumVarKeyCols + @ClusterNumFixedKeyCols); + SET @FixedKeySize = @FixedKeySize + @MaxClusterFixedKeySize; + SET @NumVariableKeyCols = @NumVariableKeyCols + @ClusterNumVarKeyCols; + SET @MaxVarKeySize = @MaxVarKeySize + @MaxClusterVarKeySize; + SET @NullCols = @NullCols + @ClusterNullCols; + + IF (@IsClusterUnique = 0) + BEGIN; + SET @MaxVarKeySize = @MaxVarKeySize + 4; + SET @NumVariableKeyCols = @NumVariableKeyCols + 1; + SET @NumKeyCols = @NumKeyCols + 1; + END; + END; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('FixedKeySize: ', @FixedKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumVariableKeyCols: ', @NumVariableKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumKeyCols: ', @NumKeyCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxVarKeySize: ', @MaxVarKeySize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NullCols: ', @NullCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Account for index null bitmap + IF (@NullCols > 0) + BEGIN; + SET @IndexNullBitmap = 2 + ((@NullCols + 7) / 8); + END; + + -- Calculate variable length data size + -- Assumes each col is 100% full + IF (@NumVariableKeyCols > 0) + BEGIN; + SET @VariableKeySize = 2 + (@NumVariableKeyCols * 2) + @MaxVarKeySize; --The bytes added to @MaxVarKeySize are for tracking each variable column. + END; + + -- Calculate index row size + SET @IndexRowSize = @FixedKeySize + @VariableKeySize + @IndexNullBitmap + 1 + 6; -- + 1 (for row header overhead of an index row) + 6 (for the child page ID pointer) + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('IndexRowSize: ', @IndexRowSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + --Calculate number of index rows / page + SET @IndexRowsPerPage = FLOOR(8096 / (@IndexRowSize + 2)); -- + 2 for the row's entry in the page's slot array. + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('IndexRowsPerPage: ', @IndexRowsPerPage); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + /****************************************************************************/ + /* 2. Calculate the Space Used to Store Index Information in the Leaf Level */ + /****************************************************************************/ + -- Specify the number of fixed-length and variable-length columns at the leaf level + -- and calculate the space that is required for their storage + DECLARE @NumLeafCols INT = @NumKeyCols + ,@FixedLeafSize INT = @FixedKeySize + ,@NumVariableLeafCols INT = @NumVariableKeyCols + ,@MaxVarLeafSize INT = @MaxVarKeySize + ,@LeafNullBitmap INT = 0 + ,@VariableLeafSize INT = 0 + ,@LeafRowSize INT = 0 + ,@LeafRowsPerPage INT = 0 + ,@FreeRowsPerPage INT = 0 + ,@NumLeafPages INT = 0 + ,@LeafSpaceUsed INT = 0; + + IF (@IncludeColumns IS NOT NULL) + BEGIN; + DECLARE @NumVariableInclCols INT = 0 + ,@MaxVarInclSize INT = 0 + ,@NumFixedInclCols INT = 0 + ,@FixedInclSize INT = 0; + + --Incl types and sizes + SET @Sql = CONCAT(@UseDatabase, + N'SELECT @NumVariableInclCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @MaxVarInclSize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN CASE [ac].[max_length] + WHEN -1 + THEN (4000 + 2) -- use same estimation as the query engine for max lenths + ELSE COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + END + ELSE 0 + END), 0), + @NumFixedInclCols = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN 1 + ELSE 0 + END), 0), + @FixedInclSize = ISNULL(SUM(CASE + WHEN TYPE_NAME([ac].[user_type_id]) NOT IN(''varchar'', ''nvarchar'', ''text'', ''ntext'', ''image'', ''varbinary'', ''xml'') + THEN COL_LENGTH(OBJECT_NAME([i].object_id), [ac].[name]) + ELSE 0 + END), 0) + FROM [sys].[indexes] AS [i] + INNER JOIN [sys].[index_columns] AS [ic] ON [i].[index_id] = [ic].[index_id] + AND [ic].object_id = [i].object_id + INNER JOIN [sys].[all_columns] AS [ac] ON [ac].object_id = [ic].object_id + AND [ac].[column_id] = [ic].[column_id] + WHERE [i].[name] = @IndexName + AND [i].[object_id] = @ObjectID + AND [i].[is_hypothetical] = 1 + AND [ic].[is_included_column] = 1;'); + SET @ParmDefinition = N'@IndexName SYSNAME, @ObjectID BIGINT, @NumVariableInclCols INT OUTPUT, + @MaxVarInclSize INT OUTPUT, @NumFixedInclCols INT OUTPUT, @FixedInclSize INT OUTPUT'; + EXEC sp_executesql @Sql + ,@ParmDefinition + ,@IndexName + ,@ObjectID + ,@NumVariableInclCols OUTPUT + ,@MaxVarInclSize OUTPUT + ,@NumFixedInclCols OUTPUT + ,@FixedInclSize OUTPUT; + + -- Add included columns to rolling totals + SET @NumLeafCols = @NumLeafCols + (@NumVariableInclCols + @NumFixedInclCols); + SET @FixedLeafSize = @FixedLeafSize + @FixedInclSize; + SET @NumVariableLeafCols = @NumVariableLeafCols + @NumVariableInclCols; + SET @MaxVarLeafSize = @MaxVarLeafSize + @MaxVarInclSize; + END; + + -- Account for data row locator for unique indexes + -- If non-unique, already accounted for above + IF (@IsUnique = 1) + BEGIN; + IF (@IsHeap = 1) + BEGIN; + SET @NumLeafCols = @NumLeafCols + 1; + SET @NumVariableLeafCols = @NumVariableLeafCols + 1; + SET @MaxVarLeafSize = @MaxVarLeafSize + 8; -- the data row locator is the heap RID (size 8 bytes). + END; + ELSE -- Clustered + BEGIN; + SET @NumLeafCols = @NumLeafCols + (@ClusterNumVarKeyCols + @ClusterNumFixedKeyCols); + SET @FixedLeafSize = @FixedLeafSize + @ClusterNumFixedKeyCols; + SET @NumVariableLeafCols = @NumVariableLeafCols + @ClusterNumVarKeyCols; + SET @MaxVarLeafSize = @MaxVarLeafSize + @MaxClusterVarKeySize; + + IF (@IsClusterUnique = 0) + BEGIN; + SET @NumLeafCols = @NumLeafCols + 1; + SET @NumVariableLeafCols = @NumVariableLeafCols + 1; + SET @MaxVarLeafSize = @MaxVarLeafSize + 4; + END; + END; + END; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumLeafCols: ', @NumLeafCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('FixedLeafSize: ', @FixedLeafSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('NumVariableLeafCols: ', @NumVariableLeafCols); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + SET @Msg = CONCAT('MaxVarLeafSize: ', @MaxVarLeafSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Account for index null bitmap + SET @LeafNullBitmap = 2 + ((@NumLeafCols + 7) / 8); + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('LeafNullBitmap: ', @LeafNullBitmap); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate variable length data size + -- Assumes each col is 100% full + IF (@NumVariableLeafCols > 0) + BEGIN; + SET @VariableLeafSize = 2 + (@NumVariableLeafCols * 2) + @MaxVarLeafSize; + END; + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('VariableLeafSize: ', @VariableLeafSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate index row size + SET @LeafRowSize = @FixedLeafSize + @VariableLeafSize + @LeafNullBitmap + 1; -- +1 for row header overhead of an index row) + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('LeafRowSize: ', @LeafRowSize); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate number of index rows / page + SET @LeafRowsPerPage = FLOOR(8096 / (@LeafRowSize + 2)); -- + 2 for the row's entry in the page's slot array. + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('LeafRowsPerPage: ', @LeafRowsPerPage); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate free rows / page + SET @FreeRowsPerPage = 8096 * (( 100 - @FillFactor) / 100) / (@LeafRowSize + 2); -- + 2 for the row's entry in the page's slot array. + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('FreeRowsPerPage: ', @FreeRowsPerPage); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate pages for all rows + SET @NumLeafPages = CEILING(@NumRows / (@LeafRowsPerPage - @FreeRowsPerPage)); + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NumLeafPages: ', @NumLeafPages); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + -- Calculate size of index at leaf level + SET @LeafSpaceUsed = 8192 * @NumLeafPages; + + /*********************************************************************************/ + /* 3. Calculate the Space Used to Store Index Information in the Non-leaf Levels */ + /*********************************************************************************/ + DECLARE @NonLeafLevels INT = 0, + @NumIndexPages INT = 0, + @IndexSpaceUsed INT = 0; + + -- Calculate the number of non-leaf levels in the index + SET @NonLeafLevels = CEILING(1 + LOG(@IndexRowsPerPage) * (@NumLeafPages / @IndexRowsPerPage)); + + IF (@Verbose = 1) + BEGIN + SET @Msg = CONCAT('NonLeafLevels: ', @NonLeafLevels); + RAISERROR(@Msg, 10, 1) WITH NOWAIT; + END; + + --Formula: IndexPages = ∑Level (Num_Leaf_Pages/Index_Rows_Per_Page^Level)where 1 <= Level <= Levels + WHILE (@NonLeafLevels > 1) + BEGIN + DECLARE @TempIndexPages FLOAT(30); + + -- TempIndexPages may be exceedingly small, so catch any arith overflows and call it 0 + BEGIN TRY; + SET @TempIndexPages = @NumLeafPages / POWER(@IndexRowsPerPage, @NonLeafLevels); + SET @NumIndexPages = @NumIndexPages + @TempIndexPages; + SET @NonLeafLevels = @NonLeafLevels - 1; + END TRY + BEGIN CATCH; + SET @NonLeafLevels = @NonLeafLevels - 1; + END CATCH; + END; + + -- Calculate size of the index + SET @IndexSpaceUsed = 8192 * @NumIndexPages; + + /**************************************/ + /* 4. Total index and leaf space used */ + /**************************************/ + DECLARE @Total INT = 0; + + SET @Total = @LeafSpaceUsed + @IndexSpaceUsed; + + SELECT @Total/1024 AS [Est. KB] + ,CAST(ROUND(@Total/1024.0/1024.0,2,1) AS DECIMAL(30,2)) AS [Est. MB] + ,CAST(ROUND(@Total/1024.0/1024.0/1024.0,2,1) AS DECIMAL(30,4)) AS [Est. GB]; + END; + + --Cleanup + EXEC sp_executesql @DropIndexSql; + +END TRY +BEGIN CATCH; + BEGIN; + DECLARE @ErrorNumber INT = ERROR_NUMBER(); + DECLARE @ErrorLine INT = ERROR_LINE(); + DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); + DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); + DECLARE @ErrorState INT = ERROR_STATE(); + + EXEC sp_executesql @DropIndexSql; + + SET @ErrorMessage = CONCAT(QUOTENAME(OBJECT_NAME(@@PROCID)), ': ', @ErrorMessage); + RAISERROR(@ErrorMessage, @ErrorSeverity, @ErrorState) WITH NOWAIT; + END; +END CATCH; + +END; +GO + +EXEC sys.sp_addextendedproperty @name=N'@DatabaseName', @value=N'Target database of the index''s table.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@FillFactor', @value=N'Optional fill factor for the index.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@Filter', @value=N'Optional filter for the index. Default is 100.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@IncludeColumns', @value=N'Optional comma separated list of include columns.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@IndexColumns', @value=N'Comma separated list of key columns.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@IsUnique', @value=N'Whether or not the index is UNIQUE. Default is 0.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@SchemaName', @value=N'Target schema of the index''s table. Default is ''dbo''.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@SqlMajorVersion', @value=N'For unit testing only.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@TableName', @value=N'Target table for the index. Default is current database.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'Description', @value=N'Estimate a new index''s size and statistics.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO + +EXEC sys.sp_addextendedproperty @name=N'@Verbose', @value=N'Show intermediate variables used in size calculations. Default is 0.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex'; +GO \ No newline at end of file diff --git a/sp_helpme.sql b/sp_helpme.sql index 6c77e05d..8493b30a 100644 --- a/sp_helpme.sql +++ b/sp_helpme.sql @@ -34,6 +34,9 @@ IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@ObjectName' , N'SCHEMA' END GO +/***************************/ +/* Create stored procedure */ +/***************************/ IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[sp_helpme]') AND [type] IN (N'P', N'PC')) BEGIN; EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[sp_helpme] AS'; diff --git a/tests/build/sp_doc_tests.sql b/tests/build/sp_doc_tests.sql index 0c869988..95d20c6f 100644 --- a/tests/build/sp_doc_tests.sql +++ b/tests/build/sp_doc_tests.sql @@ -1,3 +1,7 @@ +SET NOCOUNT ON; +SET ANSI_NULLS ON; +SET QUOTED_IDENTIFIER ON; + /************************************ Begin sp_doc tests *************************************/ @@ -16,8 +20,11 @@ CREATE PROCEDURE [sp_doc].[test sp succeeds on create] AS BEGIN; +DECLARE @ObjectName NVARCHAR(1000) = N'dbo.sp_doc'; +DECLARE @ErrorMessage NVARCHAR(MAX) = N'Stored procedure sp_doc does not exist.'; + --Assert -EXEC tSQLt.AssertObjectExists @objectName = 'dbo.sp_doc', @message = 'Stored procedure sp_doc does not exist.'; +EXEC tSQLt.AssertObjectExists @objectName = @objectName, @message = @ErrorMessage; END; GO @@ -80,23 +87,25 @@ CREATE PROCEDURE [sp_doc].[test sp fails on invalid db] AS BEGIN; -DECLARE @db SYSNAME = 'StarshipVoyager'; +DECLARE @DatabaseName SYSNAME = 'StarshipVoyager'; +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'Database not available.'; --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = N'Database not available.'; -EXEC [dbo].[sp_doc] @DatabaseName = @db; +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage; +EXEC [dbo].[sp_doc] @DatabaseName = @DatabaseName; END; GO /* -test sp_doc can assume current db if none given +test sp_doc succeeds on assume current db if none given */ CREATE PROCEDURE [sp_doc].[test sp succeeds on current db if none given] AS BEGIN; -DECLARE @command NVARCHAR(MAX) = '[dbo].[sp_doc];'; +DECLARE @Verbose BIT = 0; +DECLARE @command NVARCHAR(MAX) = CONCAT('[dbo].[sp_doc] @Verbose = ', @Verbose, ';'); --Assert EXEC [tSQLt].[ExpectNoException]; @@ -106,30 +115,32 @@ END; GO /* -test sp_doc errors on unsupported SQL Server < v12 +test sp_doc fails on unsupported SQL Server < v12 */ CREATE PROCEDURE [sp_doc].[test sp fails on unsupported version] AS BEGIN; DECLARE @version TINYINT = 10; +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'SQL Server versions below 2012 are not supported, sorry!'; --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = N'SQL Server versions below 2012 are not supported, sorry!'; +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage; EXEC [dbo].[sp_doc] @SqlMajorVersion = @version; END; GO /* -test sp_doc works on supported SQL Server >= v12 +test sp_doc succeeds on supported SQL Server >= v12 */ CREATE PROCEDURE [sp_doc].[test sp succeeds on supported version] AS BEGIN; DECLARE @version TINYINT = 13; -DECLARE @command NVARCHAR(MAX) = '[dbo].[sp_doc] @SqlMajorVersion = ' + CAST(@version AS NVARCHAR(4)) + ';'; +DECLARE @Verbose BIT = 0; +DECLARE @command NVARCHAR(MAX) = CONCAT('[dbo].[sp_doc] @SqlMajorVersion = ', @version, ', @Verbose = ', @Verbose, ';'); --Assert EXEC [tSQLt].[ExpectNoException]; @@ -147,7 +158,7 @@ BEGIN; EXEC tSQLt.AssertResultSetsHaveSameMetaData 'SELECT CAST(''test'' AS NVARCHAR(MAX)) as [value]', - 'EXEC sp_doc'; + 'EXEC [dbo].[sp_doc] @Verbose = 0'; END; GO @@ -162,19 +173,20 @@ BEGIN; --Rows returned from empty database DECLARE @TargetRows SMALLINT = 22; DECLARE @ReturnedRows BIGINT; +DECLARE @FailMessage NVARCHAR(MAX) = N'Minimum number of rows were not returned.'; +DECLARE @Verbose BIT = 0; -EXEC sp_doc; +EXEC [dbo].[sp_doc] @Verbose = @Verbose; SET @ReturnedRows = @@ROWCOUNT; IF (@TargetRows > @ReturnedRows) BEGIN; - EXEC tSQLt.Fail 'Minimum number of rows were not returned.', @ReturnedRows; + EXEC tSQLt.Fail @FailMessage, @ReturnedRows; END; END; GO - /************************************ End sp_doc tests *************************************/ \ No newline at end of file diff --git a/tests/build/sp_estindex_tests.sql b/tests/build/sp_estindex_tests.sql new file mode 100644 index 00000000..b1182e93 --- /dev/null +++ b/tests/build/sp_estindex_tests.sql @@ -0,0 +1,765 @@ +SET NOCOUNT ON; +SET ANSI_NULLS ON; +SET QUOTED_IDENTIFIER ON; + +/************************************/ +/* Begin sp_estindex tests */ +/************************************/ + +--Clean Class +EXEC tSQLt.DropClass 'sp_estindex'; +GO + +EXEC tSQLT.NewTestClass 'sp_estindex'; +GO + +/****************************** +Success Cases +******************************/ + +/* +test that sp_estindex exists +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds on create] +AS +BEGIN + +--Build +DECLARE @ObjectName SYSNAME = 'dbo.sp_estindex'; +DECLARE @Message NVARCHAR(MAX) = 'Stored procedure sp_estindex does not exist.'; + +--Assert +EXEC tSQLt.AssertObjectExists @objectName = @ObjectName + ,@message = @Message; + +END; +GO + +/* +test success on supported SQL Server >= v12 +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds on supported version] +AS +BEGIN; + +--Build +DECLARE @version TINYINT = 13; +DECLARE @Verbose BIT = 0; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @SqlMajorVersion = ', @version, ', @TableName = ''CaptureOutputLog'', @IndexColumns = ''Id'', @SchemaName = ''tSQLt'', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success on unique index +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds on unique index] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IsUnique BIT = 1; +DECLARE @TableName SYSNAME = 'CaptureOutputLog'; +DECLARE @IndexColumns NVARCHAR(MAX) = N'Id'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @IsUnique = ',@IsUnique, ', @TableName =''', @TableName, ''', @IndexColumns =''', @IndexColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + + +/* +test success on filtered index +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds on filtered index] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @Filter VARCHAR(50) = 'WHERE ID IS NOT NULL'; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @Filter = ''',@Filter , + ''', @TableName = ''CaptureOutputLog'', @IndexColumns = ''Id'', @SchemaName = ''tSQLt'', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success on non-default fill factor +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds on non-default fill factor] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @FillFactor TINYINT = 50; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @FillFactor = ',@FillFactor , + ', @TableName = ''CaptureOutputLog'', @IndexColumns = ''Id'', @SchemaName = ''tSQLt'', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success with included columns +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with included columns] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IncludeColumns VARCHAR(50) = 'OutputText'; +DECLARE @IndexColumns VARCHAR(50) = 'Id'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'CaptureOutputLog'; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @IncludeColumns = ''',@IncludeColumns , + ''', @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success with unique index on heap +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with unique index on heap] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IndexColumns VARCHAR(50) = 'ID'; +DECLARE @TableName SYSNAME = '##Heap'; +DECLARE @IsUnique BIT = 1; +DECLARE @DatabaseName SYSNAME = 'tempdb'; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @DatabaseName =''', @DatabaseName, ''', @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @IsUnique =', @IsUnique, ', @Verbose =', @Verbose, ';'); +DECLARE @ResultSetNumber TINYINT = 5; --5 = estimated index size +DECLARE @FailMessage NVARCHAR(MAX) = N'Index size estimation failed - not > 0.'; + +--Populate table to build index for +IF OBJECT_ID('tempdb..##Heap') IS NOT NULL +BEGIN + DROP TABLE ##Heap; +END + +CREATE TABLE ##Heap( +ID INT); + +WITH Nums(Number) AS +(SELECT 1 AS [Number] + UNION ALL + SELECT Number+1 FROM [Nums] WHERE [Number] < 1000 +) +INSERT INTO ##Heap(ID) +SELECT [Number] FROM [Nums] OPTION(MAXRECURSION 1000); + +--Create empty table for result set +CREATE TABLE #Result ( + [Est. KB] DECIMAL(10,3) + ,[Est. MB] DECIMAL(10,3) + ,[Est. GB] DECIMAL(10,3) +); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +INSERT INTO #Result +EXEC [tSQLt].[ResultSetFilter] @ResultSetNumber + ,@command = @command; + +DECLARE @EstKB DECIMAL(10,3) = (SELECT [Est. KB] FROM #Result); + +IF (@EstKB IS NULL) OR (@EstKB <= 0.0) + BEGIN; + EXEC [tSQLt].[Fail] @FailMessage, @EstKb; + END; + +--Teardown +DROP TABLE ##Heap; +DROP TABLE #Result; + +END; +GO + +/* +test success with non-unique index on heap +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with non-unique index on heap] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IndexColumns VARCHAR(50) = 'ID'; +DECLARE @TableName SYSNAME = '##Heap'; +DECLARE @IsUnique BIT = 0; +DECLARE @DatabaseName SYSNAME = 'tempdb'; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @DatabaseName =''', @DatabaseName, ''', @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @IsUnique =', @IsUnique, ', @Verbose =', @Verbose, ';'); +DECLARE @ResultSetNumber TINYINT = 5; --5 = estimated index size +DECLARE @FailMessage NVARCHAR(MAX) = N'Index size estimation failed - not > 0.'; + +--Populate table to build index for +IF OBJECT_ID('tempdb..##Heap') IS NOT NULL +BEGIN + DROP TABLE ##Heap; +END + +CREATE TABLE ##Heap( +ID INT); + +WITH Nums(Number) AS +(SELECT 1 AS [Number] + UNION ALL + SELECT Number+1 FROM [Nums] WHERE [Number] < 1000 +) +INSERT INTO ##Heap(ID) +SELECT [Number] FROM [Nums] OPTION(MAXRECURSION 1000); + +--Create empty table for result set +CREATE TABLE #Result ( + [Est. KB] DECIMAL(10,3) + ,[Est. MB] DECIMAL(10,3) + ,[Est. GB] DECIMAL(10,3) +); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +INSERT INTO #Result +EXEC [tSQLt].[ResultSetFilter] @ResultSetNumber, @command = @command; + +DECLARE @EstKB DECIMAL(10,3) = (SELECT [Est. KB] FROM #Result); + +IF (@EstKB IS NULL) OR (@EstKB <= 0.0) + BEGIN; + EXEC [tSQLt].[Fail] @FailMessage, @EstKb; + END; + +--Teardown +DROP TABLE ##Heap; +DROP TABLE #Result; + +END; +GO + +/* +test success with unique index on clustered +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with unique index on clustered] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IndexColumns VARCHAR(50) = 'ID'; +DECLARE @TableName SYSNAME = '##Clustered'; +DECLARE @DatabaseName SYSNAME = 'tempdb'; +DECLARE @IsUnique BIT = 1; +DECLARE @TeardownSql NVARCHAR(MAX) = N''; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @DatabaseName =''', @DatabaseName, ''', @TableName = ''', @TableName, ''', @IsUnique =', @IsUnique, ', @IndexColumns = ''',@IndexColumns, ''', @Verbose =', @Verbose, ';'); +DECLARE @ResultSetNumber TINYINT = 5; --5 = estimated index size +DECLARE @FailMessage NVARCHAR(MAX) = N'Index size estimation failed - not > 0.'; + +-- Populate table to build index for +CREATE TABLE ##Clustered( +ID INT); + +;WITH Nums(Number) AS +(SELECT 1 AS [Number] + UNION ALL + SELECT Number+1 FROM [Nums] WHERE [Number]<1000 +) +INSERT INTO ##Clustered(ID) +SELECT [Number] FROM [Nums] OPTION(maxrecursion 1000); + +--Create empty table for result set +CREATE TABLE #Result ( + [Est. KB] DECIMAL(10,3) + ,[Est. MB] DECIMAL(10,3) + ,[Est. GB] DECIMAL(10,3) +); + + +--Assert +EXEC [tSQLt].[ExpectNoException]; +INSERT INTO #Result +EXEC [tSQLt].[ResultSetFilter] @ResultSetNumber + ,@command = @command; + +DECLARE @EstKB DECIMAL(10,3) = (SELECT [Est. KB] FROM #Result); + +IF (@EstKB IS NULL) OR (@EstKB <= 0.0) + BEGIN; + EXEC [tSQLt].[Fail] @FailMessage, @EstKb; + END; + +--Teardown +DROP TABLE ##Clustered; +DROP TABLE #Result; + +END; +GO + +/* +test success with multi-leaf index +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with multi-leaf index] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IndexColumns VARCHAR(50) = 'ID'; +DECLARE @TableName SYSNAME = '##Clustered'; +DECLARE @DatabaseName SYSNAME = 'tempdb'; +DECLARE @IsUnique BIT = 1; +DECLARE @TeardownSql NVARCHAR(MAX) = N''; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @DatabaseName =''', @DatabaseName, ''', @TableName = ''', @TableName, ''', @IsUnique =', @IsUnique, ', @IndexColumns = ''',@IndexColumns, ''', @Verbose =', @Verbose, ';'); +DECLARE @ResultSetNumber TINYINT = 5; --5 = estimated index size +DECLARE @FailMessage NVARCHAR(MAX) = N'Index size estimation failed - not > 0.'; + +--Populate table to build index for +CREATE TABLE ##Clustered( +ID INT); + +;WITH Nums(Number) AS +(SELECT 1 AS [Number] + UNION ALL + SELECT Number+1 FROM [Nums] WHERE [Number]<10000 +) +INSERT INTO ##Clustered(ID) +SELECT [Number] FROM [Nums] OPTION(maxrecursion 10000); + +--Create empty table for result set +CREATE TABLE #Result ( + [Est. KB] DECIMAL(10,3) + ,[Est. MB] DECIMAL(10,3) + ,[Est. GB] DECIMAL(10,3) +); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +INSERT INTO #Result +EXEC [tSQLt].[ResultSetFilter] @ResultSetNumber + ,@command = @command; + +DECLARE @EstKB DECIMAL(10,3) = (SELECT [Est. KB] FROM #Result); + +IF (@EstKB IS NULL) OR (@EstKB <= 0.0) + BEGIN; + EXEC [tSQLt].[Fail] @FailMessage, @EstKb; + END; + +--Teardown +DROP TABLE ##Clustered; +DROP TABLE #Result; + +END; +GO + +/* +test success with non-unique index on clustered +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with non-unique index on clustered] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IndexColumns VARCHAR(50) = 'ID'; +DECLARE @TableName SYSNAME = '##Clustered'; +DECLARE @DatabaseName SYSNAME = 'tempdb'; +DECLARE @IsUnique BIT = 0; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @DatabaseName =''', @DatabaseName, ''', @TableName = ''', @TableName, ''', @IsUnique =', @IsUnique, ', @IndexColumns = ''',@IndexColumns, ''', @Verbose =', @Verbose, ';'); +DECLARE @ResultSetNumber TINYINT = 5; --5 = estimated index size +DECLARE @FailMessage NVARCHAR(MAX) = N'Index size estimation failed - not > 0.'; + +CREATE TABLE ##Clustered( +ID INT); + +;WITH Nums(Number) AS +(SELECT 1 AS [Number] + UNION ALL + SELECT Number+1 FROM [Nums] WHERE [Number]<1000 +) +INSERT INTO ##Clustered(ID) +SELECT [Number] FROM [Nums] OPTION(maxrecursion 1000); + +CREATE CLUSTERED INDEX cdx_temporary ON ##Clustered(ID); + +--Create empty table for result set +CREATE TABLE #Result ( + [Est. KB] DECIMAL(10,3) + ,[Est. MB] DECIMAL(10,3) + ,[Est. GB] DECIMAL(10,3) +); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +INSERT INTO #Result +EXEC [tSQLt].[ResultSetFilter] @ResultSetNumber + ,@command = @command; + +DECLARE @EstKB DECIMAL(10,3) = (SELECT [Est. KB] FROM #Result); + +IF (@EstKB IS NULL) OR (@EstKB <= 0.0) + BEGIN; + EXEC [tSQLt].[Fail] @FailMessage, @EstKb; + END; + +--Teardown +DROP TABLE ##Clustered; +DROP TABLE #Result; + +END; +GO + +/* +test success with existing ##TempMissingIndex +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with existing ##TempMissingIndex] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IncludeColumns VARCHAR(50) = 'OutputText'; +DECLARE @IndexColumns VARCHAR(50) = 'Id'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'CaptureOutputLog'; + +SELECT 1 AS [one] +INTO ##TempMissingIndex; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success with nullable columns +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with nullable columns] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'name'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'Private_AssertEqualsTableSchema_Actual'; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success with variable len columns +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with variable len columns] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'name'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'Private_AssertEqualsTableSchema_Actual'; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success with verbose mode +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with verbose mode] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 1; +DECLARE @IndexColumns VARCHAR(50) = 'name'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'Private_AssertEqualsTableSchema_Actual'; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @TableName = ''', @TableName, ''', @IndexColumns = ''',@IndexColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/* +test success with variable len include columns +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds with variable len include columns] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'restore_history_id'; +DECLARE @IncludeColumns VARCHAR(50) = 'destination_database_name'; +DECLARE @SchemaName SYSNAME = 'dbo'; +DECLARE @DatabaseName SYSNAME = 'msdb'; +DECLARE @TableName SYSNAME = 'restorehistory'; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @TableName = ''', @TableName, ''', @DatabaseName = ''',@DatabaseName, ''', @IndexColumns = ''',@IndexColumns, ''', @IncludeColumns = ''',@IncludeColumns, ''', @SchemaName = ''', @SchemaName, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + + +/* +test success without @SchemaName +*/ +CREATE PROCEDURE [sp_estindex].[test sp succeeds without @SchemaName] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'first_family_number'; +DECLARE @DatabaseName SYSNAME = 'msdb'; +DECLARE @TableName SYSNAME = 'backupfile'; + +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_estindex] @TableName = ''', @TableName, ''', @DatabaseName = ''', @DatabaseName, ''', @IndexColumns = ''',@IndexColumns, ''', @Verbose =', @Verbose, ';'); + +--Assert +EXEC [tSQLt].[ExpectNoException]; +EXEC [tSQLt].[SuppressOutput] @command = @command; + +END; +GO + +/************************************ +Failure cases +*************************************/ + +/* +test failure on unsupported SQL Server < v12 +*/ +CREATE PROCEDURE [sp_estindex].[test sp fails on unsupported version] +AS +BEGIN; + +--Build +DECLARE @version TINYINT = 10; +DECLARE @Verbose BIT = 0; +DECLARE @TableName VARCHAR(50) = 'DoesntMatter'; +DECLARE @IndexColumns VARCHAR(50) = 'AlsoDoesntMatter'; + +DECLARE @ExpectedMessage NVARCHAR(MAX) = '[sp_estindex]: SQL Server versions below 2012 are not supported, sorry!'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; + +--Assert +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_estindex] @SqlMajorVersion = @version + ,@TableName = @TableName + ,@IndexColumns = @IndexColumns + ,@Verbose = @Verbose; + +END; +GO + +/* +test failure with no @IndexColumns +*/ +CREATE PROCEDURE [sp_estindex].[test sp fails with no @IndexColumns] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @TableName VARCHAR(50) = 'DoesntMatter'; +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'Procedure or function ''sp_estindex'' expects parameter ''@IndexColumns'', which was not supplied.'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 4; +DECLARE @ExpectedErrorNumber INT = 201; + +--Assert +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_estindex] @TableName = @TableName + ,@Verbose = @Verbose; + +END; +GO + +/* +test failure with no @TableName +*/ +CREATE PROCEDURE [sp_estindex].[test sp fails with no @TableName] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IncludedColumns VARCHAR(50) = 'DoesntMatter'; + +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'Procedure or function ''sp_estindex'' expects parameter ''@TableName'', which was not supplied.'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 4; +DECLARE @ExpectedErrorNumber INT = 201; + +--Assert +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_estindex] @IncludedColumns = @IncludedColumns + ,@Verbose = @Verbose; + +END; +GO + +/* +test failure with invalid @IndexColumns +*/ +CREATE PROCEDURE [sp_estindex].[test sp fails with invalid @IndexColumns] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'BadColumnName'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'CaptureOutputLog'; + +DECLARE @ExpectedMessage NVARCHAR(MAX) = CONCAT('[sp_estindex]: Column name ''', @IndexColumns, ''' does not exist in the target table or view.'); +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; + +--Assert +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_estindex] @IndexColumns = @IndexColumns + ,@TableName = @TableName + ,@SchemaName = @SchemaName + ,@Verbose = @Verbose; + +END; +GO + + +/* +test failure with invalid @Database +*/ +CREATE PROCEDURE [sp_estindex].[test sp fails with invalid @Database] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'BadColumnName'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'CaptureOutputLog'; +DECLARE @DatabaseName SYSNAME = 'IDontExist'; + +DECLARE @ExpectedMessage NVARCHAR(MAX) = '[sp_estindex]: Database does not exist.'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; + +--Assert +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_estindex] @IndexColumns = @IndexColumns + ,@TableName = @TableName + ,@SchemaName = @SchemaName + ,@Verbose = @Verbose + ,@DatabaseName = @DatabaseName; + +END; +GO + +/* +test failure with invalid @FillFactor +*/ +CREATE PROCEDURE [sp_estindex].[test sp fails with invalid @FillFactor] +AS +BEGIN; + +--Build +DECLARE @Verbose BIT = 0; +DECLARE @IndexColumns VARCHAR(50) = 'BadColumnName'; +DECLARE @SchemaName SYSNAME = 'tSQLt'; +DECLARE @TableName SYSNAME = 'CaptureOutputLog'; +DECLARE @DatabaseName SYSNAME = 'IDontExist'; +DECLARE @FillFactor TINYINT = 101; + +DECLARE @ExpectedMessage NVARCHAR(MAX) = '[sp_estindex]: Fill factor must be between 1 and 100.'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; + +--Assert +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_estindex] @IndexColumns = @IndexColumns + ,@TableName = @TableName + ,@SchemaName = @SchemaName + ,@Verbose = @Verbose + ,@FillFactor = @FillFactor; + +END; +GO + +/************************************ +End sp_estindex tests +*************************************/ diff --git a/tests/build/sp_helpme_tests.sql b/tests/build/sp_helpme_tests.sql index 24fca79f..ba31cdfa 100644 --- a/tests/build/sp_helpme_tests.sql +++ b/tests/build/sp_helpme_tests.sql @@ -1,3 +1,7 @@ +SET NOCOUNT ON; +SET ANSI_NULLS ON; +SET QUOTED_IDENTIFIER ON; + /************************************ Begin sp_helpme tests *************************************/ @@ -33,9 +37,15 @@ BEGIN DECLARE @Table SYSNAME = 'dbo.IDontExist'; DECLARE @Database SYSNAME = DB_NAME(DB_ID()); DECLARE @ExpectedMessage NVARCHAR(MAX) = FORMATMESSAGE(N'The object ''%s'' does not exist in database ''%s'' or is invalid for this operation.', @Table, @Database); +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 15009; --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage, @ExpectedSeverity = 16, @ExpectedState = 1, @ExpectedErrorNumber = 15009 +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + , @ExpectedSeverity = @ExpectedSeverity + , @ExpectedState = @ExpectedState + , @ExpectedErrorNumber = @ExpectedErrorNumber; EXEC [sp_helpme] @Table; END; @@ -82,7 +92,7 @@ CREATE TABLE #Expected ( ,[create_datetime] DATETIME NOT NULL ,[modify_datetime] DATETIME NOT NULL ,[ExtendedProperty] SQL_VARIANT NULL -) +); INSERT INTO #Expected SELECT @@ -107,7 +117,7 @@ CREATE TABLE #Actual ( ,[create_datetime] DATETIME NOT NULL ,[modify_datetime] DATETIME NOT NULL ,[ExtendedProperty] SQL_VARIANT NULL -) +); INSERT INTO #Actual EXEC tSQLt.ResultSetFilter 1, @cmd; @@ -125,9 +135,10 @@ AS BEGIN; DECLARE @version TINYINT = 10; +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'SQL Server versions below 2012 are not supported, sorry!'; --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = N'SQL Server versions below 2012 are not supported, sorry!'; +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage; EXEC [dbo].[sp_helpme] @SqlMajorVersion = @version; END; @@ -158,13 +169,17 @@ BEGIN; --Build DECLARE @Table SYSNAME = 'msdb.dbo.backupset'; +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'The database name component of the object qualifier must be the name of the current database.'; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 15250; +DECLARE @ExpectedSeverity TINYINT = 16; --Assert EXEC [tSQLt].[ExpectException] - @ExpectedMessage = N'The database name component of the object qualifier must be the name of the current database.', - @ExpectedSeverity = 16, - @ExpectedState = 1, - @ExpectedErrorNumber = 15250; + @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; EXEC [sp_helpme] @Table; @@ -194,7 +209,7 @@ CREATE TABLE #Expected ( ,[create_datetime] DATETIME NOT NULL ,[modify_datetime] DATETIME NOT NULL ,[ExtendedProperty] SQL_VARIANT NULL -) +); INSERT INTO #Expected SELECT @@ -218,7 +233,7 @@ CREATE TABLE #Actual ( ,[create_datetime] DATETIME NOT NULL ,[modify_datetime] DATETIME NOT NULL ,[ExtendedProperty] SQL_VARIANT NULL -) +); INSERT INTO #Actual EXEC tSQLt.ResultSetFilter 1, @cmd; @@ -275,14 +290,17 @@ BEGIN --Build DECLARE @Table SYSNAME = 'tSQLt.CaptureOutputLog'; DECLARE @cmd NVARCHAR(MAX) = N'EXEC [sp_helpme] ''' + @Table + ''';'; +DECLARE @ViewName NVARCHAR(1000) = 'dbo.SchemaBoundView'; DECLARE @sql NVARCHAR(MAX) = N' CREATE VIEW dbo.SchemaBoundView WITH SCHEMABINDING AS SELECT [id] FROM tSQLt.CaptureOutputLog;'; -IF EXISTS (SELECT * FROM sys.views WHERE object_id = OBJECT_ID(N'dbo.SchemaBoundView')) - DROP VIEW dbo.SchemaBoundView; +IF EXISTS (SELECT 1 FROM [sys].[views] WHERE [object_id] = OBJECT_ID(@ViewName)) + BEGIN; + DROP VIEW dbo.SchemaBoundView; + END; EXEC sp_executesql @sql; diff --git a/tests/build/sp_sizeoptimiser_tests.sql b/tests/build/sp_sizeoptimiser_tests.sql index f6dedd91..7c294e60 100644 --- a/tests/build/sp_sizeoptimiser_tests.sql +++ b/tests/build/sp_sizeoptimiser_tests.sql @@ -1,3 +1,7 @@ +SET NOCOUNT ON; +SET ANSI_NULLS ON; +SET QUOTED_IDENTIFIER ON; + /************************************ Begin sp_sizeoptimiser tests *************************************/ @@ -16,8 +20,13 @@ CREATE PROCEDURE [sp_sizeoptimiser].[test sp succeeds on create] AS BEGIN +DECLARE @ObjectName NVARCHAR(1000) = N'dbo.sp_sizeoptimiser'; +DECLARE @ErrorMessage NVARCHAR(MAX) = N'Stored procedure sp_sizeoptimiser does not exist.'; + --Assert -EXEC tSQLt.AssertObjectExists @objectName = 'dbo.sp_sizeoptimiser', @message = 'Stored procedure sp_sizeoptimiser does not exist.'; +EXEC tSQLt.AssertObjectExists + @objectName = @objectName + ,@message = @ErrorMessage; END; GO @@ -31,14 +40,18 @@ BEGIN DECLARE @actual BIT = 0; DECLARE @expected BIT = 1; +DECLARE @ErrorMessage NVARCHAR(MAX) = N'User defined table type SizeOptimiserTableType does not exist'; +DECLARE @ObjectName SYSNAME = N'SizeOptimiserTableType'; --Check for table type SELECT @actual = 1 -FROM sys.table_types -WHERE [name] = 'SizeOptimiserTableType' +FROM [sys].[table_types] +WHERE [name] = @ObjectName; --Assert -EXEC tSQLt.AssertEquals @expected, @actual, @message = 'User defined table type SizeOptimiserTableType does not exist'; +EXEC tSQLt.AssertEquals @expected + ,@actual + ,@message = @ErrorMessage; END; GO @@ -50,9 +63,22 @@ CREATE PROCEDURE [sp_sizeoptimiser].[test sp fails on incorrect @IndexNumThresho AS BEGIN +DECLARE @ExpectedMessage NVARCHAR(MAX) = N'@IndexNumThreshold must be between 1 and 999.'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; +DECLARE @IndexNumThreshold TINYINT = 0; +DECLARE @Verbose BIT = 0; + --Assert -EXEC tSQLt.ExpectException @ExpectedMessage = N'@IndexNumThreshold must be between 1 and 999.', @ExpectedSeverity = 16, @ExpectedState = 1, @ExpectedErrorNumber = 50000 -EXEC dbo.sp_sizeoptimiser @IndexNumThreshold = 0, @Verbose = 0; +EXEC tSQLt.ExpectException + @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC dbo.sp_sizeoptimiser + @IndexNumThreshold = @IndexNumThreshold + ,@Verbose = @Verbose; END; GO @@ -91,6 +117,11 @@ BEGIN --Build DECLARE @IncludeDatabases [dbo].[SizeOptimiserTableType]; DECLARE @ExcludeDatabases [dbo].[SizeOptimiserTableType]; +DECLARE @ExpectedMessage NVARCHAR(MAX) = 'Both @IncludeDatabases and @ExcludeDatabases cannot be specified.'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; +DECLARE @Verbose BIT = 0; INSERT INTO @IncludeDatabases VALUES ('master'); @@ -99,8 +130,15 @@ INSERT INTO @ExcludeDatabases VALUES ('model'); --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = N'Both @IncludeDatabases and @ExcludeDatabases cannot be specified.', @ExpectedSeverity = 16, @ExpectedState = 1, @ExpectedErrorNumber = 50000 -EXEC [dbo].[sp_sizeoptimiser] NULL, @IncludeDatabases = @IncludeDatabases, @ExcludeDatabases = @ExcludeDatabases, @Verbose = 0; +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_sizeoptimiser] + NULL + ,@IncludeDatabases = @IncludeDatabases + ,@ExcludeDatabases = @ExcludeDatabases + ,@Verbose = @Verbose; END; GO @@ -115,10 +153,20 @@ BEGIN; --Build DECLARE @version TINYINT = 10; +DECLARE @Verbose BIT = 0; +DECLARE @ExpectedMessage NVARCHAR(MAX) = 'SQL Server versions below 2012 are not supported, sorry!'; +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = N'SQL Server versions below 2012 are not supported, sorry!', @ExpectedSeverity = 16, @ExpectedState = 1, @ExpectedErrorNumber = 50000 -EXEC [dbo].[sp_sizeoptimiser] @SqlMajorVersion = @version, @Verbose = 0; +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; +EXEC [dbo].[sp_sizeoptimiser] + @SqlMajorVersion = @version + ,@Verbose = @Verbose; END; GO @@ -133,10 +181,11 @@ BEGIN; --Build DECLARE @version TINYINT = 13; DECLARE @IncludeDatabases [dbo].[SizeOptimiserTableType]; -DECLARE @command NVARCHAR(MAX) = N'EXEC [dbo].[sp_sizeoptimiser] @SqlMajorVersion = ' + CAST(@version AS NVARCHAR(2)) + ', @Verbose = 0;' +DECLARE @Verbose BIT = 0; +DECLARE @command NVARCHAR(MAX) = CONCAT(N'EXEC [dbo].[sp_sizeoptimiser] @SqlMajorVersion = ',@version, ', @Verbose =', @Verbose, ';'); --Assert -EXEC [tSQLt].[ExpectNoException] +EXEC [tSQLt].[ExpectNoException]; EXEC [tSQLt].[SuppressOutput] @command = @command; END; @@ -154,13 +203,14 @@ BEGIN; DECLARE @version TINYINT = 13; DECLARE @IncludeDatabases [dbo].[SizeOptimiserTableType]; DECLARE @DbName SYSNAME = DB_NAME(DB_ID()); +DECLARE @Verbose BIT = 1; +DECLARE @command NVARCHAR(MAX) = CONCAT('EXEC [dbo].[sp_sizeoptimiser] @Verbose =', @Verbose, ';'); INSERT INTO @IncludeDatabases VALUES (@DbName); --Assert -EXEC [tSQLt].[ExpectNoException] -DECLARE @command NVARCHAR(MAX) = 'EXEC [dbo].[sp_sizeoptimiser] @Verbose = 1;'; +EXEC [tSQLt].[ExpectNoException]; EXEC [tSQLt].[SuppressOutput] @command = @command; END; @@ -176,13 +226,16 @@ BEGIN; --Build DECLARE @version TINYINT = 13; DECLARE @ExcludeDatabases [dbo].[SizeOptimiserTableType]; +DECLARE @Verbose BIT = 0; INSERT INTO @ExcludeDatabases VALUES ('master'); --Assert -EXEC [tSQLt].[ExpectNoException] -EXEC [dbo].[sp_sizeoptimiser] @ExcludeDatabases = @ExcludeDatabases, @Verbose = 0; +EXEC [tSQLt].[ExpectNoException]; +EXEC [dbo].[sp_sizeoptimiser] + @ExcludeDatabases = @ExcludeDatabases + ,@Verbose = @Verbose; END; GO @@ -198,19 +251,25 @@ BEGIN; DECLARE @IncludeDatabases [dbo].[SizeOptimiserTableType]; DECLARE @DbName SYSNAME = 'BlackLivesMatter'; DECLARE @ExpectedMessage NVARCHAR(MAX) = FORMATMESSAGE('Supplied databases do not exist or are not accessible: %s.', @DbName); +DECLARE @ExpectedSeverity TINYINT = 16; +DECLARE @ExpectedState TINYINT = 1; +DECLARE @ExpectedErrorNumber INT = 50000; INSERT INTO @IncludeDatabases VALUES (@DbName); --Assert -EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage, @ExpectedSeverity = 16, @ExpectedState = 1, @ExpectedErrorNumber = 50000 +EXEC [tSQLt].[ExpectException] @ExpectedMessage = @ExpectedMessage + ,@ExpectedSeverity = @ExpectedSeverity + ,@ExpectedState = @ExpectedState + ,@ExpectedErrorNumber = @ExpectedErrorNumber; EXEC [dbo].[sp_sizeoptimiser] @IncludeDatabases = @IncludeDatabases; END; GO /* -test success on SQLExpress +test success in Express Mode */ CREATE PROCEDURE [sp_sizeoptimiser].[test sp succeeds in Express Mode] AS @@ -218,16 +277,27 @@ BEGIN; --Check if testing on Azure SQL DECLARE @EngineEdition TINYINT = CAST(ServerProperty('EngineEdition') AS TINYINT); +DECLARE @Verbose BIT = 0; +DECLARE @AzureSQLEngine TINYINT = 5; -IF (@EngineEdition <> 5) -- Not Azure SQL +IF (@EngineEdition <> @AzureSQLEngine) -- Not Azure SQL BEGIN --Build DECLARE @IsExpress BIT = 1; --Assert - EXEC [tSQLt].[ExpectNoException] - EXEC [dbo].[sp_sizeoptimiser] @IsExpress = @IsExpress, @Verbose = 0; + EXEC [tSQLt].[ExpectNoException]; + EXEC [dbo].[sp_sizeoptimiser] + @IsExpress = @IsExpress + ,@Verbose = @Verbose; END; + +ELSE + BEGIN; + EXEC [tSQLt].[ExpectNoException]; + EXEC [dbo].[sp_sizeoptimiser] + @Verbose = @Verbose; + END; END; GO diff --git a/tests/run/localdev_test.ps1 b/tests/run/localdev_test.ps1 index b194e39f..fa5dc502 100644 --- a/tests/run/localdev_test.ps1 +++ b/tests/run/localdev_test.ps1 @@ -6,7 +6,6 @@ param( $LocalTest = $true $TrustedConnection = "yes" -$TestRunPath = "tests\run" $TestBuildPath = "tests\build" $Color = "Green" $LintConfig = ".\appveyor\tsqllint\.tsqllintrc_150" @@ -15,8 +14,8 @@ $LintConfig = ".\appveyor\tsqllint\.tsqllintrc_150" .\appveyor\install_dependencies.ps1 -Color $Color # Install latest versions -.\appveyor\make_combined_script.ps1 -.\appveyor\install_expsql.ps1 -SqlInstance $SqlInstance -Database $Database -Color $Color +.\appveyor\generate_combined_script.ps1 +.\appveyor\install_tool.ps1 -SqlInstance $SqlInstance -Database $Database -Color $Color # Lint code .\appveyor\run_tsqllint.ps1 -Config $LintConfig -Color $Color