|
@@ -197,6 +197,7 @@ CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_Working
|
|
|
, is_hypothetical bit
|
|
|
, has_filter bit
|
|
|
, allow_page_locks bit
|
|
|
+ , compression_type NVARCHAR(60) NULL -- 0 = NONE; 1 = ROW; 2 = PAGE; 3 = COLUMNSTORE; 4 = COLUMNSTORE_ARCHIVE
|
|
|
, range_scan_count bigint NULL
|
|
|
, record_count bigint
|
|
|
, [type] tinyint -- 0 = Heap; 1 = Clustered; 2 = Nonclustered; 3 = XML; 4 = Spatial; 5 = Clustered columnstore; 6 = Nonclustered columnstore; 7 = Nonclustered hash
|
|
@@ -312,24 +313,25 @@ FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log_old;')
|
|
|
END
|
|
|
|
|
|
IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions_old')
|
|
|
- INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Exceptions ([dbID],[objectID],[indexID],[dbName]
|
|
|
- ,[objectName],[indexName],[exclusionMask])
|
|
|
- SELECT [dbID],[objectID],[indexID],[dbName]
|
|
|
- ,[objectName],[indexName],[exclusionMask]
|
|
|
+ INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Exceptions ([dbID],[objectID],[indexID],[dbName],[objectName],[indexName],[exclusionMask])
|
|
|
+ SELECT [dbID],[objectID],[indexID],[dbName],[objectName],[indexName],[exclusionMask]
|
|
|
FROM dbo.tbl_AdaptiveIndexDefrag_Exceptions_old;
|
|
|
|
|
|
IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working_old')
|
|
|
- INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Working ([dbID],[objectID],[indexID],[partitionNumber]
|
|
|
- ,[dbName],[schemaName],[objectName],[indexName],[fragmentation]
|
|
|
- ,[page_count],[fill_factor],[is_disabled],[is_padded],[is_hypothetical]
|
|
|
- ,[has_filter],[allow_page_locks],[range_scan_count],[record_count]
|
|
|
- ,[type],[scanDate],[defragDate],[printStatus],[exclusionMask])
|
|
|
- SELECT [dbID],[objectID],[indexID],[partitionNumber],[dbName]
|
|
|
- ,[schemaName],[objectName],[indexName],[fragmentation],[page_count]
|
|
|
- ,[fill_factor],[is_disabled],[is_padded],[is_hypothetical],[has_filter]
|
|
|
- ,[allow_page_locks],[range_scan_count],[record_count],[type],[scanDate]
|
|
|
- ,[defragDate],[printStatus],[exclusionMask]
|
|
|
- FROM dbo.tbl_AdaptiveIndexDefrag_Working_old;
|
|
|
+ BEGIN
|
|
|
+ IF EXISTS (SELECT sc.column_id FROM sys.tables st INNER JOIN sys.columns sc ON st.[object_id] = sc.[object_id] WHERE (sc.[name] = 'compression_type') AND st.[name] = 'tbl_AdaptiveIndexDefrag_Working_old')
|
|
|
+ BEGIN
|
|
|
+ EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Working ([dbID],[objectID],[indexID],[partitionNumber],[dbName],[schemaName],[objectName],[indexName],[fragmentation],[page_count],[fill_factor],[is_disabled],[is_padded],[is_hypothetical],[has_filter],[allow_page_locks],[compression_type],[range_scan_count],[record_count],[type],[scanDate],[defragDate],[printStatus],[exclusionMask])
|
|
|
+SELECT [dbID],[objectID],[indexID],[partitionNumber],[dbName],[schemaName],[objectName],[indexName],[fragmentation],[page_count],[fill_factor],[is_disabled],[is_padded],[is_hypothetical],[has_filter],[allow_page_locks],[compression_type],[range_scan_count],[record_count],[type],[scanDate],[defragDate],[printStatus],[exclusionMask]
|
|
|
+FROM dbo.tbl_AdaptiveIndexDefrag_Working_old;')
|
|
|
+ END
|
|
|
+ ELSE
|
|
|
+ BEGIN
|
|
|
+ EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Working ([dbID],[objectID],[indexID],[partitionNumber],[dbName],[schemaName],[objectName],[indexName],[fragmentation],[page_count],[fill_factor],[is_disabled],[is_padded],[is_hypothetical],[has_filter],[allow_page_locks],[range_scan_count],[record_count],[type],[scanDate],[defragDate],[printStatus],[exclusionMask])
|
|
|
+SELECT [dbID],[objectID],[indexID],[partitionNumber],[dbName],[schemaName],[objectName],[indexName],[fragmentation],[page_count],[fill_factor],[is_disabled],[is_padded],[is_hypothetical],[has_filter],[allow_page_locks],[range_scan_count],[record_count],[type],[scanDate],[defragDate],[printStatus],[exclusionMask]
|
|
|
+FROM dbo.tbl_AdaptiveIndexDefrag_Working_old;')
|
|
|
+ END
|
|
|
+ END
|
|
|
|
|
|
IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working_old')
|
|
|
BEGIN
|
|
@@ -474,7 +476,7 @@ CREATE PROCEDURE dbo.usp_AdaptiveIndexDefrag
|
|
|
, @sortInTempDB bit = 0
|
|
|
/* 1 = perform sort operation in TempDB; 0 = perform sort operation in the indexes database */
|
|
|
, @maxDopRestriction tinyint = NULL
|
|
|
- /* Option to restrict the number of processors for the operation; only in Enterprise Edition */
|
|
|
+ /* Option to restrict the number of processors for both index and statistics operations; only in Enterprise Edition */
|
|
|
, @updateStats bit = 1
|
|
|
/* 1 = updates stats when reorganizing; 0 = does not update stats when reorganizing */
|
|
|
, @updateStatsWhere bit = 0
|
|
@@ -515,13 +517,18 @@ CREATE PROCEDURE dbo.usp_AdaptiveIndexDefrag
|
|
|
, @getBlobfrag bit = 0
|
|
|
/* 0 = (default) exclude blobs from fragmentation scan.
|
|
|
1 = include blobs and off-row data when scanning for fragmentation.*/
|
|
|
+ , @dataCompression NVARCHAR(4) = NULL
|
|
|
+ /* NULL = (default) Keeps whatever compression setting exists for the object and partition;
|
|
|
+ NONE = Forces no compression (and removes compression if set);
|
|
|
+ PAGE = Forces page compression;
|
|
|
+ ROW = Forces row compression.*/
|
|
|
AS
|
|
|
/*
|
|
|
-usp_AdaptiveIndexDefrag.sql - [email protected] (http://blogs.msdn.com/b/blogdoezequiel/)
|
|
|
+usp_AdaptiveIndexDefrag.sql - [email protected] (http://aka.ms/AID)
|
|
|
|
|
|
-Inspired by Michelle Ufford (http://sqlfool.com)
|
|
|
+v1 inspired by Michelle Ufford (http://sqlfool.com)
|
|
|
|
|
|
-PURPOSE: Intelligent defrag on one or more indexes for one or more databases.
|
|
|
+PURPOSE: Intelligent defrag on one or more indexes and statistics update for one or more databases.
|
|
|
|
|
|
DISCLAIMER:
|
|
|
This code is not supported under any Microsoft standard support program or service.
|
|
@@ -617,25 +624,25 @@ v1.5.4 - 12-09-2013 - Changed system database exclusion choices;
|
|
|
v1.5.5 - 24-10-2013 - Added more verbose to debug mode;
|
|
|
Fixed issue with error while keeping original fill factor when it was already set to 0 on the index;
|
|
|
Fixed issue with error 35337 or 2706 on update statistics.
|
|
|
-v1.5.6 - 27-11-2013 - Added SQL 2014 support for online partition rebuild;
|
|
|
+v1.5.6 - 27-11-2013 - Added SQL 2014 support for online partition rebuild;
|
|
|
Tuned LOB support with online operations;
|
|
|
Improved detection of scope changes - saves unneeded database scans;
|
|
|
Optimized defrag cycle pre-work with partially excluded DBs;
|
|
|
Fixed issue with skipping partially excluded databases;
|
|
|
Added resilience for CS collations.
|
|
|
-v1.5.7 - 14-01-2014 - Fixed issue on support SP usp_AdaptiveIndexDefrag_Exceptions with SQL Server 2005;
|
|
|
+v1.5.7 - 14-01-2014 - Fixed issue on support SP usp_AdaptiveIndexDefrag_Exceptions with SQL Server 2005;
|
|
|
Fixed issue with support SP usp_AdaptiveIndexDefrag_CurrentExecStats.
|
|
|
-v1.5.8 - 10-05-2014 - Added SQL 2014 support for Online Lock Priority;
|
|
|
+v1.5.8 - 10-05-2014 - Added SQL 2014 support for Online Lock Priority;
|
|
|
Fixed issue introduced in previous version where an Online rebuild operation could not be executed in SQL 2012.
|
|
|
-v1.5.9 - 17-11-2014 - Fixed issue on support SP usp_AdaptiveIndexDefrag_PurgeLogs.
|
|
|
-v1.6 - 18-11-2014 - Added resilience when objects are dropped while being scanned, avoiding error 2573.
|
|
|
-v1.6.1 - 04-02-2015 - Removed dependency of @scan_mode to use TF 2371 behavior for statistics update;
|
|
|
+v1.5.9 - 17-11-2014 - Fixed issue on support SP usp_AdaptiveIndexDefrag_PurgeLogs.
|
|
|
+v1.6 - 18-11-2014 - Added resilience when objects are dropped while being scanned, avoiding error 2573.
|
|
|
+v1.6.1 - 04-02-2015 - Removed dependency of @scan_mode to use TF 2371 behavior for statistics update;
|
|
|
Improved support for Columnstore indexes on SQL 2014, with specific rebuild threshold and reorg option.
|
|
|
-v1.6.2 - 10/3/2016 - Added option to determine whether to exclude blobs from fragmentation scan;
|
|
|
+v1.6.2 - 10/3/2016 - Added option to determine whether to exclude blobs from fragmentation scan;
|
|
|
Added support for incremental statistics;
|
|
|
Fixed PK issue with columnstore fragmentation discovery.
|
|
|
Fixed issue where auto created statistics would not be picked up for update.
|
|
|
-v1.6.3 - 10/14/2016 - Fixed issue with statistics collection in SQL Server 2012 and below;
|
|
|
+v1.6.3 - 10/14/2016 - Fixed issue with statistics collection in SQL Server 2012 and below;
|
|
|
Fixed issue where indexes on views generated error 1934.
|
|
|
v1.6.3.1 - 10/26/2016 - Fixed failed migration from v1.6.2 with NULL insert error;
|
|
|
Fixed issue when running in debug mode.
|
|
@@ -645,10 +652,10 @@ v1.6.3.2 - 11/4/2016 - Fixed DISABLE index applying to NCCI.
|
|
|
Fixed issue with statistics collection in SQL Server 2012 and below;
|
|
|
Added statistic related info to log table (rows, mod counter, rows sampled).
|
|
|
v1.6.3.3 - 11/7/2016 - Rolled back previously reported issue with REORGANIZE and database names.
|
|
|
-v1.6.4 - 11/10/2016 - Fixed support for incremental statistics in SQL Server 2016 RTM.
|
|
|
+v1.6.4 - 11/10/2016 - Fixed support for incremental statistics in SQL Server 2016 RTM.
|
|
|
v1.6.4.1 - 11/16/2016 - Added support for incremental statistics in SQL Server 2016 SP1.
|
|
|
v1.6.4.2 - 1/20/2017 - Fixed support for incremental statistics introduced error 4104.
|
|
|
-v1.6.5 - 2/18/2017 - Fixed empty columnstore indexes being picked up;
|
|
|
+v1.6.5 - 2/18/2017 - Fixed empty columnstore indexes being picked up;
|
|
|
Fixed orphaned statistic not being updated and preventing rescan;
|
|
|
Fixed getting null comparison in sys.indexes (only on SQL 2005, SQL 2008 or SQL 2008R2 pre-SP2);
|
|
|
Fixed insert error into tbl_AdaptiveIndexDefrag_Stats_log table.
|
|
@@ -660,6 +667,8 @@ v1.6.5.4 - 8/04/2017 - Fixed error where @minPageCount wasn't getting passed int
|
|
|
v1.6.5.5 - 8/11/2017 - Added support for fixed sampling rate for statistics.
|
|
|
v1.6.5.6 - 10/16/2017 - Added logging for fragmentation analysis.
|
|
|
v1.6.5.7 - 10/19/2017 - Extended support for CCI under SQL 2016 and above.
|
|
|
+v1.6.6 - 1/11/2018 - Added support to set or reset compression setting on all rowstore indexes;
|
|
|
+ Added support for MAXDOP in statistics operations.
|
|
|
|
|
|
IMPORTANT:
|
|
|
Execute in the database context of where you created the log and working tables.
|
|
@@ -705,15 +714,16 @@ ALL parameters are optional. If not specified, the defaults for each parameter a
|
|
|
0 = only Non-Clustered indexes will be defragmented (includes XML and Spatial Indexes);
|
|
|
|
|
|
@minFragmentation Defaults to 5%, will not defrag if fragmentation is less.
|
|
|
- Refer to http://msdn.microsoft.com/en-us/library/ms189858.aspx
|
|
|
+ Refer to http://docs.microsoft.com/sql/relational-databases/indexes/reorganize-and-rebuild-indexes
|
|
|
|
|
|
@rebuildThreshold Defaults to 30%. greater than 30% will result in rebuild instead of reorganize.
|
|
|
- Refer to http://msdn.microsoft.com/en-us/library/ms189858.aspx
|
|
|
+ Refer to http://docs.microsoft.com/sql/relational-databases/indexes/reorganize-and-rebuild-indexes
|
|
|
|
|
|
@rebuildThreshold_csDefaults to 10%. Greater than 10% will result in columnstore rebuild.
|
|
|
- Refer to https://msdn.microsoft.com/en-us/data/dn589807(v=sql.120)
|
|
|
+ Refer to http://docs.microsoft.com/sql/relational-databases/sql-server-index-design-guide
|
|
|
|
|
|
-@minPageCount Specifies how many pages must exist in an index in order to be considered for a defrag. Default to an extent. Refer to http://msdn.microsoft.com/en-us/library/ms189858.aspx
|
|
|
+@minPageCount Specifies how many pages must exist in an index in order to be considered for a defrag. Default to an extent.
|
|
|
+ Refer to http://docs.microsoft.com/sql/relational-databases/indexes/reorganize-and-rebuild-indexes
|
|
|
NOTE: The @minPageCount will restrict the indexes that are stored in tbl_AdaptiveIndexDefrag_Working table and can render other options inoperative.
|
|
|
|
|
|
@maxPageCount Specifies the maximum number of pages that can exist in an index and still be considered for a defrag.
|
|
@@ -738,16 +748,16 @@ ALL parameters are optional. If not specified, the defaults for each parameter a
|
|
|
@sortInTempDB When 1, the sort results are stored in TempDB. When 0, the sort results are stored in the filegroup or partition scheme in which the resulting index is stored.
|
|
|
If a sort operation is not required, or if the sort can be performed in memory, SORT_IN_TEMPDB is ignored.
|
|
|
Enabling this option can result in faster defrags and prevent database file size inflation. Just have monitor TempDB closely.
|
|
|
- More information here: http://msdn.microsoft.com/en-us/library/ms188281.aspx and http://msdn.microsoft.com/en-us/library/ms179542.aspx and http://msdn.microsoft.com/en-us/library/ms191183.aspx
|
|
|
+ Refer to http://docs.microsoft.com/sql/relational-databases/indexes/sort-in-tempdb-option-for-indexes and http://docs.microsoft.com/sql/relational-databases/indexes/disk-space-requirements-for-index-ddl-operations and http://docs.microsoft.com/sql/relational-databases/indexes/disk-space-requirements-for-index-ddl-operations
|
|
|
1 = perform sort operation in TempDB
|
|
|
0 = perform sort operation in the indexes database
|
|
|
|
|
|
-@maxDopRestriction Option to specify a processor limit for index rebuilds
|
|
|
+@maxDopRestriction Option to specify a processor limit for index rebuilds and statistics updates. If not specified, defrag operations will use the system MaxDOP setting, up to a limit of 8.
|
|
|
|
|
|
@updateStats 1 = updates stats when reorganizing;
|
|
|
0 = does not update stats when reorganizing
|
|
|
|
|
|
-@updateStatsWhere Update statistics within certain thresholds (http://support.microsoft.com/kb/195565/en-us)
|
|
|
+@updateStatsWhere Update statistics within certain thresholds. Refer to http://docs.microsoft.com/sql/relational-databases/statistics/statistics
|
|
|
1 = updates only index related stats;
|
|
|
0 = updates all stats in entire table
|
|
|
|
|
@@ -774,7 +784,8 @@ ALL parameters are optional. If not specified, the defaults for each parameter a
|
|
|
0 = default which is with STATISTICS_NORECOMPUTE off
|
|
|
|
|
|
@statsIncremental When Incremental is ON, the statistics created are per partition statistics.
|
|
|
- When OFF, the statistics tree is dropped and SQL Server re-computes the statistics. This setting overrides the database level INCREMENTAL property. (http://msdn.microsoft.com/en-us/library/ms190397.aspx)
|
|
|
+ When OFF, the statistics tree is dropped and SQL Server re-computes the statistics. This setting overrides the database level INCREMENTAL property.
|
|
|
+ Refer to http://docs.microsoft.com/sql/relational-databases/statistics/statistics
|
|
|
NULL = Keep server setting;
|
|
|
1 = Enable auto create statistics with Incremental
|
|
|
0 = Disable auto create statistics with Incremental
|
|
@@ -808,7 +819,8 @@ ALL parameters are optional. If not specified, the defaults for each parameter a
|
|
|
0 = does NOT disable non-clustered indexes prior to a rebuild (default behavior);
|
|
|
1 = disables non-clustered indexes prior to a rebuild (space saving feature)
|
|
|
|
|
|
-@offlinelocktimeout As set in SET LOCK_TIMEOUT (http://msdn.microsoft.com/en-us/library/ms189470.aspx)
|
|
|
+@offlinelocktimeout As set in SET LOCK_TIMEOUT option
|
|
|
+ Refer to http://docs.microsoft.com/sql/t-sql/statements/set-lock-timeout-transact-sql
|
|
|
-1 = (default) indicates no time-out period
|
|
|
Any other positive integer = sets the number of milliseconds that will pass before Microsoft SQL Server returns a locking error
|
|
|
|
|
@@ -826,6 +838,12 @@ ALL parameters are optional. If not specified, the defaults for each parameter a
|
|
|
@getBlobfrag Indicates whether to exclude or include blobs from fragmentation scan.
|
|
|
0 = (default) exclude blobs from fragmentation scan.
|
|
|
1 = include blobs and off-row data when scanning for fragmentation.
|
|
|
+
|
|
|
+@dataCompression Sets specific compression options for all indexes.
|
|
|
+ NULL = (default) Does not use the DATA_COMPRESSION keyword in index rebuild, keeping whatever compression setting exists.
|
|
|
+ NONE = Index or specified partitions are not compressed.
|
|
|
+ PAGE = Use page compression.
|
|
|
+ ROW = Use row compression.
|
|
|
|
|
|
-------------------------------------------------------
|
|
|
Usage:
|
|
@@ -858,7 +876,7 @@ SET XACT_ABORT ON;
|
|
|
SET QUOTED_IDENTIFIER ON;
|
|
|
SET DATEFORMAT ymd;
|
|
|
SET DEADLOCK_PRIORITY -10;
|
|
|
--- Required so it can update stats on IxVws and FiltIxs
|
|
|
+-- Required so it can update stats on Indexed Views and Filtered Indexes
|
|
|
SET ANSI_WARNINGS ON;
|
|
|
SET ANSI_PADDING ON;
|
|
|
SET ANSI_NULLS ON;
|
|
@@ -893,6 +911,9 @@ BEGIN
|
|
|
|
|
|
IF @timeLimit IS NULL
|
|
|
SET @timeLimit = 480;
|
|
|
+
|
|
|
+ IF @dataCompression IS NOT NULL AND UPPER(@dataCompression) NOT IN ('NONE','ROW','PAGE')
|
|
|
+ SET @dataCompression = NULL;
|
|
|
|
|
|
/* Validate if table name is fully qualified and database scope is set */
|
|
|
IF @tblName IS NOT NULL AND @tblName NOT LIKE '%.%'
|
|
@@ -1003,11 +1024,12 @@ END'
|
|
|
RETURN
|
|
|
END
|
|
|
END
|
|
|
- /* Check if database scope has changed, if rescan is not being forced */
|
|
|
+
|
|
|
+ /* Check if database scope has changed, if rescan is not being forced */
|
|
|
IF @forceRescan = 0 AND @dbScope IS NOT NULL -- Specific scope was set
|
|
|
BEGIN
|
|
|
- IF (SELECT COUNT(DISTINCT [dbID]) FROM dbo.tbl_AdaptiveIndexDefrag_Working) = 1
|
|
|
- AND QUOTENAME(LOWER(@dbScope)) NOT IN (SELECT DISTINCT LOWER([dbName]) FROM dbo.tbl_AdaptiveIndexDefrag_Working UNION SELECT DISTINCT LOWER(dbName) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working)
|
|
|
+ IF (SELECT COUNT(DISTINCT [dbID]) FROM dbo.tbl_AdaptiveIndexDefrag_Working) > 1
|
|
|
+ OR QUOTENAME(LOWER(@dbScope)) NOT IN (SELECT DISTINCT LOWER([dbName]) FROM dbo.tbl_AdaptiveIndexDefrag_Working UNION SELECT DISTINCT LOWER(dbName) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working)
|
|
|
BEGIN
|
|
|
SET @forceRescan = 1
|
|
|
RAISERROR('Scope has changed. Forcing rescan of single database in scope...', 0, 42) WITH NOWAIT;
|
|
@@ -1026,6 +1048,15 @@ END'
|
|
|
RAISERROR('No indexes of the chosen type left to defrag nor statistics left to update. Forcing rescan...', 0, 42) WITH NOWAIT;
|
|
|
END;
|
|
|
|
|
|
+ /* Recognize if we missing information post-upgrade;
|
|
|
+ if so force rescan of database(s) */
|
|
|
+ IF @forceRescan = 0
|
|
|
+ AND (EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working
|
|
|
+ WHERE (fill_factor IS NULL OR is_padded IS NULL OR compression_type IS NULL) AND [exclusionMask] & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)) BEGIN
|
|
|
+ SET @forceRescan = 1
|
|
|
+ RAISERROR('Missing column information due to post-upgrade condition. Forcing rescan...', 0, 42) WITH NOWAIT;
|
|
|
+ END;
|
|
|
+
|
|
|
/* Check if any databases where dropped or created since last run, if rescan is not being forced */
|
|
|
IF @forceRescan = 0 AND @dbScope IS NULL
|
|
|
BEGIN
|
|
@@ -1058,7 +1089,8 @@ WHERE [dbID] IN (SELECT DISTINCT database_id FROM master.sys.databases sd
|
|
|
, hasIXs bit NOT NULL
|
|
|
, scanStatus bit NULL
|
|
|
);
|
|
|
- /* Retrieve the list of databases to loop, excluding Always On secondary replicas */
|
|
|
+
|
|
|
+ /* Retrieve the list of databases to loop, excluding Always On secondary replicas */
|
|
|
SET @sqlcmd_CntTgt = 'SELECT [database_id], 0, 0 -- not yet scanned
|
|
|
FROM master.sys.databases
|
|
|
WHERE LOWER([name]) = ISNULL(LOWER(@dbScopeIN), LOWER([name]))
|
|
@@ -1194,9 +1226,11 @@ BEGIN SET @hasIXsOUT = 1 END ELSE BEGIN SET @hasIXsOUT = 0 END'
|
|
|
, @ColumnStoreGetIXSQL_Param NVARCHAR(1000)
|
|
|
, @rows bigint
|
|
|
, @rows_sampled bigint
|
|
|
+ , @AID_dbID int
|
|
|
+ , @currCompression NVARCHAR(60)
|
|
|
|
|
|
/* Initialize variables */
|
|
|
- SELECT @startDateTime = GETDATE(), @endDateTime = DATEADD(minute, @timeLimit, GETDATE()), @operationFlag = NULL, @ver = '1.6.5.6';
|
|
|
+ SELECT @AID_dbID = DB_ID(), @startDateTime = GETDATE(), @endDateTime = DATEADD(minute, @timeLimit, GETDATE()), @operationFlag = NULL, @ver = '1.6.6';
|
|
|
|
|
|
/* Create temporary tables */
|
|
|
IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragDatabaseList'))
|
|
@@ -1246,7 +1280,7 @@ BEGIN SET @hasIXsOUT = 1 END ELSE BEGIN SET @hasIXsOUT = 0 END'
|
|
|
SET @maxDopRestriction = 8;
|
|
|
END
|
|
|
|
|
|
- /* Refer to http://msdn.microsoft.com/en-us/library/ms174396.aspx */
|
|
|
+ /* Refer to http://docs.microsoft.com/sql/t-sql/functions/serverproperty-transact-sql */
|
|
|
IF (SELECT SERVERPROPERTY('EditionID')) IN (1804890536, 1872460670, 610778273, -2117995310)
|
|
|
SET @editionCheck = 1 -- supports enterprise only features: online rebuilds, partitioned indexes and MaxDOP
|
|
|
ELSE
|
|
@@ -1255,7 +1289,7 @@ BEGIN SET @hasIXsOUT = 1 END ELSE BEGIN SET @hasIXsOUT = 0 END'
|
|
|
/* Output the parameters to work with */
|
|
|
IF @debugMode = 1
|
|
|
BEGIN
|
|
|
- SELECT @debugMessage = CHAR(10) + 'Executing AdaptiveIndexDefrag v' + @ver + ' on ' + @@VERSION + '.
|
|
|
+ SELECT @debugMessage = CHAR(10) + 'Executing AdaptiveIndexDefrag v' + @ver + ' on ' + @@VERSION + '
|
|
|
The selected parameters are:
|
|
|
Defragment indexes with fragmentation greater or equal to ' + CAST(@minFragmentation AS NVARCHAR(10)) + ';
|
|
|
Rebuild indexes with fragmentation greater than ' + CAST(@rebuildThreshold AS NVARCHAR(10)) + ';
|
|
@@ -1265,7 +1299,7 @@ Rebuild columnstore indexes with fragmentation greater than ' + CAST(@rebuildThr
|
|
|
Commands' + CASE WHEN @Exec_Print = 1 THEN ' WILL' ELSE ' WILL NOT' END + ' be executed automatically;
|
|
|
Defragment indexes in ' + @defragSortOrder + ' order of the ' + UPPER(@defragOrderColumn) + ' value;
|
|
|
Time limit' + CASE WHEN @timeLimit IS NULL THEN ' was not specified;' ELSE ' was specified and is ' + CAST(@timeLimit AS NVARCHAR(10)) END + ' minutes;
|
|
|
-' + CASE WHEN @dbScope IS NULL THEN 'ALL databases' ELSE 'The ' + @dbScope + ' database' END + ' will be defragmented;
|
|
|
+' + CASE WHEN @dbScope IS NULL THEN 'ALL databases' ELSE 'The [' + @dbScope + '] database' END + ' will be defragmented;
|
|
|
' + CASE WHEN @tblName IS NULL THEN 'ALL tables' ELSE 'The ' + @tblName + ' table' END + ' will be defragmented;
|
|
|
' + 'We' + CASE WHEN EXISTS(SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL) AND @forceRescan = 0 THEN ' will resume any existing previous run. If so, we WILL NOT' ELSE ' WILL' END + ' be rescanning indexes;
|
|
|
The scan will be performed in ' + @scanMode + ' mode;
|
|
@@ -1274,7 +1308,8 @@ Limit defrags to indexes' + CASE WHEN @maxPageCount IS NULL THEN ' with more tha
|
|
|
' between ' + CAST(@minPageCount AS NVARCHAR(10)) + ' and ' + CAST(@maxPageCount AS NVARCHAR(10)) END + ' pages;
|
|
|
Indexes will be defragmented' + CASE WHEN @onlineRebuild = 0 OR @editionCheck = 0 THEN ' OFFLINE;' ELSE ' ONLINE;' END + '
|
|
|
Indexes will be sorted in' + CASE WHEN @sortInTempDB = 0 THEN ' the DATABASE;' ELSE ' TEMPDB;' END + '
|
|
|
-Indexes will have' + CASE WHEN @fillfactor = 1 THEN ' its ORIGINAL' ELSE ' the DEFAULT' END + ' Fill Factor;' +
|
|
|
+Indexes will use ' + CASE WHEN @dataCompression IS NULL THEN 'CURRENT compression setting;' WHEN @dataCompression = 'NONE' THEN 'NO compression on all indexes;' WHEN @dataCompression = 'PAGE' THEN 'PAGE compression on all indexes;' WHEN @dataCompression = 'ROW' THEN 'ROW compression on all indexes;' ELSE @dataCompression + 'COLUMNSTORE compression on all indexes;' END + '
|
|
|
+Indexes will keep' + CASE WHEN @fillfactor = 1 THEN ' its EXISTING' ELSE ' the DEFAULT' END + ' Fill Factor;' +
|
|
|
CASE WHEN @dealMaxPartition = 1 AND @editionCheck = 1 THEN '
|
|
|
The right-most populated partitions will be ignored;'
|
|
|
WHEN @dealMaxPartition = 0 AND @editionCheck = 1 THEN '
|
|
@@ -1289,10 +1324,10 @@ CHAR(10) + 'Statistics will be updated using ' + CASE WHEN @statsThreshold IS NO
|
|
|
+ ' on tables' + CASE WHEN @statsThreshold IS NOT NULL AND @statsThreshold BETWEEN 0.01 AND 100.0 AND @statsMinRows IS NOT NULL THEN ' with a min of ' + CONVERT(VARCHAR, @statsMinRows) + ' rows.' WHEN @statsMinRows IS NOT NULL THEN ' of any size.' ELSE '.' END +
|
|
|
CHAR(10) + 'Statistics will be updated with Incremental property (if any) ' + CASE WHEN @statsIncremental = 1 THEN 'as ON' WHEN @statsIncremental = 0 THEN 'as OFF' ELSE 'not changed from current setting' END + '.' +
|
|
|
CHAR(10) + 'Defragmentation will use ' + CASE WHEN @editionCheck = 0 OR @maxDopRestriction IS NULL THEN 'system defaults for processors;'
|
|
|
-ELSE CAST(@maxDopRestriction AS VARCHAR(2)) + ' processors;' END +
|
|
|
+ELSE CAST(@maxDopRestriction AS VARCHAR(3)) + ' processors;' END +
|
|
|
CHAR(10) + 'Lock timeout is set to ' + CASE WHEN @offlinelocktimeout <> -1 AND @offlinelocktimeout IS NOT NULL THEN CONVERT(NVARCHAR(15), @offlinelocktimeout) ELSE 'system default' END + ' for offline rebuilds;' +
|
|
|
-CHAR(10) + 'From SQL Server 2014, lock timeout is set to ' + CONVERT(NVARCHAR(15), @onlinelocktimeout) + ' for online rebuilds;' +
|
|
|
-CHAR(10) + 'From SQL Server 2014, lock timeout action is set to ' + CASE WHEN @abortAfterwait = 0 THEN 'BLOCKERS' WHEN @abortAfterwait = 1 THEN 'SELF' ELSE 'NONE' END + ' for online rebuilds;' +
|
|
|
+CHAR(10) + 'Starting with SQL Server 2014, lock timeout is set to ' + CONVERT(NVARCHAR(15), @onlinelocktimeout) + ' for online rebuilds;' +
|
|
|
+CHAR(10) + 'Starting with SQL Server 2014, lock timeout action is set to ' + CASE WHEN @abortAfterwait = 0 THEN 'BLOCKERS' WHEN @abortAfterwait = 1 THEN 'SELF' ELSE 'NONE' END + ' for online rebuilds;' +
|
|
|
CHAR(10) + CASE WHEN @printCmds = 1 THEN ' DO print' ELSE ' DO NOT print' END + ' the sql commands;' +
|
|
|
CHAR(10) + CASE WHEN @outputResults = 1 THEN ' DO output' ELSE ' DO NOT output' END + ' fragmentation levels;
|
|
|
Wait ' + @defragDelay + ' (hh:mm:ss) between index operations;
|
|
@@ -1307,7 +1342,7 @@ Execute in' + CASE WHEN @debugMode = 1 THEN ' DEBUG' ELSE ' SILENT' END + ' mode
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR('Listing databases...', 0, 42) WITH NOWAIT;
|
|
|
|
|
|
- /* Retrieve the list of databases to loop, exclusing Always On secondary replicas */
|
|
|
+ /* Retrieve the list of databases to loop, excluding Always On secondary replicas */
|
|
|
DECLARE @sqlcmdAO2 NVARCHAR(4000), @paramsAO2 NVARCHAR(50)
|
|
|
|
|
|
IF @debugMode = 1 AND @sqlmajorver >= 11
|
|
@@ -1397,11 +1432,19 @@ WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
|
|
|
/* Reset status after cross check with exceptions */
|
|
|
UPDATE #tblIndexDefragDatabaseList
|
|
|
SET scanStatus = 0;
|
|
|
+
|
|
|
+ /* Delete database set by @dbScope */
|
|
|
+ IF @dbScope IS NOT NULL
|
|
|
+ BEGIN
|
|
|
+ DELETE FROM #tblIndexDefragDatabaseList
|
|
|
+ WHERE dbID <> DB_ID(@dbScope);
|
|
|
+ END;
|
|
|
END
|
|
|
|
|
|
/* Check to see if we have indexes of the chosen type in need of defrag, or stats to update; otherwise, allow re-scanning the database(s) */
|
|
|
- IF @forceRescan = 1 OR (NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL AND [exclusionMask] & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)
|
|
|
- AND NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working AS idss WHERE idss.updateDate IS NULL AND NOT EXISTS (SELECT TOP 1 objectID FROM dbo.tbl_AdaptiveIndexDefrag_Working ids WHERE ids.[dbID] = idss.[dbID] AND ids.objectID = idss.objectID AND idss.statsName = ids.indexName AND idss.updateDate IS NULL AND ids.exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)))
|
|
|
+ IF @forceRescan = 1 OR (@forceRescan = 0
|
|
|
+ AND NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL AND [exclusionMask] & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)
|
|
|
+ AND NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working AS idss WHERE idss.updateDate IS NULL AND NOT EXISTS (SELECT TOP 1 objectID FROM dbo.tbl_AdaptiveIndexDefrag_Working ids WHERE ids.[dbID] = idss.[dbID] AND ids.objectID = idss.objectID AND idss.statsName = ids.indexName AND idss.updateDate IS NULL AND ids.exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)))
|
|
|
BEGIN
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR('Preparing for new database scan...', 0, 42) WITH NOWAIT;
|
|
@@ -1412,7 +1455,7 @@ WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
|
|
|
END
|
|
|
ELSE
|
|
|
BEGIN
|
|
|
- /* Print an error message if there are any indexes left to defragment according to the chosen criteria */
|
|
|
+ /* Print an error message if there are any indexes left to defrag according to the chosen criteria */
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR('There are still fragmented indexes or out-of-date stats from last execution. Resuming...', 0, 42) WITH NOWAIT;
|
|
|
END
|
|
@@ -1432,7 +1475,7 @@ WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
|
|
|
SELECT TOP 1 @dbID = dbID FROM #tblIndexDefragDatabaseList WHERE scanStatus = 0;
|
|
|
|
|
|
IF @debugMode = 1
|
|
|
- SELECT @debugMessage = ' Working on ' + DB_NAME(@dbID) + '...';
|
|
|
+ SELECT @debugMessage = ' Working on database [' + DB_NAME(@dbID) + ']...';
|
|
|
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
|
|
@@ -1449,12 +1492,13 @@ WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
|
|
|
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR(' Building list of objects in database...', 0, 42) WITH NOWAIT;
|
|
|
- SELECT @TableScanSQL = 'SELECT si.[object_id], si.index_id, si.type, sp.partition_number, 0
|
|
|
-FROM [' + DB_NAME(@dbID) + '].sys.indexes si
|
|
|
-INNER JOIN [' + DB_NAME(@dbID) + '].sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id
|
|
|
-INNER JOIN [' + DB_NAME(@dbID) + '].sys.tables AS mst ON mst.[object_id] = si.[object_id]
|
|
|
-INNER JOIN [' + DB_NAME(@dbID) + '].sys.schemas AS t ON t.[schema_id] = mst.[schema_id]' +
|
|
|
-CASE WHEN @dbScope IS NULL AND @tblName IS NULL THEN CHAR(10) + 'LEFT JOIN [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Exceptions AS ide ON ide.[dbID] = ' + CONVERT(NVARCHAR(10),@dbID) + ' AND ide.objectID = si.[object_id] AND ide.indexID = si.index_id' ELSE '' END +
|
|
|
+ SELECT @TableScanSQL = 'USE [' + DB_NAME(@dbID) + ']
|
|
|
+SELECT si.[object_id], si.index_id, si.type, sp.partition_number, 0
|
|
|
+FROM sys.indexes si
|
|
|
+INNER JOIN sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id
|
|
|
+INNER JOIN sys.tables AS mst ON mst.[object_id] = si.[object_id]
|
|
|
+INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]' +
|
|
|
+CASE WHEN @dbScope IS NULL AND @tblName IS NULL THEN CHAR(10) + 'LEFT JOIN [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Exceptions AS ide ON ide.[dbID] = ' + CONVERT(NVARCHAR(10),@dbID) + ' AND ide.objectID = si.[object_id] AND ide.indexID = si.index_id' ELSE '' END +
|
|
|
CHAR(10) + 'WHERE mst.is_ms_shipped = 0 ' + CASE WHEN @dbScope IS NULL AND @tblName IS NULL THEN 'AND (ide.exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0 OR ide.exclusionMask IS NULL)' ELSE '' END + '
|
|
|
AND si.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + DB_NAME(@dbID) + '].sys.internal_tables AS sit)' +
|
|
|
CASE WHEN @dbScope IS NOT NULL AND @tblName IS NOT NULL THEN '
|
|
@@ -1497,7 +1541,7 @@ CHAR(10) + 'WHERE mst.is_ms_shipped = 0 ' + CASE WHEN @dbScope IS NULL AND @tblN
|
|
|
INNER JOIN #tblIndexDefragmaxPartitionList AS mpl ON ids.objectID = mpl.objectID AND ids.indexID = mpl.indexID AND ids.partitionNumber <> mpl.maxPartition;
|
|
|
END;
|
|
|
|
|
|
- /* Determine which indexes to defragment using user-defined parameters */
|
|
|
+ /* Determine which indexes to defrag using user-defined parameters */
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR(' Filtering indexes according to ixtypeOption parameter...', 0, 42) WITH NOWAIT;
|
|
|
IF @ixtypeOption IS NULL
|
|
@@ -1563,7 +1607,7 @@ CHAR(10) + 'WHERE mst.is_ms_shipped = 0 ' + CASE WHEN @dbScope IS NULL AND @tblN
|
|
|
BEGIN CATCH
|
|
|
IF @debugMode = 1
|
|
|
BEGIN
|
|
|
- SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining which rowstore indexes to defragment. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
|
|
|
+ SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining which rowstore indexes to defrag. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
|
|
|
|
|
|
SET @dateTimeEnd = GETDATE();
|
|
|
|
|
@@ -1626,7 +1670,7 @@ OPTION (MAXDOP 2)'
|
|
|
BEGIN CATCH
|
|
|
IF @debugMode = 1
|
|
|
BEGIN
|
|
|
- SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining which columnstore indexes to defragment. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
|
|
|
+ SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining which columnstore indexes to defrag. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
|
|
|
|
|
|
SET @dateTimeEnd = GETDATE();
|
|
|
|
|
@@ -1659,7 +1703,7 @@ OPTION (MAXDOP 2)'
|
|
|
/* Look up index status for various purposes */
|
|
|
SELECT @updateSQL = N'UPDATE ids
|
|
|
SET schemaName = QUOTENAME(s.name), objectName = QUOTENAME(o.name), indexName = QUOTENAME(i.name), is_primary_key = i.is_primary_key, fill_factor = i.fill_factor, is_disabled = i.is_disabled, is_padded = i.is_padded, is_hypothetical = i.is_hypothetical, has_filter = ' + CASE WHEN @sqlmajorver >= 10 THEN 'i.has_filter' ELSE '0' END + ', allow_page_locks = i.allow_page_locks, type = i.type
|
|
|
-FROM [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
|
|
|
+FROM [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
|
|
|
INNER JOIN [' + DB_NAME(@dbID) + '].sys.objects AS o WITH (NOLOCK) ON ids.objectID = o.object_id
|
|
|
INNER JOIN [' + DB_NAME(@dbID) + '].sys.indexes AS i WITH (NOLOCK) ON o.object_id = i.object_id AND ids.indexID = i.index_id
|
|
|
INNER JOIN [' + DB_NAME(@dbID) + '].sys.schemas AS s WITH (NOLOCK) ON o.schema_id = s.schema_id
|
|
@@ -1672,8 +1716,8 @@ AND ids.[dbID] = ' + CAST(@dbID AS NVARCHAR(10));
|
|
|
IF @scanMode = 'LIMITED'
|
|
|
BEGIN
|
|
|
SELECT @updateSQL = N'UPDATE ids
|
|
|
-SET record_count = [rows]
|
|
|
-FROM [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
|
|
|
+SET [record_count] = [rows], [compression_type] = [data_compression_desc]
|
|
|
+FROM [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
|
|
|
INNER JOIN [' + DB_NAME(@dbID) + '].sys.partitions AS p WITH (NOLOCK) ON ids.objectID = p.[object_id] AND ids.indexID = p.index_id AND ids.partitionNumber = p.partition_number
|
|
|
WHERE ids.[dbID] = ' + CAST(@dbID AS NVARCHAR(10));
|
|
|
|
|
@@ -1682,42 +1726,29 @@ WHERE ids.[dbID] = ' + CAST(@dbID AS NVARCHAR(10));
|
|
|
|
|
|
IF @debugMode = 1
|
|
|
RAISERROR(' Looking up additional statistic information...', 0, 42) WITH NOWAIT;
|
|
|
-
|
|
|
+
|
|
|
/* Look up stats information for various purposes */
|
|
|
- IF @tblName IS NULL
|
|
|
- BEGIN
|
|
|
- SELECT @updateSQL = N'USE [' + DB_NAME(@dbID) + '];
|
|
|
-SELECT DISTINCT ' + CAST(@dbID AS NVARCHAR(10)) + ', ''' + QUOTENAME(DB_NAME(@dbID)) + ''', ss.[object_id], ss.stats_id, ' + CASE WHEN ((@sqlmajorver = 12 AND @sqlbuild >= 5000) OR @sqlmajorver > 12) THEN 'ISNULL(sp.partition_number,1),' ELSE '1,' END + '
|
|
|
- QUOTENAME(s.name), QUOTENAME(so.name), QUOTENAME(ss.name), ss.[no_recompute], ' + CASE WHEN @sqlmajorver < 12 THEN '0 AS ' ELSE 'ss.' END + '[is_incremental], GETDATE() AS scanDate
|
|
|
-FROM sys.stats ss WITH (NOLOCK)
|
|
|
-INNER JOIN sys.objects so WITH (NOLOCK) ON ss.[object_id] = so.[object_id]
|
|
|
-INNER JOIN sys.schemas s WITH (NOLOCK) ON so.[schema_id] = s.[schema_id]
|
|
|
-LEFT JOIN sys.indexes si WITH (NOLOCK) ON ss.[object_id] = si.[object_id] and ss.name = si.name
|
|
|
-' + CASE WHEN ((@sqlmajorver = 12 AND @sqlbuild >= 5000) OR @sqlmajorver > 12) THEN 'CROSS APPLY sys.dm_db_stats_properties_internal(ss.[object_id], ss.stats_id) sp' ELSE '' END + '
|
|
|
-WHERE is_ms_shipped = 0 ' + CASE WHEN @sqlmajorver >= 12 THEN 'AND ss.is_temporary = 0' ELSE '' END + '
|
|
|
- AND so.[object_id] NOT IN (SELECT sit.[object_id] FROM sys.internal_tables AS sit)
|
|
|
- AND so.[type] IN (''U'',''V'')
|
|
|
- AND (si.[type] IS NULL OR si.[type] NOT IN (5,6,7))' -- Avoid error 35337
|
|
|
- END
|
|
|
- ELSE
|
|
|
+ DECLARE @tblNameOnly NVARCHAR(1000), @schemaNameOnly NVARCHAR(128)
|
|
|
+ IF @tblName IS NOT NULL
|
|
|
BEGIN
|
|
|
- DECLARE @tblNameOnly NVARCHAR(1000), @schemaNameOnly NVARCHAR(128)
|
|
|
SELECT @tblNameOnly = RIGHT(@tblName, LEN(@tblName) - CHARINDEX('.', @tblName, 1)), @schemaNameOnly = LEFT(@tblName, CHARINDEX('.', @tblName, 1) -1)
|
|
|
- SELECT @updateSQL = N'USE [' + DB_NAME(@dbID) + '];
|
|
|
+ END
|
|
|
+
|
|
|
+ SELECT @updateSQL = N'USE [' + DB_NAME(@dbID) + '];
|
|
|
SELECT DISTINCT ' + CAST(@dbID AS NVARCHAR(10)) + ', ''' + QUOTENAME(DB_NAME(@dbID)) + ''', ss.[object_id], ss.stats_id, ' + CASE WHEN ((@sqlmajorver = 12 AND @sqlbuild >= 5000) OR @sqlmajorver > 12) THEN 'ISNULL(sp.partition_number,1),' ELSE '1,' END + '
|
|
|
QUOTENAME(s.name), QUOTENAME(so.name), QUOTENAME(ss.name), ss.[no_recompute], ' + CASE WHEN @sqlmajorver < 12 THEN '0 AS ' ELSE 'ss.' END + '[is_incremental], GETDATE() AS scanDate
|
|
|
-FROM sys.stats ss WITH (NOLOCK)
|
|
|
-INNER JOIN sys.objects so WITH (NOLOCK) ON ss.[object_id] = so.[object_id]
|
|
|
-INNER JOIN sys.schemas s WITH (NOLOCK) ON so.[schema_id] = s.[schema_id]
|
|
|
-LEFT JOIN sys.indexes si WITH (NOLOCK) ON ss.[object_id] = si.[object_id] and ss.name = si.name
|
|
|
-' + CASE WHEN @sqlmajorver >= 12 THEN 'CROSS APPLY sys.dm_db_stats_properties_internal(ss.[object_id], ss.stats_id) sp' ELSE '' END + '
|
|
|
-WHERE is_ms_shipped = 0 ' + CASE WHEN @sqlmajorver >= 12 THEN 'AND ss.is_temporary = 0' ELSE '' END + '
|
|
|
+FROM sys.stats AS ss WITH (NOLOCK)
|
|
|
+INNER JOIN sys.objects AS so WITH (NOLOCK) ON ss.[object_id] = so.[object_id]
|
|
|
+INNER JOIN sys.schemas AS s WITH (NOLOCK) ON so.[schema_id] = s.[schema_id]' +
|
|
|
+CASE WHEN @updateStatsWhere = 0 THEN 'LEFT JOIN' ELSE 'INNER JOIN' END + -- @updateStatsWhere = 0 then table-wide statistics;
|
|
|
+' sys.indexes AS si WITH (NOLOCK) ON ss.[object_id] = si.[object_id] and ss.name = si.name' +
|
|
|
+CASE WHEN @dbScope IS NULL AND @tblName IS NULL THEN CHAR(10) + CHAR(10) + 'LEFT JOIN [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Exceptions AS ide ON ide.[dbID] = ' + CONVERT(NVARCHAR(10),@dbID) + ' AND ide.objectID = so.[object_id]' ELSE '' END +
|
|
|
+CASE WHEN ((@sqlmajorver = 12 AND @sqlbuild >= 5000) OR @sqlmajorver > 12) THEN CHAR(10) + 'CROSS APPLY sys.dm_db_stats_properties_internal(ss.[object_id], ss.stats_id) sp' ELSE '' END +
|
|
|
+CHAR(10) + 'WHERE is_ms_shipped = 0 ' + CASE WHEN @sqlmajorver >= 12 THEN 'AND ss.is_temporary = 0' ELSE '' END + '
|
|
|
AND so.[object_id] NOT IN (SELECT sit.[object_id] FROM sys.internal_tables AS sit)
|
|
|
- AND s.name = ''' + @schemaNameOnly + '''
|
|
|
- AND so.name = ''' + @tblNameOnly + '''
|
|
|
AND so.[type] IN (''U'',''V'')
|
|
|
- AND (si.[type] IS NULL OR si.[type] NOT IN (5,6,7))' -- Avoid error 35337
|
|
|
- END
|
|
|
+ AND (si.[type] IS NULL OR si.[type] NOT IN (5,6,7))' + -- Avoid error 35337
|
|
|
+CASE WHEN @dbScope IS NOT NULL AND @tblName IS NOT NULL THEN CHAR(10) + 'AND s.name = ''' + @schemaNameOnly + ''' AND so.name = ''' + @tblNameOnly + ''';' ELSE ';' END
|
|
|
|
|
|
INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_Working (dbID, dbName, objectID, statsID, partitionNumber, schemaName, objectName, statsName, [no_recompute], [is_incremental], scanDate)
|
|
|
EXECUTE sp_executesql @updateSQL;
|
|
@@ -1824,13 +1855,13 @@ ORDER BY + ' + @defragOrderColumn + ' ' + @defragSortOrder;
|
|
|
/* Get object names and info */
|
|
|
IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
|
|
|
BEGIN
|
|
|
- SELECT TOP 1 @objectName = objectName, @schemaName = schemaName, @indexName = indexName, @dbName = dbName, @fragmentation = fragmentation, @partitionNumber = partitionNumber, @pageCount = page_count, @range_scan_count = range_scan_count, @is_primary_key = is_primary_key, @fill_factor = fill_factor, @record_count = record_count, @ixtype = [type], @is_disabled = is_disabled, @is_padded = is_padded, @has_filter = has_filter
|
|
|
+ SELECT TOP 1 @objectName = objectName, @schemaName = schemaName, @indexName = indexName, @dbName = dbName, @fragmentation = fragmentation, @partitionNumber = partitionNumber, @pageCount = page_count, @range_scan_count = range_scan_count, @is_primary_key = is_primary_key, @fill_factor = fill_factor, @record_count = record_count, @ixtype = [type], @is_disabled = is_disabled, @is_padded = is_padded, @has_filter = has_filter, @currCompression = [compression_type]
|
|
|
FROM dbo.tbl_AdaptiveIndexDefrag_Working
|
|
|
WHERE objectID = @objectID AND indexID = @indexID AND dbID = @dbID AND ((@Exec_Print = 1 AND defragDate IS NULL) OR (@Exec_Print = 0 AND defragDate IS NULL AND printStatus = 0));
|
|
|
END
|
|
|
ELSE
|
|
|
BEGIN
|
|
|
- SELECT TOP 1 @objectName = objectName, @schemaName = schemaName, @indexName = indexName, @dbName = dbName, @fragmentation = fragmentation, @partitionNumber = NULL, @pageCount = page_count, @range_scan_count = range_scan_count, @is_primary_key = is_primary_key, @fill_factor = fill_factor, @record_count = record_count, @ixtype = [type], @is_disabled = is_disabled, @is_padded = is_padded, @has_filter = has_filter
|
|
|
+ SELECT TOP 1 @objectName = objectName, @schemaName = schemaName, @indexName = indexName, @dbName = dbName, @fragmentation = fragmentation, @partitionNumber = NULL, @pageCount = page_count, @range_scan_count = range_scan_count, @is_primary_key = is_primary_key, @fill_factor = fill_factor, @record_count = record_count, @ixtype = [type], @is_disabled = is_disabled, @is_padded = is_padded, @has_filter = has_filter, @currCompression = [compression_type]
|
|
|
FROM dbo.tbl_AdaptiveIndexDefrag_Working
|
|
|
WHERE objectID = @objectID AND indexID = @indexID AND dbID = @dbID AND ((@Exec_Print = 1 AND defragDate IS NULL) OR (@Exec_Print = 0 AND defragDate IS NULL AND printStatus = 0));
|
|
|
END
|
|
@@ -1959,8 +1990,8 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
END
|
|
|
/* If the index is heavily fragmented and doesn't contain any partitions,
|
|
|
or if the index does not allow page locks, or if it is a filtered index, rebuild it */
|
|
|
- ELSE IF (@fragmentation >= @rebuildThreshold AND @ixtype IN (1,2))
|
|
|
- OR (@fragmentation >= @rebuildThreshold_cs AND @ixtype IN (5,6))
|
|
|
+ ELSE IF ((@fragmentation >= @rebuildThreshold AND @ixtype IN (1,2)) OR @rebuildThreshold = 0)
|
|
|
+ OR ((@fragmentation >= @rebuildThreshold_cs AND @ixtype IN (5,6)) OR @rebuildThreshold_cs = 0)
|
|
|
OR @has_filter = 1 OR @allowPageLocks = 0
|
|
|
BEGIN
|
|
|
SET @rebuildcommand = N' REBUILD'
|
|
@@ -1979,26 +2010,47 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
/* Set defrag options*/
|
|
|
SET @rebuildcommand = @rebuildcommand + N' WITH ('
|
|
|
|
|
|
- /* Set index pad options; not compatible with partition operations*/
|
|
|
+ /* Set index pad options; not compatible with partition operations */
|
|
|
IF @is_padded = 1 AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
|
|
|
SET @rebuildcommand = @rebuildcommand + N'PAD_INDEX = ON, '
|
|
|
|
|
|
+ /* Sets specific compression options for indexes */
|
|
|
+ IF @dataCompression IN ('NONE','PAGE','ROW')
|
|
|
+ AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
|
|
|
+ AND @ixtype IN (1,2)
|
|
|
+ AND (@sqlmajorver > 13 OR (@sqlmajorver = 13 AND @sqlbuild >= 4001) OR @editionCheck = 1) -- SQL 2016 SP1 or higher for compression in non-EE
|
|
|
+ SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @dataCompression + ', '
|
|
|
+
|
|
|
+ IF @dataCompression IS NULL
|
|
|
+ AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
|
|
|
+ AND @ixtype IN (1,2)
|
|
|
+ AND (@sqlmajorver > 13 OR (@sqlmajorver = 13 AND @sqlbuild >= 4001) OR @editionCheck = 1) -- SQL 2016 SP1 or higher for compression in non-EE
|
|
|
+ SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @currCompression + ', '
|
|
|
+
|
|
|
+ IF @dataCompression IN ('NONE','PAGE','ROW') AND @ixtype IN (1,2)
|
|
|
+ AND @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
|
|
|
+ SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @dataCompression + ' ON PARTITIONS (' + CAST(@partitionNumber AS NVARCHAR(10)) + '), '
|
|
|
+
|
|
|
+ IF @dataCompression IS NULL AND @ixtype IN (1,2)
|
|
|
+ AND @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
|
|
|
+ SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @currCompression + ' ON PARTITIONS (' + CAST(@partitionNumber AS NVARCHAR(10)) + '), '
|
|
|
+
|
|
|
/* Set online rebuild options; requires Enterprise Edition; not compatible with partition operations, Columnstore indexes in table and XML or Spatial indexes.
|
|
|
- Up to SQL Server 2008R2, not compatible with clustered indexes with LOB columnns in table or non-clustered indexes with LOBs in INCLUDED columns.
|
|
|
- In SQL Server 2012, not compatible with clustered indexes with LOB columnns in table.*/
|
|
|
+ Up to SQL Server 2008R2, not compatible with clustered indexes with LOB columns in table or non-clustered indexes with LOBs in INCLUDED columns.
|
|
|
+ In SQL Server 2012, not compatible with clustered indexes with LOB columns in table.*/
|
|
|
IF @sqlmajorver <= 11 AND @onlineRebuild = 1 AND @editionCheck = 1
|
|
|
AND @ixtype IN (1,2) AND @containsLOB = 0
|
|
|
AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
|
|
|
SET @rebuildcommand = @rebuildcommand + N'ONLINE = ON, ';
|
|
|
|
|
|
/* Set online rebuild options; requires Enterprise Edition; not compatible with partition operations, Columnstore indexes in table and XML or Spatial indexes.
|
|
|
- In SQL Server 2014, not compatible with clustered indexes with LOB columnns in table, but compatible with partition operations.
|
|
|
- Also, we can use Lock Priority with online indexing.*/
|
|
|
+ In SQL Server 2014, not compatible with clustered indexes with LOB columns in table, but compatible with partition operations.
|
|
|
+ Also, we can use Lock Priority with online indexing. */
|
|
|
IF @sqlmajorver > 11 AND @onlineRebuild = 1 AND @editionCheck = 1
|
|
|
AND @ixtype IN (1,2) AND @containsLOB = 0
|
|
|
SELECT @rebuildcommand = @rebuildcommand + N'ONLINE = ON (WAIT_AT_LOW_PRIORITY (MAX_DURATION = ' + CONVERT(NVARCHAR(15), @onlinelocktimeout) + ', ABORT_AFTER_WAIT = ' + CASE WHEN @abortAfterwait = 0 THEN 'BLOCKERS' WHEN @abortAfterwait = 1 THEN 'SELF' ELSE 'NONE' END + ')), '
|
|
|
|
|
|
- /* Set fill factor operation preferences; not compatible with partition operations and Columnstore indexes*/
|
|
|
+ /* Set fill factor operation preferences; not compatible with partition operations and Columnstore indexes */
|
|
|
IF @fillfactor = 1 AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1)) AND @ixtype IN (1,2)
|
|
|
SET @rebuildcommand = @rebuildcommand + N'FILLFACTOR = ' + CONVERT(NVARCHAR, CASE WHEN @fill_factor = 0 THEN 100 ELSE @fill_factor END) + N', ';
|
|
|
|
|
@@ -2019,7 +2071,7 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
|
|
|
/* Set processor restriction options; requires Enterprise Edition */
|
|
|
IF @maxDopRestriction IS NOT NULL AND @editionCheck = 1
|
|
|
- SET @rebuildcommand = @rebuildcommand + N'MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(2)) + N');';
|
|
|
+ SET @rebuildcommand = @rebuildcommand + N'MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3)) + N');';
|
|
|
ELSE
|
|
|
SET @rebuildcommand = @rebuildcommand + N');';
|
|
|
|
|
@@ -2044,11 +2096,23 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
IF (@sqlmajorver < 13 OR @partitionCount = 1) AND @sqldisablecommand IS NULL AND @ixtype IN (1,2)
|
|
|
BEGIN
|
|
|
SET @sqlprecommand = N'UPDATE STATISTICS ' + @dbName + N'.' + @schemaName + N'.' + @objectName + N' (' + @indexName + N')'
|
|
|
- SET @sqlprecommand = @sqlprecommand + N'; '
|
|
|
+
|
|
|
+ /* Set processor restriction options */
|
|
|
+ IF @maxDopRestriction IS NOT NULL
|
|
|
+ AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
|
|
|
+ SET @sqlprecommand = @sqlprecommand + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3)) + N'; ';
|
|
|
+ ELSE
|
|
|
+ SET @sqlprecommand = @sqlprecommand + N'; ';
|
|
|
END
|
|
|
ELSE IF @sqlmajorver >= 13 AND @partitionCount > 1 AND @stats_isincremental = 1 AND @sqldisablecommand IS NULL AND @ixtype IN (1,2)
|
|
|
BEGIN
|
|
|
SET @sqlprecommand = N'UPDATE STATISTICS ' + @dbName + N'.' + @schemaName + N'.' + @objectName + N' (' + @indexName + N') WITH RESAMPLE ON PARTITIONS(' + CONVERT(NVARCHAR(10), @partitionNumber) + N')'
|
|
|
+
|
|
|
+ /* Set processor restriction options */
|
|
|
+ IF @maxDopRestriction IS NOT NULL
|
|
|
+ AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
|
|
|
+ SET @sqlprecommand = @sqlprecommand + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3)) + N'; ';
|
|
|
+ ELSE
|
|
|
SET @sqlprecommand = @sqlprecommand + N'; '
|
|
|
END
|
|
|
|
|
@@ -2387,7 +2451,7 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
Default rules for auto update stats are:
|
|
|
If the cardinality for a table is greater than 6, but less than or equal to 500, update status every 500 modifications.
|
|
|
If the cardinality for a table is greater than 500, update statistics when (500 + 20 percent of the table) changes have occurred.
|
|
|
- Reference: http://support.microsoft.com/kb/195565
|
|
|
+ Reference: http://docs.microsoft.com/sql/relational-databases/statistics/statistics and http://support.microsoft.com/kb/195565
|
|
|
*/
|
|
|
IF (@statsThreshold IS NOT NULL AND @statsThreshold BETWEEN 0.001 AND 100.0 AND @statsMinRows IS NULL AND (@rowmodctr*100)/@record_count >= @statsThreshold)
|
|
|
OR (@statsThreshold IS NOT NULL AND @statsThreshold BETWEEN 0.001 AND 100.0 AND @statsMinRows IS NOT NULL AND @record_count >= @statsMinRows AND (@rowmodctr*100)/@record_count >= @statsThreshold)
|
|
@@ -2424,7 +2488,16 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
ELSE IF @stats_norecompute = 1 AND @sqlcommand2 NOT LIKE '%WITH%'
|
|
|
SET @sqlcommand2 = @sqlcommand2 + N' WITH NORECOMPUTE'
|
|
|
|
|
|
- /* For list of incremental stats unsupported scenarios check https://msdn.microsoft.com/en-us/library/ms187348.aspx */
|
|
|
+ IF @maxDopRestriction IS NOT NULL
|
|
|
+ AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
|
|
|
+ AND UPPER(@sqlcommand2) LIKE '%WITH%'
|
|
|
+ SET @sqlcommand2 = @sqlcommand2 + N' ,MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
|
|
|
+ ELSE IF @maxDopRestriction IS NOT NULL
|
|
|
+ AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
|
|
|
+ AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
|
|
|
+ SET @sqlcommand2 = @sqlcommand2 + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
|
|
|
+
|
|
|
+ /* For list of incremental stats unsupported scenarios check http://docs.microsoft.com/sql/t-sql/statements/update-statistics-transact-sql */
|
|
|
IF @partitionCount > 1 AND @statsIncremental = 1 AND @has_filter = 0
|
|
|
BEGIN
|
|
|
IF UPPER(@sqlcommand2) LIKE '%WITH%'
|
|
@@ -2585,7 +2658,7 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
|
|
|
/* Get stat associated table record count */
|
|
|
BEGIN TRY
|
|
|
- SELECT @getStatSQL = N'USE ' + @dbName + '; SELECT TOP 1 @record_count_Out = p.[rows] FROM [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss INNER JOIN sys.partitions AS p ON idss.objectID = p.[object_id] AND idss.partitionNumber = p.partition_number WHERE idss.updateDate IS NULL ' + CASE WHEN @Exec_Print = 0 THEN 'AND idss.printStatus = 0 ' ELSE '' END + ' AND idss.statsID = @statsID_In AND idss.dbID = @dbID_In AND idss.objectID = @statsobjectID_In'
|
|
|
+ SELECT @getStatSQL = N'USE ' + @dbName + '; SELECT TOP 1 @record_count_Out = p.[rows] FROM [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss INNER JOIN sys.partitions AS p ON idss.objectID = p.[object_id] AND idss.partitionNumber = p.partition_number WHERE idss.updateDate IS NULL ' + CASE WHEN @Exec_Print = 0 THEN 'AND idss.printStatus = 0 ' ELSE '' END + ' AND idss.statsID = @statsID_In AND idss.dbID = @dbID_In AND idss.objectID = @statsobjectID_In'
|
|
|
SET @getStatSQL_Param = N'@statsID_In int, @dbID_In int, @statsobjectID_In int, @record_count_Out bigint OUTPUT'
|
|
|
EXECUTE sp_executesql @getStatSQL, @getStatSQL_Param, @statsID_In = @statsID, @dbID_In = @dbID, @statsobjectID_In = @statsobjectID, @record_count_Out = @record_count OUTPUT;
|
|
|
END TRY
|
|
@@ -2701,7 +2774,16 @@ WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR ma
|
|
|
ELSE IF @stats_norecompute = 1 AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
|
|
|
SET @sqlcommand2 = @sqlcommand2 + N' WITH NORECOMPUTE'
|
|
|
|
|
|
- /* For list of incremental stats unsupported scenarios check https://msdn.microsoft.com/en-us/library/ms187348.aspx */
|
|
|
+ IF @maxDopRestriction IS NOT NULL
|
|
|
+ AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
|
|
|
+ AND UPPER(@sqlcommand2) LIKE '%WITH%'
|
|
|
+ SET @sqlcommand2 = @sqlcommand2 + N' ,MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
|
|
|
+ ELSE IF @maxDopRestriction IS NOT NULL
|
|
|
+ AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
|
|
|
+ AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
|
|
|
+ SET @sqlcommand2 = @sqlcommand2 + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
|
|
|
+
|
|
|
+ /* For list of incremental stats unsupported scenarios check http://docs.microsoft.com/sql/t-sql/statements/update-statistics-transact-sql */
|
|
|
IF @partitionCount > 1 AND @statsIncremental = 1 AND @has_filter = 0
|
|
|
BEGIN
|
|
|
IF UPPER(@sqlcommand2) LIKE '%WITH%'
|
|
@@ -3020,7 +3102,7 @@ CROSS APPLY (SELECT TOP 1 minIxDate = CASE WHEN defragDate IS NULL THEN CONVERT(
|
|
|
ELSE CONVERT(DATETIME, CONVERT(NVARCHAR, defragDate, 112)) END
|
|
|
FROM [dbo].[tbl_AdaptiveIndexDefrag_Working]
|
|
|
ORDER BY defragDate ASC, scanDate ASC) AS minDateIxCte
|
|
|
-WHERE dateTimeStart >= minIxDate
|
|
|
+WHERE dateTimeStart <= minIxDate
|
|
|
UNION ALL
|
|
|
SELECT TOP 100 percent [dbName]
|
|
|
,[objectName]
|
|
@@ -3040,7 +3122,7 @@ CROSS APPLY (SELECT TOP 1 minStatDate = CASE WHEN updateDate IS NULL THEN CONVER
|
|
|
ELSE CONVERT(DATETIME, CONVERT(NVARCHAR, updateDate, 112)) END
|
|
|
FROM [dbo].[tbl_AdaptiveIndexDefrag_Stats_Working]
|
|
|
ORDER BY updateDate ASC, scanDate ASC) AS minDateStatCte
|
|
|
-WHERE dateTimeStart >= minStatDate
|
|
|
+WHERE dateTimeStart <= minStatDate
|
|
|
ORDER BY dateTimeEnd ASC
|
|
|
GO
|
|
|
|
|
@@ -3052,7 +3134,7 @@ GO
|
|
|
CREATE PROCEDURE usp_AdaptiveIndexDefrag_PurgeLogs @daystokeep smallint = 90
|
|
|
AS
|
|
|
/*
|
|
|
-usp_AdaptiveIndexDefrag_PurgeLogs.sql - [email protected] (http://blogs.msdn.com/b/blogdoezequiel/)
|
|
|
+usp_AdaptiveIndexDefrag_PurgeLogs.sql - [email protected] (http://aka.ms/AID)
|
|
|
|
|
|
Purge log tables to avoid indefinite growth.
|
|
|
Default is data older than 90 days.
|
|
@@ -3079,7 +3161,7 @@ GO
|
|
|
CREATE PROCEDURE usp_AdaptiveIndexDefrag_CurrentExecStats @dbname NVARCHAR(255) = NULL
|
|
|
AS
|
|
|
/*
|
|
|
-usp_AdaptiveIndexDefrag_CurrentExecStats.sql - [email protected] (http://blogs.msdn.com/b/blogdoezequiel/)
|
|
|
+usp_AdaptiveIndexDefrag_CurrentExecStats.sql - [email protected] (http://aka.ms/AID)
|
|
|
|
|
|
Allows monitoring of what has been done so far in the defrag loop.
|
|
|
|
|
@@ -3168,7 +3250,7 @@ CREATE PROCEDURE usp_AdaptiveIndexDefrag_Exceptions @exceptionMask_DB NVARCHAR(2
|
|
|
@exceptionMask_indexes NVARCHAR(500) = NULL
|
|
|
AS
|
|
|
/*
|
|
|
-usp_AdaptiveIndexDefrag_Exceptions.sql - [email protected] (http://blogs.msdn.com/b/blogdoezequiel/)
|
|
|
+usp_AdaptiveIndexDefrag_Exceptions.sql - [email protected] (http://aka.ms/AID)
|
|
|
|
|
|
To insert info into the Exceptions table, use the following guidelines:
|
|
|
For @exceptionMask_DB, enter only one database name at a time.
|