usp_AdaptiveIndexDefrag.sql 186 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002100310041005100610071008100910101011101210131014101510161017101810191020102110221023102410251026102710281029103010311032103310341035103610371038103910401041104210431044104510461047104810491050105110521053105410551056105710581059106010611062106310641065106610671068106910701071107210731074107510761077107810791080108110821083108410851086108710881089109010911092109310941095109610971098109911001101110211031104110511061107110811091110111111121113111411151116111711181119112011211122112311241125112611271128112911301131113211331134113511361137113811391140114111421143114411451146114711481149115011511152115311541155115611571158115911601161116211631164116511661167116811691170117111721173117411751176117711781179118011811182118311841185118611871188118911901191119211931194119511961197119811991200120112021203120412051206120712081209121012111212121312141215121612171218121912201221122212231224122512261227122812291230123112321233123412351236123712381239124012411242124312441245124612471248124912501251125212531254125512561257125812591260126112621263126412651266126712681269127012711272127312741275127612771278127912801281128212831284128512861287128812891290129112921293129412951296129712981299130013011302130313041305130613071308130913101311131213131314131513161317131813191320132113221323132413251326132713281329133013311332133313341335133613371338133913401341134213431344134513461347134813491350135113521353135413551356135713581359136013611362136313641365136613671368136913701371137213731374137513761377137813791380138113821383138413851386138713881389139013911392139313941395139613971398139914001401140214031404140514061407140814091410141114121413141414151416141714181419142014211422142314241425142614271428142914301431143214331434143514361437143814391440144114421443144414451446144714481449145014511452145314541455145614571458145914601461146214631464146514661467146814691470147114721473147414751476147714781479148014811482148314841485148614871488148914901491149214931494149514961497149814991500150115021503150415051506150715081509151015111512151315141515151615171518151915201521152215231524152515261527152815291530153115321533153415351536153715381539154015411542154315441545154615471548154915501551155215531554155515561557155815591560156115621563156415651566156715681569157015711572157315741575157615771578157915801581158215831584158515861587158815891590159115921593159415951596159715981599160016011602160316041605160616071608160916101611161216131614161516161617161816191620162116221623162416251626162716281629163016311632163316341635163616371638163916401641164216431644164516461647164816491650165116521653165416551656165716581659166016611662166316641665166616671668166916701671167216731674167516761677167816791680168116821683168416851686168716881689169016911692169316941695169616971698169917001701170217031704170517061707170817091710171117121713171417151716171717181719172017211722172317241725172617271728172917301731173217331734173517361737173817391740174117421743174417451746174717481749175017511752175317541755175617571758175917601761176217631764176517661767176817691770177117721773177417751776177717781779178017811782178317841785178617871788178917901791179217931794179517961797179817991800180118021803180418051806180718081809181018111812181318141815181618171818181918201821182218231824182518261827182818291830183118321833183418351836183718381839184018411842184318441845184618471848184918501851185218531854185518561857185818591860186118621863186418651866186718681869187018711872187318741875187618771878187918801881188218831884188518861887188818891890189118921893189418951896189718981899190019011902190319041905190619071908190919101911191219131914191519161917191819191920192119221923192419251926192719281929193019311932193319341935193619371938193919401941194219431944194519461947194819491950195119521953195419551956195719581959196019611962196319641965196619671968196919701971197219731974197519761977197819791980198119821983198419851986198719881989199019911992199319941995199619971998199920002001200220032004200520062007200820092010201120122013201420152016201720182019202020212022202320242025202620272028202920302031203220332034203520362037203820392040204120422043204420452046204720482049205020512052205320542055205620572058205920602061206220632064206520662067206820692070207120722073207420752076207720782079208020812082208320842085208620872088208920902091209220932094209520962097209820992100210121022103210421052106210721082109211021112112211321142115211621172118211921202121212221232124212521262127212821292130213121322133213421352136213721382139214021412142214321442145214621472148214921502151215221532154215521562157215821592160216121622163216421652166216721682169217021712172217321742175217621772178217921802181218221832184218521862187218821892190219121922193219421952196219721982199220022012202220322042205220622072208220922102211221222132214221522162217221822192220222122222223222422252226222722282229223022312232223322342235223622372238223922402241224222432244224522462247224822492250225122522253225422552256225722582259226022612262226322642265226622672268226922702271227222732274227522762277227822792280228122822283228422852286228722882289229022912292229322942295229622972298229923002301230223032304230523062307230823092310231123122313231423152316231723182319232023212322232323242325232623272328232923302331233223332334233523362337233823392340234123422343234423452346234723482349235023512352235323542355235623572358235923602361236223632364236523662367236823692370237123722373237423752376237723782379238023812382238323842385238623872388238923902391239223932394239523962397239823992400240124022403240424052406240724082409241024112412241324142415241624172418241924202421242224232424242524262427242824292430243124322433243424352436243724382439244024412442244324442445244624472448244924502451245224532454245524562457245824592460246124622463246424652466246724682469247024712472247324742475247624772478247924802481248224832484248524862487248824892490249124922493249424952496249724982499250025012502250325042505250625072508250925102511251225132514251525162517251825192520252125222523252425252526252725282529253025312532253325342535253625372538253925402541254225432544254525462547254825492550255125522553255425552556255725582559256025612562256325642565256625672568256925702571257225732574257525762577257825792580258125822583258425852586258725882589259025912592259325942595259625972598259926002601260226032604260526062607260826092610261126122613261426152616261726182619262026212622262326242625262626272628262926302631263226332634263526362637263826392640264126422643264426452646264726482649265026512652265326542655265626572658265926602661266226632664266526662667266826692670267126722673267426752676267726782679268026812682268326842685268626872688268926902691269226932694269526962697269826992700270127022703270427052706270727082709271027112712271327142715271627172718271927202721272227232724272527262727272827292730273127322733273427352736273727382739274027412742274327442745274627472748274927502751275227532754275527562757275827592760276127622763276427652766276727682769277027712772277327742775277627772778277927802781278227832784278527862787278827892790279127922793279427952796279727982799280028012802280328042805280628072808280928102811281228132814281528162817281828192820282128222823282428252826282728282829283028312832283328342835283628372838283928402841284228432844284528462847284828492850285128522853285428552856285728582859286028612862286328642865286628672868286928702871287228732874287528762877287828792880288128822883288428852886288728882889289028912892289328942895289628972898289929002901290229032904290529062907290829092910291129122913291429152916291729182919292029212922292329242925292629272928292929302931293229332934293529362937293829392940294129422943294429452946294729482949295029512952295329542955295629572958295929602961296229632964296529662967296829692970297129722973297429752976297729782979298029812982298329842985298629872988298929902991299229932994299529962997299829993000300130023003300430053006300730083009301030113012301330143015301630173018301930203021302230233024302530263027302830293030303130323033303430353036303730383039304030413042304330443045304630473048304930503051305230533054305530563057305830593060306130623063306430653066306730683069307030713072307330743075307630773078307930803081308230833084308530863087308830893090309130923093309430953096309730983099310031013102310331043105310631073108310931103111311231133114311531163117311831193120312131223123312431253126312731283129313031313132313331343135313631373138313931403141314231433144314531463147314831493150315131523153315431553156315731583159316031613162316331643165316631673168316931703171317231733174317531763177317831793180318131823183318431853186318731883189319031913192319331943195319631973198319932003201320232033204320532063207320832093210321132123213321432153216321732183219322032213222322332243225322632273228322932303231323232333234323532363237323832393240324132423243324432453246324732483249325032513252325332543255325632573258325932603261326232633264326532663267326832693270327132723273327432753276327732783279328032813282328332843285328632873288328932903291329232933294329532963297329832993300330133023303330433053306330733083309331033113312331333143315331633173318331933203321332233233324332533263327
  1. -- If you are using AdaptiveIndexDefrag together with the maintenance plans in http://blogs.msdn.com/b/blogdoezequiel/archive/2012/09/18/about-maintenance-plans-grooming-sql-server.aspx
  2. -- please note that the job that runs AdaptiveIndexDefrag is expecting msdb. As such, change the database context accordingly.
  3. -- For deployment in Azure SQL Database, remove or comment the USE statement below.
  4. USE msdb
  5. GO
  6. SET NOCOUNT ON;
  7. DECLARE @deploymode bit
  8. SET @deploymode = 0 /* 0 = Upgrade from immediately previous version, preserving all historic data;
  9. 1 = Rewrite all objects, disregarding historic data */
  10. /* Scroll down to line 429 to the see notes, disclaimers, and licensing information */
  11. RAISERROR('Droping existing objects', 0, 42) WITH NOWAIT;
  12. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_CurrentExecStats')
  13. DROP VIEW vw_CurrentExecStats
  14. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_ErrLst30Days')
  15. DROP VIEW vw_ErrLst30Days
  16. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_LastRun_Log')
  17. DROP VIEW vw_LastRun_Log
  18. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_ErrLst24Hrs')
  19. DROP VIEW vw_ErrLst24Hrs
  20. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_AvgSamplingLst30Days')
  21. DROP VIEW vw_AvgSamplingLst30Days
  22. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_AvgTimeLst30Days ')
  23. DROP VIEW vw_AvgTimeLst30Days
  24. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_AvgFragLst30Days')
  25. DROP VIEW vw_AvgFragLst30Days
  26. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_AvgLargestLst30Days')
  27. DROP VIEW vw_AvgLargestLst30Days
  28. IF EXISTS(SELECT [object_id] FROM sys.views WHERE [name] = 'vw_AvgMostUsedLst30Days')
  29. DROP VIEW vw_AvgMostUsedLst30Days
  30. IF @deploymode = 0
  31. BEGIN
  32. RAISERROR('Preserving historic data', 0, 42) WITH NOWAIT;
  33. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log_old')
  34. BEGIN
  35. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_log', 'tbl_AdaptiveIndexDefrag_log_old';
  36. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_log_old.PK_AdaptiveIndexDefrag_log', N'PK_AdaptiveIndexDefrag_log_old', N'INDEX';
  37. END;
  38. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log_old')
  39. BEGIN
  40. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_Analysis_log', 'tbl_AdaptiveIndexDefrag_Analysis_log_old';
  41. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_Analysis_log_old.PK_AdaptiveIndexDefrag_Analysis_log', N'PK_AdaptiveIndexDefrag_Analysis_log_old', N'INDEX';
  42. END;
  43. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old')
  44. BEGIN
  45. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_Stats_log', 'tbl_AdaptiveIndexDefrag_Stats_log_old';
  46. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_Stats_log_old.PK_AdaptiveIndexDefrag_Stats_log', N'PK_AdaptiveIndexDefrag_Stats_log_old', N'INDEX';
  47. END;
  48. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions_old')
  49. BEGIN
  50. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_Exceptions', 'tbl_AdaptiveIndexDefrag_Exceptions_old';
  51. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_Exceptions_old.PK_AdaptiveIndexDefrag_Exceptions', N'PK_AdaptiveIndexDefrag_Exceptions_old', N'INDEX';
  52. END;
  53. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working_old')
  54. BEGIN
  55. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_Working', 'tbl_AdaptiveIndexDefrag_Working_old';
  56. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_Working_old.PK_AdaptiveIndexDefrag_Working', N'PK_AdaptiveIndexDefrag_Working_old', N'INDEX';
  57. END;
  58. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working_old')
  59. BEGIN
  60. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_Stats_Working', 'tbl_AdaptiveIndexDefrag_Stats_Working_old';
  61. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_Stats_Working_old.PK_AdaptiveIndexDefrag_Stats_Working', N'PK_AdaptiveIndexDefrag_Stats_Working_old', N'INDEX';
  62. END;
  63. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus') AND NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus_old')
  64. BEGIN
  65. EXEC sp_rename 'tbl_AdaptiveIndexDefrag_IxDisableStatus', 'tbl_AdaptiveIndexDefrag_IxDisableStatus_old';
  66. EXEC sp_rename N'tbl_AdaptiveIndexDefrag_IxDisableStatus_old.PK_AdaptiveIndexDefrag_IxDisableStatus', N'PK_AdaptiveIndexDefrag_IxDisableStatus_old', N'INDEX';
  67. END;
  68. END
  69. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log')
  70. DROP TABLE tbl_AdaptiveIndexDefrag_log;
  71. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log')
  72. DROP TABLE tbl_AdaptiveIndexDefrag_Analysis_log
  73. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log')
  74. DROP TABLE tbl_AdaptiveIndexDefrag_Stats_log;
  75. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions')
  76. DROP TABLE tbl_AdaptiveIndexDefrag_Exceptions;
  77. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working')
  78. DROP TABLE tbl_AdaptiveIndexDefrag_Working;
  79. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working')
  80. DROP TABLE tbl_AdaptiveIndexDefrag_Stats_Working;
  81. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus')
  82. DROP TABLE tbl_AdaptiveIndexDefrag_IxDisableStatus;
  83. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_AdaptiveIndexDefrag_PurgeLogs'), N'IsProcedure') = 1
  84. DROP PROCEDURE dbo.usp_AdaptiveIndexDefrag_PurgeLogs;
  85. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_AdaptiveIndexDefrag_Exceptions'), N'IsProcedure') = 1
  86. DROP PROCEDURE dbo.usp_AdaptiveIndexDefrag_Exceptions;
  87. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_AdaptiveIndexDefrag_Exclusions'), N'IsProcedure') = 1
  88. DROP PROCEDURE dbo.usp_AdaptiveIndexDefrag_Exclusions;
  89. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_CurrentExecStats'), N'IsProcedure') = 1
  90. DROP PROCEDURE dbo.usp_CurrentExecStats;
  91. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_AdaptiveIndexDefrag_CurrentExecStats'), N'IsProcedure') = 1
  92. DROP PROCEDURE dbo.usp_AdaptiveIndexDefrag_CurrentExecStats;
  93. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log')
  94. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_log
  95. (indexDefrag_id int identity(1,1) NOT NULL
  96. , dbID int NOT NULL
  97. , dbName NVARCHAR(128) NOT NULL
  98. , objectID int NOT NULL
  99. , objectName NVARCHAR(256) NULL
  100. , indexID int NOT NULL
  101. , indexName NVARCHAR(256) NULL
  102. , partitionNumber smallint
  103. , fragmentation float NOT NULL
  104. , page_count bigint NOT NULL
  105. , range_scan_count bigint NULL
  106. , fill_factor int NULL
  107. , dateTimeStart DATETIME NOT NULL
  108. , dateTimeEnd DATETIME NULL
  109. , durationSeconds int NULL
  110. , sqlStatement VARCHAR(4000) NULL
  111. , errorMessage VARCHAR(1000) NULL
  112. CONSTRAINT PK_AdaptiveIndexDefrag_log PRIMARY KEY CLUSTERED (indexDefrag_id));
  113. CREATE INDEX IX_tbl_AdaptiveIndexDefrag_log ON [dbo].[tbl_AdaptiveIndexDefrag_log] ([dbID], [objectID], [indexName], [dateTimeEnd]);
  114. CREATE INDEX IX_tbl_AdaptiveIndexDefrag_log_dateTimeEnd ON [dbo].[tbl_AdaptiveIndexDefrag_log] ([indexDefrag_id], [dateTimeEnd]);
  115. RAISERROR('tbl_AdaptiveIndexDefrag_log table created', 0, 42) WITH NOWAIT;
  116. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log')
  117. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_Analysis_log
  118. (analysis_id int identity(1,1) NOT NULL
  119. , [Operation] NCHAR(5)
  120. , dbID int NOT NULL
  121. , dbName NVARCHAR(128) NOT NULL
  122. , objectID int NOT NULL
  123. , objectName NVARCHAR(256) NULL
  124. , index_or_stat_ID int NOT NULL
  125. , partitionNumber smallint
  126. , dateTimeStart DATETIME NOT NULL
  127. , dateTimeEnd DATETIME NULL
  128. , durationSeconds int NULL
  129. , errorMessage VARCHAR(1000) NULL
  130. CONSTRAINT PK_AdaptiveIndexDefrag_Analysis_log PRIMARY KEY CLUSTERED (analysis_id));
  131. CREATE INDEX IX_tbl_AdaptiveIndexDefrag_Analysis_log_dateTimeEnd ON [dbo].[tbl_AdaptiveIndexDefrag_Analysis_log] ([analysis_id], [dateTimeEnd]);
  132. RAISERROR('tbl_AdaptiveIndexDefrag_Analysis_log table created', 0, 42) WITH NOWAIT;
  133. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions')
  134. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_Exceptions
  135. (dbID int NOT NULL
  136. , objectID int NOT NULL
  137. , indexID int NOT NULL
  138. , dbName NVARCHAR(128) NOT NULL
  139. , objectName NVARCHAR(256) NOT NULL
  140. , indexName NVARCHAR(256) NOT NULL
  141. , exclusionMask int NOT NULL
  142. /* Same as in msdb.dbo.sysschedules:
  143. 1=Sunday, 2=Monday, 4=Tuesday, 8=Wednesday, 16=Thursday, 32=Friday, 64=Saturday, 0=AllWeek, -1=Never
  144. For multiple days, sum the corresponding values*/
  145. CONSTRAINT PK_AdaptiveIndexDefrag_Exceptions PRIMARY KEY CLUSTERED (dbID, objectID, indexID));
  146. RAISERROR('tbl_AdaptiveIndexDefrag_Exceptions table created', 0, 42) WITH NOWAIT;
  147. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working')
  148. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_Working
  149. (dbID int
  150. , objectID int
  151. , indexID int
  152. , partitionNumber smallint
  153. , dbName NVARCHAR(128)
  154. , schemaName NVARCHAR(128) NULL
  155. , objectName NVARCHAR(256) NULL
  156. , indexName NVARCHAR(256) NULL
  157. , fragmentation float
  158. , page_count int
  159. , is_primary_key bit
  160. , fill_factor int
  161. , is_disabled bit
  162. , is_padded bit
  163. , is_hypothetical bit
  164. , has_filter bit
  165. , allow_page_locks bit
  166. , compression_type NVARCHAR(60) NULL -- 0 = NONE; 1 = ROW; 2 = PAGE; 3 = COLUMNSTORE; 4 = COLUMNSTORE_ARCHIVE
  167. , range_scan_count bigint NULL
  168. , record_count bigint
  169. , [type] tinyint -- 0 = Heap; 1 = Clustered; 2 = Nonclustered; 3 = XML; 4 = Spatial; 5 = Clustered columnstore; 6 = Nonclustered columnstore; 7 = Nonclustered hash
  170. , scanDate DATETIME
  171. , defragDate DATETIME NULL
  172. , printStatus bit DEFAULT(0) -- Used for loop control when printing the SQL commands.
  173. , exclusionMask int DEFAULT(0)
  174. CONSTRAINT PK_AdaptiveIndexDefrag_Working PRIMARY KEY CLUSTERED(dbID, objectID, indexID, partitionNumber));
  175. RAISERROR('tbl_AdaptiveIndexDefrag_Working table created', 0, 42) WITH NOWAIT;
  176. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working')
  177. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  178. (dbID int
  179. , objectID int
  180. , statsID int
  181. , partitionNumber smallint
  182. , dbName NVARCHAR(128)
  183. , schemaName NVARCHAR(128) NULL
  184. , objectName NVARCHAR(256) NULL
  185. , statsName NVARCHAR(256)
  186. , [no_recompute] bit
  187. , [is_incremental] bit
  188. , scanDate DATETIME
  189. , updateDate DATETIME NULL
  190. , printStatus bit DEFAULT(0) -- Used for loop control when printing the SQL commands.
  191. CONSTRAINT PK_AdaptiveIndexDefrag_Stats_Working PRIMARY KEY CLUSTERED(dbID, objectID, statsID, partitionNumber));
  192. RAISERROR('tbl_AdaptiveIndexDefrag_Stats_Working table created', 0, 42) WITH NOWAIT;
  193. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log')
  194. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_Stats_log
  195. (statsUpdate_id int identity(1,1) NOT NULL
  196. , dbID int NOT NULL
  197. , dbName NVARCHAR(128) NULL
  198. , objectID int NULL
  199. , objectName NVARCHAR(256) NULL
  200. , statsID int NOT NULL
  201. , statsName NVARCHAR(256) NULL
  202. , partitionNumber smallint
  203. , [rows] bigint
  204. , rows_sampled bigint
  205. , modification_counter bigint
  206. , [no_recompute] bit
  207. , dateTimeStart DATETIME NOT NULL
  208. , dateTimeEnd DATETIME NULL
  209. , durationSeconds int NULL
  210. , sqlStatement VARCHAR(4000) NULL
  211. , errorMessage VARCHAR(1000) NULL
  212. CONSTRAINT PK_AdaptiveIndexDefrag_Stats_log PRIMARY KEY CLUSTERED (statsUpdate_id));
  213. CREATE INDEX IX_tbl_AdaptiveIndexDefrag_Stats_log ON [dbo].[tbl_AdaptiveIndexDefrag_Stats_log] ([dbID], [objectID], [statsName], [dateTimeEnd]);
  214. RAISERROR('tbl_AdaptiveIndexDefrag_Stats_log table created', 0, 42) WITH NOWAIT;
  215. IF NOT EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus')
  216. CREATE TABLE dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus
  217. (disable_id int identity(1,1) NOT NULL
  218. , dbID int NOT NULL
  219. , objectID int NOT NULL
  220. , indexID int NOT NULL
  221. , [is_disabled] bit
  222. , dateTimeChange DATETIME NOT NULL
  223. CONSTRAINT PK_AdaptiveIndexDefrag_IxDisableStatus PRIMARY KEY CLUSTERED (disable_id));
  224. RAISERROR('tbl_AdaptiveIndexDefrag_IxDisableStatus table created', 0, 42) WITH NOWAIT;
  225. IF @deploymode = 0
  226. BEGIN
  227. RAISERROR('Copying old data...', 0, 42) WITH NOWAIT;
  228. BEGIN TRY
  229. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log_old')
  230. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_log ([dbID],[dbName],[objectID],[objectName]
  231. ,[indexID],[indexName],[partitionNumber],[fragmentation],[page_count]
  232. ,[range_scan_count],[fill_factor],[dateTimeStart],[dateTimeEnd]
  233. ,[durationSeconds],[sqlStatement],[errorMessage])
  234. SELECT [dbID],[dbName],[objectID],[objectName],[indexID]
  235. ,[indexName],[partitionNumber],[fragmentation],[page_count]
  236. ,[range_scan_count],[fill_factor],[dateTimeStart],[dateTimeEnd]
  237. ,[durationSeconds],[sqlStatement],[errorMessage]
  238. FROM dbo.tbl_AdaptiveIndexDefrag_log_old;
  239. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log_old')
  240. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Analysis_log ([Operation],[dbID],[dbName],[objectID],[objectName]
  241. ,[index_or_stat_ID],[partitionNumber],[dateTimeStart],[dateTimeEnd]
  242. ,[durationSeconds],[errorMessage])
  243. SELECT [Operation],[dbID],[dbName],[objectID],[objectName],[index_or_stat_ID]
  244. ,[partitionNumber],[dateTimeStart],[dateTimeEnd]
  245. ,[durationSeconds],[errorMessage]
  246. FROM dbo.tbl_AdaptiveIndexDefrag_Analysis_log_old;
  247. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old')
  248. BEGIN
  249. IF (SELECT COUNT(sc.column_id) FROM sys.tables st INNER JOIN sys.columns sc ON st.[object_id] = sc.[object_id] WHERE (sc.[name] = 'partitionNumber' OR sc.[name] = 'rows' OR sc.[name] = 'rows_sampled' OR sc.[name] = 'modification_counter') AND st.[name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old') = 4
  250. BEGIN
  251. EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log ([dbID],[dbName],[objectID],[objectName],[statsID],[statsName],[partitionNumber],[rows],rows_sampled,modification_counter,[no_recompute],[dateTimeStart],[dateTimeEnd],[durationSeconds],[sqlStatement],[errorMessage])
  252. SELECT [dbID],[dbName],[objectID],[objectName],[statsID],[statsName],[partitionNumber],[rows],rows_sampled,modification_counter,[no_recompute],[dateTimeStart],[dateTimeEnd],[durationSeconds],[sqlStatement],[errorMessage]
  253. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log_old;')
  254. END
  255. ELSE IF (SELECT COUNT(sc.column_id) FROM sys.tables st INNER JOIN sys.columns sc ON st.[object_id] = sc.[object_id] WHERE sc.[name] = 'partitionNumber' AND st.[name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old') = 1
  256. AND (SELECT COUNT(sc.column_id) FROM sys.tables st INNER JOIN sys.columns sc ON st.[object_id] = sc.[object_id] WHERE (sc.[name] = 'rows' OR sc.[name] = 'rows_sampled' OR sc.[name] = 'modification_counter') AND st.[name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old') = 0
  257. BEGIN
  258. EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log ([dbID],[dbName],[objectID],[objectName],[statsID],[statsName],[partitionNumber],[rows],rows_sampled,modification_counter,[no_recompute],[dateTimeStart],[dateTimeEnd],[durationSeconds],[sqlStatement],[errorMessage])
  259. SELECT [dbID],[dbName],[objectID],[objectName],[statsID],[statsName],[partitionNumber],-1,-1,-1,[no_recompute],[dateTimeStart],[dateTimeEnd],[durationSeconds],[sqlStatement],[errorMessage]
  260. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log_old;')
  261. END
  262. ELSE
  263. BEGIN
  264. EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log ([dbID],[dbName],[objectID],[objectName],[statsID],[statsName],[partitionNumber],[rows],rows_sampled,modification_counter,[no_recompute],[dateTimeStart],[dateTimeEnd],[durationSeconds],[sqlStatement],[errorMessage])
  265. SELECT [dbID],[dbName],[objectID],[objectName],[statsID],[statsName],1,-1,-1,-1,[no_recompute],[dateTimeStart],[dateTimeEnd],[durationSeconds],[sqlStatement],[errorMessage]
  266. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log_old;')
  267. END
  268. END
  269. 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')
  270. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Exceptions ([dbID],[objectID],[indexID],[dbName],[objectName],[indexName],[exclusionMask])
  271. SELECT [dbID],[objectID],[indexID],[dbName],[objectName],[indexName],[exclusionMask]
  272. FROM dbo.tbl_AdaptiveIndexDefrag_Exceptions_old;
  273. 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')
  274. BEGIN
  275. 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')
  276. BEGIN
  277. 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])
  278. 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]
  279. FROM dbo.tbl_AdaptiveIndexDefrag_Working_old;')
  280. END
  281. ELSE
  282. BEGIN
  283. 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])
  284. 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]
  285. FROM dbo.tbl_AdaptiveIndexDefrag_Working_old;')
  286. END
  287. END
  288. 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')
  289. BEGIN
  290. 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] = 'partitionNumber' OR sc.[name] = 'is_incremental') AND st.[name] = 'tbl_AdaptiveIndexDefrag_Stats_Working_old')
  291. BEGIN
  292. EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_Working ([dbID],[objectID],[statsID],[dbName],[schemaName],[objectName],[statsName],[partitionNumber],[no_recompute],[is_incremental],[scanDate],[updateDate],[printStatus])
  293. SELECT [dbID],[objectID],[statsID],[dbName],[schemaName],[objectName],[statsName],[partitionNumber],[no_recompute],[is_incremental],[scanDate],[updateDate],[printStatus]
  294. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working_old;')
  295. END
  296. ELSE
  297. BEGIN
  298. EXEC ('INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_Working ([dbID],[objectID],[statsID],[dbName],[schemaName],[objectName],[statsName],[partitionNumber],[no_recompute],[is_incremental],[scanDate],[updateDate],[printStatus])
  299. SELECT [dbID],[objectID],[statsID],[dbName],[schemaName],[objectName],[statsName],1,[no_recompute],0,[scanDate],[updateDate],[printStatus]
  300. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working_old;')
  301. END
  302. END
  303. IF EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus') AND EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus_old')
  304. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus ([dbID],[objectID],[indexID],[is_disabled],dateTimeChange)
  305. SELECT [dbID],[objectID],[indexID],[is_disabled],dateTimeChange
  306. FROM dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus_old;
  307. END TRY
  308. BEGIN CATCH
  309. RAISERROR('Could not copy old data back. Check for any previous errors.', 15, 42) WITH NOWAIT;
  310. RETURN
  311. END CATCH
  312. RAISERROR('Done copying old data...', 0, 42) WITH NOWAIT;
  313. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log_old')
  314. BEGIN
  315. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_log_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_log)
  316. DROP TABLE tbl_AdaptiveIndexDefrag_log_old
  317. END;
  318. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log_old')
  319. BEGIN
  320. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Analysis_log_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Analysis_log)
  321. DROP TABLE tbl_AdaptiveIndexDefrag_Analysis_log_old
  322. END;
  323. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old')
  324. BEGIN
  325. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log)
  326. DROP TABLE tbl_AdaptiveIndexDefrag_Stats_log_old
  327. END;
  328. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions_old')
  329. BEGIN
  330. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Exceptions_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Exceptions)
  331. DROP TABLE tbl_AdaptiveIndexDefrag_Exceptions_old
  332. END;
  333. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working_old')
  334. BEGIN
  335. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Working_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Working)
  336. DROP TABLE tbl_AdaptiveIndexDefrag_Working_old
  337. END;
  338. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working_old')
  339. BEGIN
  340. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working)
  341. DROP TABLE tbl_AdaptiveIndexDefrag_Stats_Working_old
  342. END;
  343. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus_old')
  344. BEGIN
  345. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus_old) = (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus)
  346. DROP TABLE tbl_AdaptiveIndexDefrag_IxDisableStatus_old
  347. END;
  348. IF EXISTS (SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_Working_old')
  349. OR EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_log_old')
  350. OR EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Analysis_log_old')
  351. OR EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Stats_log_old')
  352. OR EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Exceptions_old')
  353. OR EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_Working_old')
  354. OR EXISTS(SELECT [object_id] FROM sys.tables WHERE [name] = 'tbl_AdaptiveIndexDefrag_IxDisableStatus_old')
  355. BEGIN
  356. RAISERROR('Data mismatch. Keeping some or all old tables as <tablename_old>.', 0, 42) WITH NOWAIT;
  357. END
  358. ELSE
  359. BEGIN
  360. RAISERROR('Removed old tables...', 0, 42) WITH NOWAIT;
  361. END
  362. END;
  363. GO
  364. ------------------------------------------------------------------------------------------------------------------------------
  365. IF OBJECTPROPERTY(OBJECT_ID('dbo.usp_AdaptiveIndexDefrag'), N'IsProcedure') = 1
  366. BEGIN
  367. DROP PROCEDURE dbo.usp_AdaptiveIndexDefrag;
  368. PRINT 'Procedure usp_AdaptiveIndexDefrag dropped';
  369. END;
  370. GO
  371. CREATE PROCEDURE dbo.usp_AdaptiveIndexDefrag
  372. @Exec_Print bit = 1
  373. /* 1 = execute commands; 0 = print commands only */
  374. , @printCmds bit = 0
  375. /* 1 = print commands; 0 = do not print commands */
  376. , @outputResults bit = 0
  377. /* 1 = output fragmentation information;
  378. 0 = do not output */
  379. , @debugMode bit = 0
  380. /* display some useful comments to help determine if/where issues occur
  381. 1 = display debug comments;
  382. 0 = do not display debug comments*/
  383. , @timeLimit int = 480 /* defaults to 8 hours */
  384. /* Optional time limitation; expressed in minutes */
  385. , @dbScope NVARCHAR(256) = NULL
  386. /* Option to specify a database name; NULL will return all */
  387. , @tblName NVARCHAR(1000) = NULL -- schema.table_name
  388. /* Option to specify a table name; NULL will return all */
  389. , @defragOrderColumn NVARCHAR(20) = 'range_scan_count'
  390. /* Valid options are: range_scan_count, fragmentation, page_count */
  391. , @defragSortOrder NVARCHAR(4) = 'DESC'
  392. /* Valid options are: ASC, DESC */
  393. , @forceRescan bit = 0
  394. /* Whether to force a rescan of indexes into the tbl_AdaptiveIndexDefrag_Working table or not;
  395. 1 = force, 0 = use existing scan when available, used to continue where previous run left off */
  396. , @defragDelay CHAR(8) = '00:00:05'
  397. /* time to wait between defrag commands */
  398. , @ixtypeOption bit = NULL
  399. /* NULL = all indexes will be defragmented; 1 = only Clustered indexes will be defragmented; 0 = only Non-Clustered indexes will be defragmented (includes XML and Spatial); */
  400. , @minFragmentation float = 5.0
  401. /* in percent, will not defrag if fragmentation is less than specified */
  402. , @rebuildThreshold float = 30.0
  403. /* in percent, greater than @rebuildThreshold will result in rebuild instead of reorg */
  404. , @rebuildThreshold_cs float = 10.0
  405. /* in percent, greater than @rebuildThreshold_cs will result in rebuild the columnstore index */
  406. , @minPageCount int = 8
  407. /* Recommended is defrag when index is at least > 1 extent (8 pages) */
  408. , @maxPageCount int = NULL
  409. /* NULL = no limit */
  410. , @fillfactor bit = 1
  411. /* 1 = original from when the index was created or last defraged;
  412. 0 = default fillfactor */
  413. , @scanMode VARCHAR(10) = N'LIMITED'
  414. /* Options are LIMITED, SAMPLED, and DETAILED */
  415. , @onlineRebuild bit = 0
  416. /* 1 = online rebuild; 0 = offline rebuild; only in Enterprise Edition */
  417. , @resumableRebuild bit = 0
  418. /* 1 = resumable rebuild; 0 = normal rebuild */
  419. , @sortInTempDB bit = 0
  420. /* 1 = perform sort operation in TempDB; 0 = perform sort operation in the indexes database */
  421. , @maxDopRestriction tinyint = NULL
  422. /* Option to restrict the number of processors for both index and statistics operations; only in Enterprise Edition */
  423. , @updateStats bit = 1
  424. /* 1 = updates stats when reorganizing; 0 = does not update stats when reorganizing */
  425. , @updateStatsWhere bit = 0
  426. /* 1 = updates only index related stats; 0 = updates all stats in table */
  427. , @statsSample NVARCHAR(8) = NULL
  428. /* Valid options are: NULL, <percentage>, FULLSCAN, and RESAMPLE */
  429. , @persistStatsSample bit = NULL
  430. /* 1 = turns ON fixed sampling rate; 0 = turns OFF fixed sampling rate; NULL = do nothing */
  431. , @statsThreshold float = NULL
  432. /* Valid options are: NULL to use default stats sample method (same as TF2371), float number greater or equal to 0.001 and less than 100 to use custom stats sample */
  433. , @statsMinRows bigint = NULL
  434. /* Valid options are: NULL , integer number that sets the min number of rows a table has to have to be considered for @statsThreshold use */
  435. , @ix_statsnorecompute bit = 0
  436. /* 1 = STATISTICS_NORECOMPUTE on; 0 = default which is with STATISTICS_NORECOMPUTE off */
  437. , @statsIncremental bit = NULL
  438. /* NULL = Keep server setting; 1 = Enable auto create statistics with Incremental; 0 = Disable auto create statistics with Incremental */
  439. , @dealMaxPartition bit = 0
  440. /* 0 = only right-most partition; 1 = exclude right-most populated partition; NULL = do not exclude; see notes for caveats; only in Enterprise Edition */
  441. , @dealLOB bit = 0
  442. /* 0 = compact LOBs when reorganizing (default behavior); 1 = does not compact LOBs when reorganizing */
  443. , @ignoreDropObj bit = 0
  444. /* 0 = includes errors about objects that have been dropped since the defrag cycle began (default behavior);
  445. 1 = for error reporting purposes, ignores the fact that objects have been dropped since the defrag cycle began */
  446. , @disableNCIX bit = 0
  447. /* 0 = does NOT disable non-clustered indexes prior to a rebuild;
  448. 1 = disables non-clustered indexes prior to a rebuild, if the database is not being replicated (space saving feature) */
  449. , @offlinelocktimeout int = -1
  450. /* -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 */
  451. , @onlinelocktimeout int = 5
  452. /* 5 = (default) indicates a time-out period for locks to wait at low priority, expressed in minutes; this is valid from SQL Server 2014 onwards */
  453. , @abortAfterwait bit = 1
  454. /* NULL = (default) After lock timeout occurs, continue waiting for the lock with normal (regular) priority;
  455. 0 = Kill all user transactions that block the online index rebuild DDL operation so that the operation can continue.
  456. 1 = Exit the online index rebuild DDL operation currently being executed without taking any action.*/
  457. , @dealROWG bit = 0
  458. /* 0 = (default) compress closed rowgroups on columnstore.
  459. 1 = compress all rowgroups on columnstore, and not just closed ones.*/
  460. , @getBlobfrag bit = 0
  461. /* 0 = (default) exclude blobs from fragmentation scan.
  462. 1 = include blobs and off-row data when scanning for fragmentation.*/
  463. , @dataCompression NVARCHAR(4) = NULL
  464. /* NULL = (default) Keeps whatever compression setting exists for the object and partition;
  465. NONE = Forces no compression (and removes compression if set);
  466. PAGE = Forces page compression;
  467. ROW = Forces row compression.*/
  468. AS
  469. /*
  470. usp_AdaptiveIndexDefrag.sql - [email protected] (http://aka.ms/AID)
  471. v1 inspired by Michelle Ufford (http://sqlfool.com)
  472. PURPOSE: Intelligent defrag on one or more indexes and statistics update for one or more databases.
  473. DISCLAIMER:
  474. This code is not supported under any Microsoft standard support program or service.
  475. This code and information are provided "AS IS" without warranty of any kind, either expressed or implied.
  476. The entire risk arising out of the use or performance of the script and documentation remains with you.
  477. Furthermore, Microsoft, the author or "Blog do Ezequiel" team shall not be liable for any damages you may sustain by using this information, whether direct,
  478. indirect, special, incidental or consequential, including, without limitation, damages for loss of business profits, business interruption, loss of business information
  479. or other pecuniary loss even if it has been advised of the possibility of such damages.
  480. Read all the implementation and usage notes thoroughly.
  481. CHANGE LOG:
  482. See https://github.com/microsoft/tigertoolbox/blob/master/AdaptiveIndexDefrag/CHANGELOG.txt
  483. IMPORTANT:
  484. Execute in the database context of where you created the log and working tables.
  485. ALL parameters are optional. If not specified, the defaults for each parameter are used.
  486. @Exec_Print 1 = execute the SQL code generated by this SP;
  487. 0 = print commands only
  488. @printCmds 1 = print commands to screen;
  489. 0 = do not print commands
  490. @outputResults 1 = output fragmentation information after run completes;
  491. 0 = do not output fragmentation information
  492. @debugMode 1 = display debug comments;
  493. 0 = do not display debug comments
  494. @timeLimit Limits how much time can be spent performing index defrags; expressed in minutes.
  495. NOTE: The time limit is checked BEFORE an index defrag begins, thus a long index defrag can exceed the time limit.
  496. @dbScope Specify specific database name to defrag; if not specified, all non-system databases plus msdb and model will be defragmented.
  497. @tblName Specify if you only want to defrag indexes for a specific table, format = schema.table_name; if not specified, all tables will be defragmented.
  498. @defragOrderColumn Defines how to prioritize the order of defrags. Only used if @Exec_Print = 1.
  499. range_scan_count = count of range and table scans on the index; this is what can benefit the most from defragmentation;
  500. fragmentation = amount of fragmentation in the index;
  501. page_count = number of pages in the index; bigger indexes can take longer to defrag and thus generate more contention; may want to start with these;
  502. @defragSortOrder The sort order of the ORDER BY clause on the above query on how to prioritize the order of defrags.
  503. ASC (ascending)
  504. DESC (descending) is the default.
  505. @forceRescan Action on index rescan. If = 0, a rescan will not occur until all indexes have been defragmented. This can span multiple executions.
  506. 1 = force a rescan
  507. 0 = use previous scan, if there are indexes left to defrag
  508. @defragDelay Time to wait between defrag commands; gives the server a breathe between runs
  509. @ixtypeOption NULL = all indexes will be defragmented;
  510. 1 = only Clustered indexes will be defragmented;
  511. 0 = only Non-Clustered indexes will be defragmented (includes XML and Spatial Indexes);
  512. @minFragmentation Defaults to 5%, will not defrag if fragmentation is less.
  513. Refer to http://docs.microsoft.com/sql/relational-databases/indexes/reorganize-and-rebuild-indexes
  514. @rebuildThreshold Defaults to 30%. greater than 30% will result in rebuild instead of reorganize.
  515. Refer to http://docs.microsoft.com/sql/relational-databases/indexes/reorganize-and-rebuild-indexes
  516. @rebuildThreshold_csDefaults to 10%. Greater than 10% will result in columnstore rebuild.
  517. Refer to http://docs.microsoft.com/sql/relational-databases/sql-server-index-design-guide
  518. @minPageCount Specifies how many pages must exist in an index in order to be considered for a defrag. Default to an extent.
  519. Refer to http://docs.microsoft.com/sql/relational-databases/indexes/reorganize-and-rebuild-indexes
  520. NOTE: The @minPageCount will restrict the indexes that are stored in tbl_AdaptiveIndexDefrag_Working table and can render other options inoperative.
  521. @maxPageCount Specifies the maximum number of pages that can exist in an index and still be considered for a defrag.
  522. Useful for scheduling small indexes during business hours and large indexes for non-business hours.
  523. NOTE: The @maxPageCount will restrict the indexes selective for defrag;
  524. @fillfactor 1 = original from when the index was created or last defragmented;
  525. 0 = default fill factor
  526. @scanMode Specifies which scan mode to use to determine fragmentation levels. Options are:
  527. LIMITED = the fastest mode and scans the smallest number of pages.
  528. For an index, only the parent-level pages of the B-tree (that is, the pages above the leaf level) are scanned.
  529. For a heap, only the associated PFS and IAM pages are examined; the data pages of the heap are not scanned.
  530. Recommended for most cases.
  531. SAMPLED = returns statistics based on a 1 percent sample of all the pages in the index or heap.
  532. If the index or heap has fewer than 10,000 pages, DETAILED mode is used instead of SAMPLED.
  533. DETAILED = scans all pages and returns all statistics. Can cause performance issues.
  534. @onlineRebuild 1 = online rebuild if possible; only in Enterprise Edition;
  535. 0 = offline rebuild
  536. @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.
  537. If a sort operation is not required, or if the sort can be performed in memory, SORT_IN_TEMPDB is ignored.
  538. Enabling this option can result in faster defrags and prevent database file size inflation. Just have monitor TempDB closely.
  539. 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
  540. 1 = perform sort operation in TempDB
  541. 0 = perform sort operation in the indexes database
  542. @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.
  543. @updateStats 1 = updates stats when reorganizing;
  544. 0 = does not update stats when reorganizing
  545. @updateStatsWhere Update statistics within certain thresholds. Refer to http://docs.microsoft.com/sql/relational-databases/statistics/statistics
  546. 1 = updates only index related stats;
  547. 0 = updates all stats in entire table
  548. @statsSample NULL = perform a sample scan on the target table or indexed view. The database engine automatically computes the required sample size;
  549. <percentage> = perform a fixed percentage scan on the target table or indexed view. Valid values are integers between 1 and 100;
  550. FULLSCAN = all rows in table or view should be read to gather the statistics;
  551. RESAMPLE = statistics will be gathered using an inherited sampling ratio for all existing statistics including indexes
  552. @persistStatsSample Persist a specific statistics sampling rate (depends on version) if <percentage> or FULLSCAN needs to be used in @statsSample
  553. NULL = do nothing;
  554. 1 = turns ON fixed sampling rate;
  555. 0 = turns OFF fixed sampling rate
  556. @statsThreshold Custom threshold of changes needed to trigger update statistics, overriding default handling;
  557. NULL = assume default handling which is similar to TF2371;
  558. A float number greater or equal to 0.001 and less than 100 to use custom stats sample
  559. @statsMinRows Sets the min number of rows a table has to have to be considered for @statsThreshold use;
  560. NULL = use @statsThreshold (if set) for any size table;
  561. An integer number that sets the min number of rows a table has to have to be considered for @statsThreshold use
  562. @ix_statsnorecompute 1 = STATISTICS_NORECOMPUTE on will disable the auto update statistics.
  563. If you are dealing with stats update with a custom job (or even with this code by updating statistics), you may use this option;
  564. 0 = default which is with STATISTICS_NORECOMPUTE off
  565. @statsIncremental When Incremental is ON, the statistics created are per partition statistics.
  566. When OFF, the statistics tree is dropped and SQL Server re-computes the statistics. This setting overrides the database level INCREMENTAL property.
  567. Refer to http://docs.microsoft.com/sql/relational-databases/statistics/statistics
  568. NULL = Keep server setting;
  569. 1 = Enable auto create statistics with Incremental
  570. 0 = Disable auto create statistics with Incremental
  571. @dealMaxPartition If an index is partitioned, this option specifies whether to exclude the right-most populated partition, or act only on that same partition, excluding all others.
  572. Typically, this is the partition that is currently being written to in a sliding-window scenario.
  573. Enabling this feature may reduce contention. This may not be applicable in other types of partitioning scenarios.
  574. Non-partitioned indexes are unaffected by this option. Only in Enterprise Edition.
  575. 1 = exclude right-most populated partition
  576. 0 = only right-most populated partition (remember to verify @minPageCount, if partition is smaller than @minPageCount, it won't be considered)
  577. NULL = do not exclude any partitions
  578. @dealLOB Specifies that all pages that contain large object (LOB) data are compacted. The LOB data types are image, text, ntext, varchar(max), nvarchar(max), varbinary(max), and xml.
  579. Compacting this data can improve disk space use.
  580. Reorganizing a specified clustered index compacts all LOB columns that are contained in the clustered index.
  581. Reorganizing a non-clustered index compacts all LOB columns that are nonkey (included) columns in the index.
  582. 0 = compact LOBs when reorganizing (default behavior);
  583. 1 = does not compact LOBs when reorganizing
  584. @ignoreDropObj If a table or index is dropped after the defrag cycle has begun, you can choose to ignore those errors in the overall outcome,
  585. thus not showing a job as failed if the only errors present refer to dropped database objects.
  586. 0 = includes errors about objects that have been dropped since the defrag cycle began (default behavior);
  587. 1 = for error reporting purposes, ignores the fact that objects have been dropped since the defrag cycle began
  588. @disableNCIX If disk space is limited, it may be helpful to disable the non-clustered index before rebuilding it;
  589. When a non-clustered index is not disabled, the rebuild operation requires enough temporary disk space to store both the old and new index;
  590. However, by disabling and rebuilding a non-clustered index in separate transactions, the disk space made available by disabling the index can be reused by the subsequent rebuild or any other operation;
  591. No additional space is required except for temporary disk space for sorting; this is typically 20 percent of the index size;
  592. Does not disable indexes on partitioned tables when defragging a subset of existing partitions;
  593. Keeps track of whatever indexes were disabled by the defrag cycle. In case the defrag is cancelled, it will account for these disabled indexes in the next run.
  594. 0 = does NOT disable non-clustered indexes prior to a rebuild (default behavior);
  595. 1 = disables non-clustered indexes prior to a rebuild (space saving feature)
  596. @offlinelocktimeout As set in SET LOCK_TIMEOUT option
  597. Refer to http://docs.microsoft.com/sql/t-sql/statements/set-lock-timeout-transact-sql
  598. -1 = (default) indicates no time-out period
  599. Any other positive integer = sets the number of milliseconds that will pass before Microsoft SQL Server returns a locking error
  600. @onlinelocktimeout Indicates a time-out period for locks to wait at low priority, expressed in minutes; this is valid from SQL Server 2014 onwards
  601. @abortAfterwait If the online low priority lock timeout occurs, this will set the action to perform afterwards.
  602. NULL = (default) After lock timeout occurs, continue waiting for the lock with normal (regular) priority;
  603. 1 = Exit the online index rebuild DDL operation currently being executed without taking any action;
  604. 2 = Kill all user transactions that block the online index rebuild DDL operation so that the operation can continue.
  605. @dealROWG Set Columnstore reorg option to compress all rowgroups, and not just closed ones
  606. 0 = (default) compress closed rowgroups on columnstore.
  607. 1 = compress all rowgroups on columnstore, and not just closed ones.
  608. @getBlobfrag Indicates whether to exclude or include blobs from fragmentation scan.
  609. 0 = (default) exclude blobs from fragmentation scan.
  610. 1 = include blobs and off-row data when scanning for fragmentation.
  611. @dataCompression Sets specific compression options for all indexes.
  612. NULL = (default) Does not use the DATA_COMPRESSION keyword in index rebuild, keeping whatever compression setting exists.
  613. NONE = Index or specified partitions are not compressed.
  614. PAGE = Use page compression.
  615. ROW = Use row compression.
  616. -------------------------------------------------------
  617. Usage:
  618. EXEC dbo.usp_AdaptiveIndexDefrag
  619. or customize it like the example:
  620. EXEC dbo.usp_AdaptiveIndexDefrag
  621. @Exec_Print = 0
  622. , @printCmds = 1
  623. , @updateStats = 1
  624. , @updateStatsWhere = 1
  625. , @debugMode = 1
  626. , @outputResults = 1
  627. , @dbScope = 'AdventureWorks2008R2'
  628. , @forceRescan = 1
  629. , @maxDopRestriction = 2
  630. , @minPageCount = 8
  631. , @maxPageCount = NULL
  632. , @minFragmentation = 1
  633. , @rebuildThreshold = 1
  634. , @rebuildThreshold_cs = 1
  635. , @defragDelay = '00:00:05'
  636. , @defragOrderColumn = 'range_scan_count'
  637. , @dealMaxPartition = NULL
  638. , @disableNCIX = 1
  639. , @offlinelocktimeout = 180;
  640. */
  641. SET NOCOUNT ON;
  642. SET XACT_ABORT ON;
  643. SET QUOTED_IDENTIFIER ON;
  644. SET DATEFORMAT ymd;
  645. SET DEADLOCK_PRIORITY -10;
  646. -- Required so it can update stats on Indexed Views and Filtered Indexes
  647. SET ANSI_WARNINGS ON;
  648. SET ANSI_PADDING ON;
  649. SET ANSI_NULLS ON;
  650. SET ARITHABORT ON;
  651. SET CONCAT_NULL_YIELDS_NULL ON;
  652. SET NUMERIC_ROUNDABORT OFF;
  653. /* Find sql server version info */
  654. DECLARE @sqlmajorver int, @sqlminorver int, @sqlbuild int;
  655. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  656. SELECT @sqlminorver = CONVERT(int, (@@microsoftversion / 0x10000) & 0xff);
  657. SELECT @sqlbuild = CONVERT(int, @@microsoftversion & 0xffff);
  658. BEGIN
  659. BEGIN TRY
  660. /* Validating and normalizing options... */
  661. IF @debugMode = 1
  662. RAISERROR('Validating options...', 0, 42) WITH NOWAIT;
  663. IF @minFragmentation IS NULL OR @minFragmentation NOT BETWEEN 0.00 AND 100.0
  664. SET @minFragmentation = 5.0;
  665. IF @rebuildThreshold IS NULL OR @rebuildThreshold NOT BETWEEN 0.00 AND 100.0
  666. SET @rebuildThreshold = 30.0;
  667. IF @rebuildThreshold_cs IS NULL OR @rebuildThreshold_cs NOT BETWEEN 0.00 AND 100.0
  668. SET @rebuildThreshold_cs = 10.0;
  669. IF @statsThreshold IS NOT NULL AND @statsThreshold NOT BETWEEN 0.001 AND 100.0
  670. SET @statsThreshold = NULL;
  671. IF @timeLimit IS NULL
  672. SET @timeLimit = 480;
  673. IF @dataCompression IS NOT NULL AND UPPER(@dataCompression) NOT IN ('NONE','ROW','PAGE')
  674. SET @dataCompression = NULL;
  675. /* Validate if table name is fully qualified and database scope is set */
  676. IF @tblName IS NOT NULL AND @tblName NOT LIKE '%.%'
  677. BEGIN
  678. RAISERROR('WARNING: Table name must be fully qualified. Input format should be <schema>.<table_name>.', 15, 42) WITH NOWAIT;
  679. RETURN
  680. END;
  681. /* Validate if database scope is set when table name is also set */
  682. IF @tblName IS NOT NULL AND @dbScope IS NULL
  683. BEGIN
  684. RAISERROR('WARNING: A database scope must be set when using table names.', 15, 42) WITH NOWAIT;
  685. RETURN
  686. END;
  687. /* Validate if database scope exists */
  688. IF @dbScope IS NOT NULL AND LOWER(@dbScope) NOT IN (SELECT LOWER([name]) FROM sys.databases WHERE LOWER([name]) NOT IN ('master', 'tempdb', 'model', 'reportservertempdb','semanticsdb') AND is_distributor = 0)
  689. BEGIN
  690. RAISERROR('WARNING: The database in scope does not exist or is a system database.', 15, 42) WITH NOWAIT;
  691. RETURN
  692. END;
  693. /* Validate offline lock timeout settings */
  694. IF @offlinelocktimeout IS NULL OR ISNUMERIC(@offlinelocktimeout) <> 1
  695. BEGIN
  696. RAISERROR('WARNING: Offline lock timeout must be set to an integer number.', 15, 42) WITH NOWAIT;
  697. RETURN
  698. END;
  699. IF @offlinelocktimeout <> -1 AND @offlinelocktimeout IS NOT NULL
  700. SET @offlinelocktimeout = ABS(@offlinelocktimeout)
  701. /* Validate online lock timeout settings */
  702. IF @onlinelocktimeout IS NULL OR ISNUMERIC(@onlinelocktimeout) <> 1
  703. BEGIN
  704. RAISERROR('WARNING: Online lock timeout must be set to an integer number.', 15, 42) WITH NOWAIT;
  705. RETURN
  706. END;
  707. IF @onlinelocktimeout <> 5 AND @onlinelocktimeout IS NOT NULL
  708. SET @onlinelocktimeout = ABS(@onlinelocktimeout)
  709. /* Validate online lock timeout wait action settings */
  710. IF @abortAfterwait IS NOT NULL AND @abortAfterwait NOT IN (0,1)
  711. BEGIN
  712. RAISERROR('WARNING: Online lock timeout action is invalid.', 15, 42) WITH NOWAIT;
  713. RETURN
  714. END;
  715. /* Validate amount of breather time to give between operations*/
  716. IF @defragDelay NOT LIKE '00:[0-5][0-9]:[0-5][0-9]'
  717. BEGIN
  718. SET @defragDelay = '00:00:05';
  719. RAISERROR('Defrag delay input not valid. Defaulting to 5s.', 0, 42) WITH NOWAIT;
  720. END;
  721. IF @defragOrderColumn IS NULL OR LOWER(@defragOrderColumn) NOT IN ('range_scan_count', 'fragmentation', 'page_count')
  722. BEGIN
  723. SET @defragOrderColumn = 'range_scan_count';
  724. RAISERROR('Defrag order input not valid. Defaulting to range_scan_count.', 0, 42) WITH NOWAIT;
  725. END;
  726. IF @defragSortOrder IS NULL OR UPPER(@defragSortOrder) NOT IN ('ASC', 'DESC')
  727. SET @defragSortOrder = 'DESC';
  728. IF UPPER(@scanMode) NOT IN ('LIMITED', 'SAMPLED', 'DETAILED')
  729. BEGIN
  730. SET @scanMode = 'LIMITED';
  731. RAISERROR('Index scan mode input not valid. Defaulting to LIMITED.', 0, 42) WITH NOWAIT;
  732. END;
  733. IF @ixtypeOption IS NOT NULL AND @ixtypeOption NOT IN (0,1)
  734. SET @ixtypeOption = NULL;
  735. IF @statsSample IS NOT NULL AND (ISNUMERIC(@statsSample) = 1 AND @statsSample NOT BETWEEN 1 AND 100)
  736. OR (ISNUMERIC(@statsSample) = 0 AND UPPER(@statsSample) NOT IN ('FULLSCAN', 'RESAMPLE'))
  737. SET @statsSample = NULL
  738. IF (@persistStatsSample IS NOT NULL AND @persistStatsSample NOT IN (0,1))
  739. OR (@sqlmajorver <> 13 OR (@sqlmajorver = 13 AND @sqlbuild < 4446))
  740. SET @persistStatsSample = NULL;
  741. /* Recognize if database in scope is a Always On secondary replica */
  742. IF @dbScope IS NOT NULL AND @sqlmajorver >= 11
  743. BEGIN
  744. DECLARE @sqlcmdAO NVARCHAR(3000), @paramsAO NVARCHAR(50), @DBinAG int
  745. SET @sqlcmdAO = 'IF LOWER(@dbScopeIN) IN (SELECT LOWER(DB_NAME(dr.database_id))
  746. FROM sys.dm_hadr_database_replica_states dr
  747. INNER JOIN sys.dm_hadr_availability_replica_states rs ON dr.group_id = rs.group_id
  748. INNER JOIN sys.databases d ON dr.database_id = d.database_id
  749. WHERE rs.role = 2 -- Is Secondary
  750. AND dr.is_local = 1
  751. AND rs.is_local = 1)
  752. BEGIN
  753. SET @DBinAG_OUT = 1
  754. END
  755. ELSE
  756. BEGIN
  757. SET @DBinAG_OUT = 0
  758. END'
  759. SET @paramsAO = N'@dbScopeIN NVARCHAR(256), @DBinAG_OUT int OUTPUT'
  760. EXECUTE sp_executesql @sqlcmdAO, @paramsAO, @dbScopeIN = @dbScope, @DBinAG_OUT = @DBinAG OUTPUT
  761. IF @DBinAG = 1
  762. BEGIN
  763. RAISERROR('WARNING: Cannot defrag database in scope because it is part of an Always On secondary replica.', 15, 42) WITH NOWAIT;
  764. RETURN
  765. END
  766. END
  767. /* Check if database scope has changed, if rescan is not being forced */
  768. IF @forceRescan = 0 AND @dbScope IS NOT NULL -- Specific scope was set
  769. BEGIN
  770. IF (SELECT COUNT(DISTINCT [dbID]) FROM dbo.tbl_AdaptiveIndexDefrag_Working) > 1
  771. 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)
  772. BEGIN
  773. SET @forceRescan = 1
  774. RAISERROR('Scope has changed. Forcing rescan of single database in scope...', 0, 42) WITH NOWAIT;
  775. END;
  776. END;
  777. /* Recognize if we have indexes of the chosen type left to defrag or stats left to update;
  778. otherwise force rescan of database(s), if rescan is not being forced */
  779. IF @forceRescan = 0
  780. AND (NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL AND [type] = 1 AND [exclusionMask] & POWER(2, DATEPART(weekday, GETDATE())-1) = 0) AND @ixtypeOption = 1)
  781. AND (NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL AND [type] <> 1 AND [exclusionMask] & POWER(2, DATEPART(weekday, GETDATE())-1) = 0) AND @ixtypeOption = 0)
  782. 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 @ixtypeOption IS NULL)
  783. 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))
  784. BEGIN
  785. SET @forceRescan = 1
  786. RAISERROR('No indexes of the chosen type left to defrag nor statistics left to update. Forcing rescan...', 0, 42) WITH NOWAIT;
  787. END;
  788. /* Recognize if we missing information post-upgrade;
  789. if so force rescan of database(s) */
  790. IF @forceRescan = 0
  791. AND (EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working
  792. 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
  793. SET @forceRescan = 1
  794. RAISERROR('Missing column information due to post-upgrade condition. Forcing rescan...', 0, 42) WITH NOWAIT;
  795. END;
  796. /* Check if any databases where dropped or created since last run, if rescan is not being forced */
  797. IF @forceRescan = 0 AND @dbScope IS NULL
  798. BEGIN
  799. DECLARE @sqlcmd_CntSrc NVARCHAR(3000), @params_CntSrc NVARCHAR(50), @CountSrc int
  800. DECLARE @sqlcmd_CntTgt NVARCHAR(3000), @params_CntTgt NVARCHAR(50), @CountTgt int
  801. DECLARE @dbIDIX int, @hasIXs bit, @hasIXsCntsqlcmd NVARCHAR(3000), @hasIXsCntsqlcmdParams NVARCHAR(50)
  802. -- What is in working tables plus exceptions that still exist in server
  803. SET @sqlcmd_CntSrc = 'SELECT @CountSrc_OUT = COUNT(DISTINCT Working.[dbID]) FROM
  804. (SELECT DISTINCT [dbID] FROM [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Working
  805. UNION
  806. SELECT DISTINCT [dbID] FROM [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  807. UNION
  808. SELECT DISTINCT [dbID] FROM [' + DB_NAME() + '].dbo.tbl_AdaptiveIndexDefrag_Exceptions
  809. WHERE [dbID] IN (SELECT DISTINCT database_id FROM sys.databases sd
  810. WHERE LOWER(sd.[name]) NOT IN (''master'', ''tempdb'', ''model'', ''reportservertempdb'',''semanticsdb'')
  811. AND [state] = 0 -- must be ONLINE
  812. AND is_read_only = 0 -- cannot be READ_ONLY
  813. AND is_distributor = 0)
  814. ) Working'
  815. SET @params_CntSrc = N'@CountSrc_OUT int OUTPUT'
  816. -- What exists in current instance, in ONLINE state and READ_WRITE
  817. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexFindInDatabaseList'))
  818. DROP TABLE #tblIndexFindInDatabaseList;
  819. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexFindInDatabaseList'))
  820. CREATE TABLE #tblIndexFindInDatabaseList
  821. (
  822. [dbID] int
  823. , hasIXs bit NOT NULL
  824. , scanStatus bit NULL
  825. );
  826. /* Retrieve the list of databases to loop, excluding Always On secondary replicas */
  827. SET @sqlcmd_CntTgt = 'SELECT [database_id], 0, 0 -- not yet scanned
  828. FROM sys.databases
  829. WHERE LOWER([name]) = ISNULL(LOWER(@dbScopeIN), LOWER([name]))
  830. AND LOWER([name]) NOT IN (''master'', ''tempdb'', ''model'', ''reportservertempdb'',''semanticsdb'') -- exclude system databases
  831. AND [state] = 0 -- must be ONLINE
  832. AND is_read_only = 0 -- cannot be READ_ONLY
  833. AND is_distributor = 0'
  834. IF @sqlmajorver >= 11 AND (SELECT @@VERSION) NOT LIKE 'Microsoft SQL Azure%' -- Except all local Always On secondary replicas
  835. BEGIN
  836. SET @sqlcmd_CntTgt = @sqlcmd_CntTgt + CHAR(10) + 'AND [database_id] NOT IN (SELECT dr.database_id FROM sys.dm_hadr_database_replica_states dr
  837. INNER JOIN sys.dm_hadr_availability_replica_states rs ON dr.group_id = rs.group_id
  838. INNER JOIN sys.databases d ON dr.database_id = d.database_id
  839. WHERE rs.role = 2 -- Is Secondary
  840. AND dr.is_local = 1
  841. AND rs.is_local = 1)'
  842. END
  843. SET @params_CntTgt = N'@dbScopeIN NVARCHAR(256)'
  844. INSERT INTO #tblIndexFindInDatabaseList
  845. EXECUTE sp_executesql @sqlcmd_CntTgt, @params_CntTgt, @dbScopeIN = @dbScope
  846. WHILE (SELECT COUNT(*) FROM #tblIndexFindInDatabaseList WHERE scanStatus = 0) > 0
  847. BEGIN
  848. SELECT TOP 1 @dbIDIX = [dbID] FROM #tblIndexFindInDatabaseList WHERE scanStatus = 0;
  849. SET @hasIXsCntsqlcmd = 'IF EXISTS (SELECT TOP 1 [index_id] from [' + DB_NAME(@dbIDIX) + '].sys.indexes AS si
  850. INNER JOIN [' + DB_NAME(@dbIDIX) + '].sys.objects so ON si.object_id = so.object_id
  851. WHERE so.is_ms_shipped = 0 AND [index_id] > 0 AND si.is_hypothetical = 0
  852. AND si.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + DB_NAME(@dbIDIX) + '].sys.internal_tables AS sit))
  853. OR
  854. EXISTS (SELECT TOP 1 [stats_id] from [' + DB_NAME(@dbIDIX) + '].sys.stats AS ss
  855. INNER JOIN [' + DB_NAME(@dbIDIX) + '].sys.objects so ON ss.[object_id] = so.[object_id]
  856. WHERE so.is_ms_shipped = 0
  857. AND ss.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + DB_NAME(@dbIDIX) + '].sys.internal_tables AS sit))
  858. BEGIN SET @hasIXsOUT = 1 END ELSE BEGIN SET @hasIXsOUT = 0 END'
  859. SET @hasIXsCntsqlcmdParams = '@hasIXsOUT int OUTPUT'
  860. EXECUTE sp_executesql @hasIXsCntsqlcmd, @hasIXsCntsqlcmdParams, @hasIXsOUT = @hasIXs OUTPUT
  861. UPDATE #tblIndexFindInDatabaseList
  862. SET hasIXs = @hasIXs, scanStatus = 1
  863. WHERE [dbID] = @dbIDIX
  864. END
  865. EXECUTE sp_executesql @sqlcmd_CntSrc, @params_CntSrc, @CountSrc_OUT = @CountSrc OUTPUT
  866. SELECT @CountTgt = COUNT([dbID]) FROM #tblIndexFindInDatabaseList WHERE hasIXs = 1
  867. IF @CountSrc <> @CountTgt -- current databases in working lists <> number of eligible databases in instance
  868. BEGIN
  869. SET @forceRescan = 1
  870. RAISERROR('Scope has changed. Forcing rescan...', 0, 42) WITH NOWAIT;
  871. END
  872. END
  873. IF @debugMode = 1
  874. RAISERROR('Starting up...', 0, 42) WITH NOWAIT;
  875. /* Declare variables */
  876. DECLARE @ver VARCHAR(10)
  877. , @objectID int
  878. , @dbID int
  879. , @dbName NVARCHAR(256)
  880. , @indexID int
  881. , @operationFlag bit -- 0 = Reorganize, 1 = Rebuild
  882. , @partitionCount bigint
  883. , @schemaName NVARCHAR(128)
  884. , @objectName NVARCHAR(256)
  885. , @indexName NVARCHAR(256)
  886. , @statsobjectID int
  887. , @statsschemaName NVARCHAR(128)
  888. , @statsName NVARCHAR(256)
  889. , @statsobjectName NVARCHAR(256)
  890. , @stats_norecompute bit
  891. , @stats_isincremental bit
  892. , @is_primary_key bit
  893. , @fill_factor int
  894. , @is_disabled bit
  895. , @is_padded bit
  896. , @has_filter bit
  897. , @partitionNumber smallint
  898. , @maxpartitionNumber smallint
  899. , @minpartitionNumber smallint
  900. , @fragmentation float
  901. , @pageCount int
  902. , @sqlcommand NVARCHAR(4000)
  903. , @sqlcommand2 NVARCHAR(600)
  904. , @sqldisablecommand NVARCHAR(600)
  905. , @sqlprecommand NVARCHAR(600)
  906. , @rebuildcommand NVARCHAR(600)
  907. , @dateTimeStart DATETIME
  908. , @dateTimeEnd DATETIME
  909. , @containsColumnstore int
  910. , @CStore_SQL NVARCHAR(4000)
  911. , @CStore_SQL_Param NVARCHAR(1000)
  912. , @editionCheck bit
  913. , @debugMessage VARCHAR(2048)
  914. , @updateSQL NVARCHAR(4000)
  915. , @partitionSQL NVARCHAR(4000)
  916. , @partitionSQL_Param NVARCHAR(1000)
  917. , @rowmodctrSQL NVARCHAR(4000)
  918. , @rowmodctrSQL_Param NVARCHAR(1000)
  919. , @rowmodctr NUMERIC(10,3)
  920. , @record_count bigint
  921. , @range_scan_count bigint
  922. , @getStatSQL NVARCHAR(4000)
  923. , @getStatSQL_Param NVARCHAR(1000)
  924. , @statsID int
  925. , @surrogateStatsID int
  926. , @ixtype tinyint -- 0 = Heap; 1 = Clustered; 2 = Nonclustered; 3 = XML; 4 = Spatial
  927. , @containsLOB int
  928. , @LOB_SQL NVARCHAR(4000)
  929. , @LOB_SQL_Param NVARCHAR(1000)
  930. , @indexDefrag_id int
  931. , @statsUpdate_id int
  932. , @analysis_id int
  933. , @startDateTime DATETIME
  934. , @endDateTime DATETIME
  935. , @getIndexSQL NVARCHAR(4000)
  936. , @getIndexSQL_Param NVARCHAR(4000)
  937. , @allowPageLockSQL NVARCHAR(4000)
  938. , @allowPageLockSQL_Param NVARCHAR(4000)
  939. , @allowPageLocks bit
  940. , @dealMaxPartitionSQL NVARCHAR(4000)
  941. , @cpucount smallint
  942. , @tblNameFQN NVARCHAR(1000)
  943. , @TableScanSQL NVARCHAR(2000)
  944. , @ixCntSource int
  945. , @ixCntTarget int
  946. , @ixCntsqlcmd NVARCHAR(1000)
  947. , @ixCntsqlcmdParams NVARCHAR(100)
  948. , @ColumnStoreGetIXSQL NVARCHAR(2000)
  949. , @ColumnStoreGetIXSQL_Param NVARCHAR(1000)
  950. , @rows bigint
  951. , @rows_sampled bigint
  952. , @AID_dbID int
  953. , @currCompression NVARCHAR(60)
  954. /* Initialize variables */
  955. SELECT @AID_dbID = DB_ID(), @startDateTime = GETDATE(), @endDateTime = DATEADD(minute, @timeLimit, GETDATE()), @operationFlag = NULL, @ver = '1.6.6.9';
  956. /* Create temporary tables */
  957. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragDatabaseList'))
  958. DROP TABLE #tblIndexDefragDatabaseList;
  959. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragDatabaseList'))
  960. CREATE TABLE #tblIndexDefragDatabaseList
  961. (
  962. dbID int
  963. , dbName NVARCHAR(256)
  964. , scanStatus bit NULL
  965. );
  966. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragmaxPartitionList'))
  967. DROP TABLE #tblIndexDefragmaxPartitionList;
  968. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragmaxPartitionList'))
  969. CREATE TABLE #tblIndexDefragmaxPartitionList
  970. (
  971. objectID int
  972. , indexID int
  973. , maxPartition int
  974. );
  975. /* Create table for fragmentation scan per table, index and partition - slower but less chance of blocking*/
  976. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragScanWorking'))
  977. DROP TABLE #tblIndexDefragScanWorking;
  978. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragScanWorking'))
  979. CREATE TABLE #tblIndexDefragScanWorking
  980. (
  981. objectID int
  982. , indexID int
  983. , type tinyint
  984. , partitionNumber int
  985. , is_done bit
  986. );
  987. /* Find available processors*/
  988. SELECT @cpucount = COUNT(*)
  989. FROM sys.dm_os_schedulers
  990. WHERE is_online = 1 AND scheduler_id < 255 AND status = 'VISIBLE ONLINE'
  991. IF @maxDopRestriction IS NOT NULL AND @maxDopRestriction > @cpucount AND @cpucount <= 8
  992. BEGIN
  993. SET @maxDopRestriction = @cpucount
  994. END
  995. ELSE IF @maxDopRestriction IS NOT NULL AND ((@maxDopRestriction > @cpucount AND @cpucount > 8) OR @maxDopRestriction > 8)
  996. BEGIN
  997. SET @maxDopRestriction = 8;
  998. END
  999. /* Refer to http://docs.microsoft.com/sql/t-sql/functions/serverproperty-transact-sql */
  1000. IF (SELECT SERVERPROPERTY('EditionID')) IN (1804890536, 1872460670, 610778273, -2117995310)
  1001. SET @editionCheck = 1 -- supports enterprise only features: online rebuilds, partitioned indexes and MaxDOP
  1002. ELSE
  1003. SET @editionCheck = 0; -- does not support enterprise only features: online rebuilds, partitioned indexes and MaxDOP
  1004. /* Output the parameters to work with */
  1005. IF @debugMode = 1
  1006. BEGIN
  1007. SELECT @debugMessage = CHAR(10) + 'Executing AdaptiveIndexDefrag v' + @ver + ' on ' + @@VERSION + '
  1008. The selected parameters are:
  1009. Defragment indexes with fragmentation greater or equal to ' + CAST(@minFragmentation AS NVARCHAR(10)) + ';
  1010. Rebuild indexes with fragmentation greater than ' + CAST(@rebuildThreshold AS NVARCHAR(10)) + ';
  1011. Rebuild columnstore indexes with fragmentation greater than ' + CAST(@rebuildThreshold_cs AS NVARCHAR(10)) + ';
  1012. ' + CASE WHEN @disableNCIX = 1 THEN 'Non-clustered indexes will be disabled prior to rebuild;
  1013. ' ELSE '' END + 'Defragment ' + CASE WHEN @ixtypeOption IS NULL THEN 'ALL indexes' WHEN @ixtypeOption = 1 THEN 'only CLUSTERED indexes' ELSE 'only NON-CLUSTERED, XML and Spatial indexes' END + ';
  1014. Commands' + CASE WHEN @Exec_Print = 1 THEN ' WILL' ELSE ' WILL NOT' END + ' be executed automatically;
  1015. Defragment indexes in ' + @defragSortOrder + ' order of the ' + UPPER(@defragOrderColumn) + ' value;
  1016. Time limit' + CASE WHEN @timeLimit IS NULL THEN ' was not specified;' ELSE ' was specified and is ' + CAST(@timeLimit AS NVARCHAR(10)) END + ' minutes;
  1017. ' + CASE WHEN @dbScope IS NULL THEN 'ALL databases' ELSE 'The [' + @dbScope + '] database' END + ' will be defragmented;
  1018. ' + CASE WHEN @tblName IS NULL THEN 'ALL tables' ELSE 'The ' + @tblName + ' table' END + ' will be defragmented;
  1019. ' + '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;
  1020. The scan will be performed in ' + @scanMode + ' mode;
  1021. LOBs will ' + CASE WHEN @dealLOB = 1 THEN 'NOT ' ELSE '' END + 'be compacted;
  1022. Limit defrags to indexes' + CASE WHEN @maxPageCount IS NULL THEN ' with more than ' + CAST(@minPageCount AS NVARCHAR(10)) ELSE
  1023. ' between ' + CAST(@minPageCount AS NVARCHAR(10)) + ' and ' + CAST(@maxPageCount AS NVARCHAR(10)) END + ' pages;
  1024. Indexes will be defragmented' + CASE WHEN @onlineRebuild = 0 OR @editionCheck = 0 THEN ' OFFLINE;' ELSE ' ONLINE;' END + '
  1025. Indexes will be sorted in' + CASE WHEN @sortInTempDB = 0 THEN ' the DATABASE;' ELSE ' TEMPDB;' END + '
  1026. 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 + '
  1027. Indexes will keep' + CASE WHEN @fillfactor = 1 THEN ' its EXISTING' ELSE ' the DEFAULT' END + ' Fill Factor;' +
  1028. CASE WHEN @dealMaxPartition = 1 AND @editionCheck = 1 THEN '
  1029. The right-most populated partitions will be ignored;'
  1030. WHEN @dealMaxPartition = 0 AND @editionCheck = 1 THEN '
  1031. Only the right-most populated partitions will be considered if greater than ' + CAST(@minPageCount AS NVARCHAR(10)) + ' page(s);'
  1032. ELSE CHAR(10) + 'All partitions will be considered;' END +
  1033. CHAR(10) + 'Statistics ' + CASE WHEN @updateStats = 1 THEN 'WILL' ELSE 'WILL NOT' END + ' be updated ' + CASE WHEN @updateStatsWhere = 1 THEN 'on reorganized indexes;' ELSE 'on all stats belonging to parent table;' END +
  1034. CASE WHEN @updateStats = 1 AND @statsSample IS NOT NULL AND ISNUMERIC(@statsSample) = 0 THEN CHAR(10) + 'Statistics will be updated with ' + @statsSample ELSE '' END +
  1035. CASE WHEN @updateStats = 1 AND @statsSample IS NOT NULL AND ISNUMERIC(@statsSample) = 1 THEN CHAR(10) + 'Statistics will be updated with ' + RTRIM(@statsSample) + ' sampling rate' ELSE '' END +
  1036. CASE WHEN @updateStats = 1 AND @statsSample IS NOT NULL AND ISNUMERIC(@statsSample) = 1 AND @persistStatsSample = 1 THEN ' and persisting specified sampling rate percent;' ELSE '' END +
  1037. CASE WHEN @updateStats = 1 AND @statsSample IS NOT NULL AND ((ISNUMERIC(@statsSample) = 1 AND @persistStatsSample = 0) OR @persistStatsSample IS NULL) THEN ' and NOT persisting specified sampling rate percent;' ELSE '' END +
  1038. CHAR(10) + 'Statistics will be updated using ' + CASE WHEN @statsThreshold IS NOT NULL AND @statsThreshold BETWEEN 0.001 AND 100.0 THEN 'a threshold of ' + CONVERT(VARCHAR, @statsThreshold) + ' percent' ELSE 'a calculated threshold similar to TF2371' END +
  1039. + ' 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 +
  1040. 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 + '.' +
  1041. CHAR(10) + 'Defragmentation will use ' + CASE WHEN @editionCheck = 0 OR @maxDopRestriction IS NULL THEN 'system defaults for processors;'
  1042. ELSE CAST(@maxDopRestriction AS VARCHAR(3)) + ' processors;' END +
  1043. 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;' +
  1044. CHAR(10) + 'Starting with SQL Server 2014, lock timeout is set to ' + CONVERT(NVARCHAR(15), @onlinelocktimeout) + ' for online rebuilds;' +
  1045. 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;' +
  1046. CHAR(10) + CASE WHEN @printCmds = 1 THEN ' DO print' ELSE ' DO NOT print' END + ' the sql commands;' +
  1047. CHAR(10) + CASE WHEN @outputResults = 1 THEN ' DO output' ELSE ' DO NOT output' END + ' fragmentation levels;
  1048. Wait ' + @defragDelay + ' (hh:mm:ss) between index operations;
  1049. Execute in' + CASE WHEN @debugMode = 1 THEN ' DEBUG' ELSE ' SILENT' END + ' mode.' + CHAR(10);
  1050. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1051. END;
  1052. /* If we are scanning the database(s), do some pre-work */
  1053. 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)
  1054. 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)))
  1055. BEGIN
  1056. IF @debugMode = 1
  1057. RAISERROR('Listing databases...', 0, 42) WITH NOWAIT;
  1058. /* Retrieve the list of databases to loop, excluding Always On secondary replicas */
  1059. DECLARE @sqlcmdAO2 NVARCHAR(4000), @paramsAO2 NVARCHAR(50)
  1060. IF @debugMode = 1 AND @sqlmajorver >= 11
  1061. RAISERROR('Retrieving list of databases to loop, excluding Always On secondary replicas...', 0, 42) WITH NOWAIT;
  1062. IF @debugMode = 1 AND @sqlmajorver < 11
  1063. RAISERROR('Retrieving list of databases to loop...', 0, 42) WITH NOWAIT;
  1064. SET @sqlcmdAO2 = 'SELECT [database_id], name, 0 -- not yet scanned for fragmentation
  1065. FROM sys.databases
  1066. WHERE LOWER([name]) = ISNULL(LOWER(@dbScopeIN), LOWER([name]))
  1067. AND LOWER([name]) NOT IN (''master'', ''tempdb'', ''model'', ''reportservertempdb'',''semanticsdb'') -- exclude system databases
  1068. AND [state] = 0 -- must be ONLINE
  1069. AND is_read_only = 0 -- cannot be READ_ONLY
  1070. AND is_distributor = 0'
  1071. IF @sqlmajorver >= 11 AND (SELECT @@VERSION) NOT LIKE 'Microsoft SQL Azure%'-- Except all local Always On secondary replicas
  1072. BEGIN
  1073. SET @sqlcmdAO2 = @sqlcmdAO2 + CHAR(10) + 'AND [database_id] NOT IN (SELECT dr.database_id FROM sys.dm_hadr_database_replica_states dr
  1074. INNER JOIN sys.dm_hadr_availability_replica_states rs ON dr.group_id = rs.group_id
  1075. INNER JOIN sys.databases d ON dr.database_id = d.database_id
  1076. WHERE rs.role = 2 -- Is Secondary
  1077. AND dr.is_local = 1
  1078. AND rs.is_local = 1)'
  1079. END
  1080. SET @paramsAO2 = N'@dbScopeIN NVARCHAR(256)'
  1081. INSERT INTO #tblIndexDefragDatabaseList
  1082. EXECUTE sp_executesql @sqlcmdAO2, @paramsAO2, @dbScopeIN = @dbScope
  1083. IF @debugMode = 1
  1084. RAISERROR('Cross checking with exceptions for today...', 0, 42) WITH NOWAIT;
  1085. /* Avoid scanning databases that have all its indexes in the exceptions table i.e, fully excluded */
  1086. WHILE (SELECT COUNT(*) FROM #tblIndexDefragDatabaseList WHERE scanStatus = 0) > 0
  1087. BEGIN
  1088. SELECT TOP 1 @dbID = dbID FROM #tblIndexDefragDatabaseList WHERE scanStatus = 0;
  1089. SELECT @ixCntSource = COUNT([indexName]) FROM dbo.tbl_AdaptiveIndexDefrag_Exceptions WHERE [dbID] = @dbID AND exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0
  1090. SET @ixCntsqlcmd = 'SELECT @ixCntTargetOUT = COUNT(si.index_id) FROM [' + DB_NAME(@dbID) + '].sys.indexes si
  1091. INNER JOIN [' + DB_NAME(@dbID) + '].sys.objects so ON si.object_id = so.object_id
  1092. WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
  1093. AND si.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + DB_NAME(@dbID) + '].sys.internal_tables AS sit)' -- Exclude Heaps, Internal and Hypothetical objects
  1094. SET @ixCntsqlcmdParams = '@ixCntTargetOUT int OUTPUT'
  1095. EXECUTE sp_executesql @ixCntsqlcmd, @ixCntsqlcmdParams, @ixCntTargetOUT = @ixCntTarget OUTPUT
  1096. IF @ixCntSource = @ixCntTarget AND @ixCntSource > 0 -- All database objects are excluded, so skip database scanning
  1097. BEGIN
  1098. UPDATE #tblIndexDefragDatabaseList
  1099. SET scanStatus = NULL
  1100. WHERE dbID = @dbID;
  1101. IF @debugMode = 1
  1102. SELECT @debugMessage = ' Database ' + DB_NAME(@dbID) + ' is fully excluded from todays work.';
  1103. IF @debugMode = 1
  1104. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1105. END
  1106. IF @ixCntSource < @ixCntTarget AND @ixCntSource > 0 -- Only some database objects are excluded, so scan anyway and deal with exclusions on a granular level
  1107. BEGIN
  1108. UPDATE #tblIndexDefragDatabaseList
  1109. SET scanStatus = 1
  1110. WHERE dbID = @dbID;
  1111. IF @debugMode = 1
  1112. SELECT @debugMessage = ' Database ' + DB_NAME(@dbID) + ' is partially excluded from todays work.';
  1113. IF @debugMode = 1
  1114. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1115. END
  1116. IF @ixCntSource = 0 -- Database does not have excluded objects
  1117. BEGIN
  1118. UPDATE #tblIndexDefragDatabaseList
  1119. SET scanStatus = 1
  1120. WHERE dbID = @dbID;
  1121. END;
  1122. END;
  1123. /* Delete databases that are fully excluded for today */
  1124. DELETE FROM #tblIndexDefragDatabaseList
  1125. WHERE scanStatus IS NULL;
  1126. /* Reset status after cross check with exceptions */
  1127. UPDATE #tblIndexDefragDatabaseList
  1128. SET scanStatus = 0;
  1129. /* Delete database set by @dbScope */
  1130. IF @dbScope IS NOT NULL
  1131. BEGIN
  1132. DELETE FROM #tblIndexDefragDatabaseList
  1133. WHERE dbID <> DB_ID(@dbScope);
  1134. END;
  1135. END
  1136. /* 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) */
  1137. IF @forceRescan = 1 OR (@forceRescan = 0
  1138. AND NOT EXISTS (SELECT TOP 1 * FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL AND [exclusionMask] & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)
  1139. 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)))
  1140. BEGIN
  1141. IF @debugMode = 1
  1142. RAISERROR('Preparing for new database scan...', 0, 42) WITH NOWAIT;
  1143. /* Truncate list of indexes and stats to prepare for a new scan */
  1144. TRUNCATE TABLE dbo.tbl_AdaptiveIndexDefrag_Working;
  1145. TRUNCATE TABLE dbo.tbl_AdaptiveIndexDefrag_Stats_Working;
  1146. END
  1147. ELSE
  1148. BEGIN
  1149. /* Print an error message if there are any indexes left to defrag according to the chosen criteria */
  1150. IF @debugMode = 1
  1151. RAISERROR('There are still fragmented indexes or out-of-date stats from last execution. Resuming...', 0, 42) WITH NOWAIT;
  1152. END
  1153. /* Scan the database(s) */
  1154. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Working) = 0
  1155. BEGIN
  1156. IF @debugMode = 1
  1157. RAISERROR('Scanning database(s)...', 0, 42) WITH NOWAIT;
  1158. IF @debugMode = 1
  1159. RAISERROR(' Looping through list of databases and checking for fragmentation...', 0, 42) WITH NOWAIT;
  1160. /* Loop through list of databases */
  1161. WHILE (SELECT COUNT(*) FROM #tblIndexDefragDatabaseList WHERE scanStatus = 0) > 0
  1162. BEGIN
  1163. SELECT TOP 1 @dbID = dbID FROM #tblIndexDefragDatabaseList WHERE scanStatus = 0;
  1164. IF @debugMode = 1
  1165. SELECT @debugMessage = ' Working on database [' + DB_NAME(@dbID) + ']...';
  1166. IF @debugMode = 1
  1167. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1168. IF @dbScope IS NOT NULL AND @tblName IS NOT NULL
  1169. SELECT @tblNameFQN = @dbScope + '.' + @tblName
  1170. /* Set partitioning rebuild options; requires Enterprise Edition */
  1171. IF @dealMaxPartition IS NOT NULL AND @editionCheck = 0
  1172. SET @dealMaxPartition = NULL;
  1173. /* Truncate list of tables, indexes and partitions to prepare for a new scan */
  1174. TRUNCATE TABLE #tblIndexDefragScanWorking;
  1175. IF @debugMode = 1
  1176. RAISERROR(' Building list of objects in database...', 0, 42) WITH NOWAIT;
  1177. SELECT @TableScanSQL = 'USE [' + DB_NAME(@dbID) + ']
  1178. SELECT si.[object_id], si.index_id, si.type, sp.partition_number, 0
  1179. FROM sys.indexes si
  1180. INNER JOIN sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id
  1181. INNER JOIN sys.tables AS mst ON mst.[object_id] = si.[object_id]
  1182. INNER JOIN sys.schemas AS t ON t.[schema_id] = mst.[schema_id]' +
  1183. 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 +
  1184. 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 + '
  1185. AND si.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + DB_NAME(@dbID) + '].sys.internal_tables AS sit)' +
  1186. CASE WHEN @dbScope IS NOT NULL AND @tblName IS NOT NULL THEN '
  1187. AND t.name + ''.'' + mst.name = ''' + @tblName + ''';' ELSE ';' END
  1188. INSERT INTO #tblIndexDefragScanWorking
  1189. EXEC sp_executesql @TableScanSQL;
  1190. /* Do we want to act on a subset of existing partitions? */
  1191. IF @dealMaxPartition = 1 OR @dealMaxPartition = 0
  1192. BEGIN
  1193. IF @debugMode = 1
  1194. RAISERROR(' Setting partition handling...', 0, 42) WITH NOWAIT;
  1195. SET @dealMaxPartitionSQL = 'SELECT [object_id], index_id, MAX(partition_number) AS [maxPartition] FROM [' + DB_NAME(@dbID) + '].sys.partitions WHERE partition_number > 1 AND [rows] > 0 GROUP BY object_id, index_id;';
  1196. INSERT INTO #tblIndexDefragmaxPartitionList
  1197. EXEC sp_executesql @dealMaxPartitionSQL;
  1198. END;
  1199. /* We don't want to defrag the right-most populated partition, so delete any records for partitioned indexes where partition = MAX(partition) */
  1200. IF @dealMaxPartition = 1 AND @editionCheck = 1
  1201. BEGIN
  1202. IF @debugMode = 1
  1203. RAISERROR(' Ignoring right-most populated partition...', 0, 42) WITH NOWAIT;
  1204. DELETE ids
  1205. FROM #tblIndexDefragScanWorking AS ids
  1206. INNER JOIN #tblIndexDefragmaxPartitionList AS mpl ON ids.objectID = mpl.objectID AND ids.indexID = mpl.indexID AND ids.partitionNumber = mpl.maxPartition;
  1207. END;
  1208. /* We only want to defrag the right-most populated partition, so delete any records for partitioned indexes where partition <> MAX(partition) */
  1209. IF @dealMaxPartition = 0 AND @editionCheck = 1
  1210. BEGIN
  1211. IF @debugMode = 1
  1212. RAISERROR(' Setting only right-most populated partition...', 0, 42) WITH NOWAIT;
  1213. DELETE ids
  1214. FROM #tblIndexDefragScanWorking AS ids
  1215. INNER JOIN #tblIndexDefragmaxPartitionList AS mpl ON ids.objectID = mpl.objectID AND ids.indexID = mpl.indexID AND ids.partitionNumber <> mpl.maxPartition;
  1216. END;
  1217. /* Determine which indexes to defrag using user-defined parameters */
  1218. IF @debugMode = 1
  1219. RAISERROR(' Filtering indexes according to ixtypeOption parameter...', 0, 42) WITH NOWAIT;
  1220. IF @ixtypeOption IS NULL
  1221. BEGIN
  1222. DELETE FROM #tblIndexDefragScanWorking
  1223. WHERE [type] = 0; -- ignore heaps
  1224. END
  1225. ELSE IF @ixtypeOption = 1
  1226. BEGIN
  1227. DELETE FROM #tblIndexDefragScanWorking
  1228. WHERE [type] NOT IN (1,5); -- keep only clustered index
  1229. END
  1230. ELSE IF @ixtypeOption = 0
  1231. BEGIN
  1232. DELETE FROM #tblIndexDefragScanWorking
  1233. WHERE [type] NOT IN (2,6); -- keep only non-clustered indexes
  1234. END;
  1235. -- Get rowstore indexes to work on
  1236. IF @debugMode = 1
  1237. RAISERROR(' Getting rowstore indexes...', 0, 42) WITH NOWAIT;
  1238. WHILE (SELECT COUNT(*) FROM #tblIndexDefragScanWorking WHERE is_done = 0 AND [type] IN (1,2)) > 0
  1239. BEGIN
  1240. SELECT TOP 1 @objectID = objectID, @indexID = indexID, @partitionNumber = partitionNumber
  1241. FROM #tblIndexDefragScanWorking WHERE is_done = 0 AND type IN (1,2)
  1242. /* Get the time for logging purposes */
  1243. SET @dateTimeStart = GETDATE();
  1244. IF @debugMode = 1
  1245. BEGIN
  1246. SELECT @debugMessage = ' Analyzing index ID ' + CONVERT(VARCHAR(20), @indexID) + ' on table [' + OBJECT_NAME(@objectID, @dbID) + ']...'
  1247. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1248. END
  1249. /* Start log actions */
  1250. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Analysis_log ([Operation], [dbID], dbName, objectID, objectName, index_or_stat_ID, partitionNumber, dateTimeStart)
  1251. SELECT 'Index', @dbID, DB_NAME(@dbID), @objectID, OBJECT_NAME(@objectID, @dbID), @indexID, @partitionNumber, @dateTimeStart;
  1252. SET @analysis_id = SCOPE_IDENTITY();
  1253. BEGIN TRY
  1254. IF @getBlobfrag = 1
  1255. BEGIN
  1256. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Working (dbID, dbName, objectID, indexID, partitionNumber, fragmentation, page_count, range_scan_count, record_count, scanDate)
  1257. SELECT @dbID AS [dbID], QUOTENAME(DB_NAME(ps.database_id)) AS [dbName], @objectID AS [objectID], @indexID AS [indexID], ps.partition_number AS [partitionNumber], SUM(ps.avg_fragmentation_in_percent) AS [fragmentation], SUM(ps.page_count) AS [page_count], os.range_scan_count, ps.record_count, GETDATE() AS [scanDate]
  1258. FROM sys.dm_db_index_physical_stats(@dbID, @objectID, @indexID, @partitionNumber, @scanMode) AS ps
  1259. LEFT JOIN sys.dm_db_index_operational_stats(@dbID, @objectID, @indexID, @partitionNumber) AS os ON ps.database_id = os.database_id AND ps.object_id = os.object_id AND ps.index_id = os.index_id AND ps.partition_number = os.partition_number
  1260. WHERE avg_fragmentation_in_percent >= @minFragmentation
  1261. AND ps.page_count >= @minPageCount
  1262. AND ps.index_level = 0 -- leaf-level nodes only, supports @scanMode
  1263. AND ps.alloc_unit_type_desc = 'IN_ROW_DATA' -- exclude blobs
  1264. GROUP BY ps.database_id, QUOTENAME(DB_NAME(ps.database_id)), ps.partition_number, os.range_scan_count, ps.record_count
  1265. OPTION (MAXDOP 2);
  1266. END
  1267. ELSE IF @getBlobfrag = 0
  1268. BEGIN
  1269. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Working (dbID, dbName, objectID, indexID, partitionNumber, fragmentation, page_count, range_scan_count, record_count, scanDate)
  1270. SELECT @dbID AS [dbID], QUOTENAME(DB_NAME(ps.database_id)) AS [dbName], @objectID AS [objectID], @indexID AS [indexID], ps.partition_number AS [partitionNumber], SUM(ps.avg_fragmentation_in_percent) AS [fragmentation], SUM(ps.page_count) AS [page_count], os.range_scan_count, ps.record_count, GETDATE() AS [scanDate]
  1271. FROM sys.dm_db_index_physical_stats(@dbID, @objectID, @indexID, @partitionNumber, @scanMode) AS ps
  1272. LEFT JOIN sys.dm_db_index_operational_stats(@dbID, @objectID, @indexID, @partitionNumber) AS os ON ps.database_id = os.database_id AND ps.object_id = os.object_id AND ps.index_id = os.index_id AND ps.partition_number = os.partition_number
  1273. WHERE avg_fragmentation_in_percent >= @minFragmentation
  1274. AND ps.page_count >= @minPageCount
  1275. AND ps.index_level = 0 -- leaf-level nodes only, supports @scanMode
  1276. GROUP BY ps.database_id, QUOTENAME(DB_NAME(ps.database_id)), ps.partition_number, os.range_scan_count, ps.record_count
  1277. OPTION (MAXDOP 2);
  1278. END
  1279. END TRY
  1280. BEGIN CATCH
  1281. IF @debugMode = 1
  1282. BEGIN
  1283. 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)) + ')'
  1284. SET @dateTimeEnd = GETDATE();
  1285. /* Update log with completion time */
  1286. UPDATE dbo.tbl_AdaptiveIndexDefrag_Analysis_log
  1287. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd), errorMessage = LTRIM(@debugMessage)
  1288. WHERE analysis_id = @analysis_id AND dateTimeEnd IS NULL;
  1289. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1290. --RAISERROR(' An error has occurred executing the pre-command! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 0, 42) WITH NOWAIT;
  1291. END
  1292. END CATCH
  1293. SET @dateTimeEnd = GETDATE();
  1294. /* Update log with completion time */
  1295. UPDATE dbo.tbl_AdaptiveIndexDefrag_Analysis_log
  1296. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd)
  1297. WHERE analysis_id = @analysis_id AND dateTimeEnd IS NULL;
  1298. UPDATE #tblIndexDefragScanWorking
  1299. SET is_done = 1
  1300. WHERE objectID = @objectID AND indexID = @indexID AND partitionNumber = @partitionNumber
  1301. END;
  1302. -- Get columnstore indexes to work on
  1303. IF @debugMode = 1 AND @sqlmajorver >= 12
  1304. RAISERROR(' Getting columnstore indexes...', 0, 42) WITH NOWAIT;
  1305. IF @sqlmajorver >= 12
  1306. BEGIN
  1307. WHILE (SELECT COUNT(*) FROM #tblIndexDefragScanWorking WHERE is_done = 0 AND [type] IN (5,6)) > 0
  1308. BEGIN
  1309. SELECT TOP 1 @objectID = objectID, @indexID = indexID, @partitionNumber = partitionNumber
  1310. FROM #tblIndexDefragScanWorking WHERE is_done = 0 AND type IN (5,6)
  1311. /* Get the time for logging purposes */
  1312. SET @dateTimeStart = GETDATE();
  1313. /* Start log actions */
  1314. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Analysis_log ([Operation], [dbID], dbName, objectID, objectName, index_or_stat_ID, partitionNumber, dateTimeStart)
  1315. SELECT 'Index', @dbID, DB_NAME(@dbID), @objectID, OBJECT_NAME(@objectID, @dbID), @indexID, @partitionNumber, @dateTimeStart;
  1316. SET @analysis_id = SCOPE_IDENTITY();
  1317. BEGIN TRY
  1318. SELECT @ColumnStoreGetIXSQL = 'USE [' + DB_NAME(@dbID) + ']; SELECT @dbID_In, QUOTENAME(DB_NAME(@dbID_In)), rg.object_id, rg.index_id, rg.partition_number, CASE WHEN SUM((ISNULL(rg.deleted_rows,1)*100)/rg.total_rows) > 100 THEN 100 ELSE SUM((ISNULL(rg.deleted_rows,1)*100)/rg.total_rows) END AS [fragmentation], SUM(ISNULL(rg.size_in_bytes,1)/1024/8) AS [simulated_page_count], SUM(rg.total_rows) AS total_rows, GETDATE() AS [scanDate]
  1319. FROM ' + CASE WHEN @sqlmajorver = 12 THEN 'sys.column_store_row_groups' ELSE 'sys.dm_db_column_store_row_group_physical_stats' END + ' rg WITH (NOLOCK)
  1320. WHERE rg.object_id = @objectID_In
  1321. AND rg.index_id = @indexID_In
  1322. AND rg.partition_number = @partitionNumber_In
  1323. AND rg.state = 3 -- Only COMPRESSED row groups
  1324. GROUP BY rg.object_id, rg.index_id, rg.partition_number
  1325. HAVING SUM(ISNULL(rg.size_in_bytes,1)/1024/8) >= @minPageCount_In
  1326. OPTION (MAXDOP 2)'
  1327. SET @ColumnStoreGetIXSQL_Param = N'@dbID_In int, @objectID_In int, @indexID_In int, @partitionNumber_In smallint, @minPageCount_in int';
  1328. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Working (dbID, dbName, objectID, indexID, partitionNumber, fragmentation, page_count, record_count, scanDate)
  1329. EXECUTE sp_executesql @ColumnStoreGetIXSQL, @ColumnStoreGetIXSQL_Param, @dbID_In = @dbID, @objectID_In = @objectID, @indexID_In = @indexID, @partitionNumber_In = @partitionNumber, @minPageCount_in = @minPageCount;
  1330. END TRY
  1331. BEGIN CATCH
  1332. IF @debugMode = 1
  1333. BEGIN
  1334. 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)) + ')'
  1335. SET @dateTimeEnd = GETDATE();
  1336. /* Update log with completion time */
  1337. UPDATE dbo.tbl_AdaptiveIndexDefrag_Analysis_log
  1338. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd), errorMessage = LTRIM(@debugMessage)
  1339. WHERE analysis_id = @analysis_id AND dateTimeEnd IS NULL;
  1340. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1341. --RAISERROR(' An error has occurred executing the pre-command! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 0, 42) WITH NOWAIT;
  1342. END
  1343. END CATCH;
  1344. SET @dateTimeEnd = GETDATE();
  1345. /* Update log with completion time */
  1346. UPDATE dbo.tbl_AdaptiveIndexDefrag_Analysis_log
  1347. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd)
  1348. WHERE analysis_id = @analysis_id AND dateTimeEnd IS NULL;
  1349. UPDATE #tblIndexDefragScanWorking
  1350. SET is_done = 1
  1351. WHERE objectID = @objectID AND indexID = @indexID AND partitionNumber = @partitionNumber
  1352. END
  1353. END;
  1354. /* Look up index status for various purposes */
  1355. SELECT @updateSQL = N'UPDATE ids
  1356. 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
  1357. FROM [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
  1358. INNER JOIN [' + DB_NAME(@dbID) + '].sys.objects AS o WITH (NOLOCK) ON ids.objectID = o.object_id
  1359. INNER JOIN [' + DB_NAME(@dbID) + '].sys.indexes AS i WITH (NOLOCK) ON o.object_id = i.object_id AND ids.indexID = i.index_id
  1360. INNER JOIN [' + DB_NAME(@dbID) + '].sys.schemas AS s WITH (NOLOCK) ON o.schema_id = s.schema_id
  1361. WHERE o.object_id = ids.objectID AND i.index_id = ids.indexID AND i.type > 0
  1362. AND o.object_id NOT IN (SELECT sit.object_id FROM [' + DB_NAME(@dbID) + '].sys.internal_tables AS sit)
  1363. AND ids.[dbID] = ' + CAST(@dbID AS NVARCHAR(10));
  1364. IF @debugMode = 1
  1365. BEGIN
  1366. RAISERROR(' Looking up additional index information (pass 1)...', 0, 42) WITH NOWAIT;
  1367. --PRINT @updateSQL
  1368. END
  1369. EXECUTE sp_executesql @updateSQL;
  1370. IF @sqlmajorver = 9
  1371. BEGIN
  1372. SELECT @updateSQL = N'UPDATE ids
  1373. SET [record_count] = [rows], [compression_type] = N''''
  1374. FROM [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
  1375. 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
  1376. WHERE ids.[dbID] = ' + CAST(@dbID AS NVARCHAR(10));
  1377. END
  1378. ELSE
  1379. BEGIN
  1380. SELECT @updateSQL = N'UPDATE ids
  1381. SET [record_count] = [rows], [compression_type] = [data_compression_desc]
  1382. FROM [' + DB_NAME(@AID_dbID) + '].dbo.tbl_AdaptiveIndexDefrag_Working ids WITH (NOLOCK)
  1383. 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
  1384. WHERE ids.[dbID] = ' + CAST(@dbID AS NVARCHAR(10));
  1385. END
  1386. IF @debugMode = 1
  1387. BEGIN
  1388. RAISERROR(' Looking up additional index information (pass 2)...', 0, 42) WITH NOWAIT;
  1389. --PRINT @updateSQL
  1390. END
  1391. EXECUTE sp_executesql @updateSQL;
  1392. IF @debugMode = 1
  1393. RAISERROR(' Looking up additional statistic information...', 0, 42) WITH NOWAIT;
  1394. /* Look up stats information for various purposes */
  1395. DECLARE @tblNameOnly NVARCHAR(1000), @schemaNameOnly NVARCHAR(128)
  1396. IF @tblName IS NOT NULL
  1397. BEGIN
  1398. SELECT @tblNameOnly = RIGHT(@tblName, LEN(@tblName) - CHARINDEX('.', @tblName, 1)), @schemaNameOnly = LEFT(@tblName, CHARINDEX('.', @tblName, 1) -1)
  1399. END
  1400. SELECT @updateSQL = N'USE [' + DB_NAME(@dbID) + '];
  1401. 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 + '
  1402. 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
  1403. FROM sys.stats AS ss WITH (NOLOCK)
  1404. INNER JOIN sys.objects AS so WITH (NOLOCK) ON ss.[object_id] = so.[object_id]
  1405. INNER JOIN sys.schemas AS s WITH (NOLOCK) ON so.[schema_id] = s.[schema_id]' +
  1406. CASE WHEN @updateStatsWhere = 0 THEN 'LEFT JOIN' ELSE 'INNER JOIN' END + -- @updateStatsWhere = 0 then table-wide statistics;
  1407. ' sys.indexes AS si WITH (NOLOCK) ON ss.[object_id] = si.[object_id] and ss.name = si.name' +
  1408. 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 +
  1409. 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 +
  1410. CHAR(10) + 'WHERE is_ms_shipped = 0 ' + CASE WHEN @sqlmajorver >= 12 THEN 'AND ss.is_temporary = 0' ELSE '' END + '
  1411. AND so.[object_id] NOT IN (SELECT sit.[object_id] FROM sys.internal_tables AS sit)
  1412. AND so.[type] IN (''U'',''V'')
  1413. AND (si.[type] IS NULL OR si.[type] NOT IN (5,6,7))' + -- Avoid error 35337
  1414. CASE WHEN @dbScope IS NOT NULL AND @tblName IS NOT NULL THEN CHAR(10) + 'AND s.name = ''' + @schemaNameOnly + ''' AND so.name = ''' + @tblNameOnly + ''';' ELSE ';' END
  1415. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_Working (dbID, dbName, objectID, statsID, partitionNumber, schemaName, objectName, statsName, [no_recompute], [is_incremental], scanDate)
  1416. EXECUTE sp_executesql @updateSQL;
  1417. /* Keep track of which databases have already been scanned */
  1418. UPDATE #tblIndexDefragDatabaseList
  1419. SET scanStatus = 1
  1420. WHERE dbID = @dbID;
  1421. END;
  1422. /* Delete any records for disabled (except those disabled by the defrag cycle itself) or hypothetical indexes */
  1423. IF @debugMode = 1
  1424. RAISERROR(' Listing and removing disabled indexes (except those disabled by the defrag cycle itself) or hypothetical indexes from loop...', 0, 42) WITH NOWAIT;
  1425. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Working AS ids WHERE ids.is_disabled = 1 OR ids.is_hypothetical = 1) > 0
  1426. DELETE ids
  1427. FROM dbo.tbl_AdaptiveIndexDefrag_Working AS ids
  1428. LEFT JOIN dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus AS ids_disable ON ids.objectID = ids_disable.objectID AND ids.indexID = ids_disable.indexID AND ids.[dbID] = ids_disable.dbID
  1429. WHERE ids.is_disabled = 1 OR ids.is_hypothetical = 1 AND ids_disable.indexID IS NULL;
  1430. IF @debugMode = 1
  1431. RAISERROR(' Updating Exception mask for any index that has a restriction on the days it CANNOT be defragmented...', 0, 42) WITH NOWAIT;
  1432. /* Update our Exception mask for any index that has a restriction on the days it CANNOT be defragmented
  1433. based on 1=Sunday, 2=Monday, 4=Tuesday, 8=Wednesday, 16=Thursday, 32=Friday, 64=Saturday, 127=AllWeek
  1434. */
  1435. UPDATE ids
  1436. SET ids.exclusionMask = ide.exclusionMask
  1437. FROM dbo.tbl_AdaptiveIndexDefrag_Working AS ids
  1438. INNER JOIN dbo.tbl_AdaptiveIndexDefrag_Exceptions AS ide ON ids.[dbID] = ide.[dbID] AND ids.objectID = ide.objectID AND ids.indexID = ide.indexID;
  1439. END;
  1440. IF @debugMode = 1
  1441. SELECT @debugMessage = 'Looping through batch list... There are ' + CAST(COUNT(DISTINCT indexName) AS NVARCHAR(10)) + ' indexes to defragment in ' + CAST(COUNT(DISTINCT dbName) AS NVARCHAR(10)) + ' database(s)!'
  1442. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  1443. WHERE defragDate IS NULL AND page_count BETWEEN @minPageCount AND ISNULL(@maxPageCount, page_count) AND exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0;
  1444. IF @debugMode = 1
  1445. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1446. IF @debugMode = 1
  1447. BEGIN
  1448. IF @updateStatsWhere = 1
  1449. BEGIN
  1450. SELECT @debugMessage = 'Looping through batch list... There are ' + CAST(COUNT(DISTINCT statsName) AS NVARCHAR(10)) + ' index related statistics to update in ' + CAST(COUNT(DISTINCT idss.dbName) AS NVARCHAR(10)) + ' database(s)!'
  1451. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss
  1452. INNER JOIN dbo.tbl_AdaptiveIndexDefrag_Working ids ON ids.[dbID] = idss.[dbID] AND ids.objectID = idss.objectID
  1453. WHERE idss.schemaName = ids.schemaName AND idss.statsName = ids.indexName AND idss.updateDate IS NULL AND ids.exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0;
  1454. END
  1455. ELSE
  1456. BEGIN
  1457. SELECT @debugMessage = 'Looping through batch list... There are ' + CAST(COUNT(DISTINCT statsName) AS NVARCHAR(10)) + ' index related statistics to update in ' + CAST(COUNT(DISTINCT idss.dbName) AS NVARCHAR(10)) + ' database(s),'
  1458. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss
  1459. INNER JOIN dbo.tbl_AdaptiveIndexDefrag_Working ids ON ids.[dbID] = idss.[dbID] AND ids.objectID = idss.objectID
  1460. WHERE idss.schemaName = ids.schemaName AND idss.statsName = ids.indexName AND idss.updateDate IS NULL AND ids.exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0;
  1461. SELECT @debugMessage = @debugMessage + ' plus ' + CAST(COUNT(DISTINCT statsName) AS NVARCHAR(10)) + ' other statistics to update in ' + CAST(COUNT(DISTINCT dbName) AS NVARCHAR(10)) + ' database(s)!'
  1462. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss
  1463. WHERE idss.updateDate IS NULL
  1464. 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);
  1465. END
  1466. END
  1467. IF @debugMode = 1
  1468. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1469. IF @Exec_Print = 0 AND @printCmds = 1
  1470. BEGIN
  1471. RAISERROR(' Printing SQL statements...', 0, 42) WITH NOWAIT;
  1472. END;
  1473. /* Begin defragmentation loop */
  1474. WHILE (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE ((@Exec_Print = 1 AND defragDate IS NULL) OR (@Exec_Print = 0 AND defragDate IS NULL AND printStatus = 0)) AND exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0 AND page_count BETWEEN @minPageCount AND ISNULL(@maxPageCount, page_count)) > 0
  1475. BEGIN
  1476. /* Check to see if we need to exit loop because of our time limit */
  1477. IF ISNULL(@endDateTime, GETDATE()) < GETDATE()
  1478. RAISERROR('Time limit has been exceeded for this maintenance window!', 16, 42) WITH NOWAIT;
  1479. IF @debugMode = 1
  1480. RAISERROR(' Selecting an index to defragment...', 0, 42) WITH NOWAIT;
  1481. /* Select the index with highest priority, based on the values submitted; Verify date constraint for this index in the Exception table */
  1482. SET @getIndexSQL = N'SELECT TOP 1 @objectID_Out = objectID, @indexID_Out = indexID, @dbID_Out = dbID
  1483. FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NULL '
  1484. + CASE WHEN @Exec_Print = 0 THEN 'AND printStatus = 0 ' ELSE '' END + '
  1485. AND exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0
  1486. AND page_count BETWEEN @p_minPageCount AND ISNULL(@p_maxPageCount, page_count)
  1487. ORDER BY + ' + @defragOrderColumn + ' ' + @defragSortOrder + ', objectID DESC';
  1488. SET @getIndexSQL_Param = N'@objectID_Out int OUTPUT, @indexID_Out int OUTPUT, @dbID_Out int OUTPUT, @p_minPageCount int, @p_maxPageCount int';
  1489. EXECUTE sp_executesql @getIndexSQL, @getIndexSQL_Param, @p_minPageCount = @minPageCount, @p_maxPageCount = @maxPageCount, @objectID_Out = @objectID OUTPUT, @indexID_Out = @indexID OUTPUT, @dbID_Out = @dbID OUTPUT;
  1490. IF @debugMode = 1
  1491. RAISERROR(' Getting partition count...', 0, 42) WITH NOWAIT;
  1492. /* Determine if the index is partitioned */
  1493. SELECT @partitionCount = MAX(partitionNumber)
  1494. FROM dbo.tbl_AdaptiveIndexDefrag_Working AS ids
  1495. WHERE objectID = @objectID AND indexID = @indexID AND dbID = @dbID
  1496. IF @debugMode = 1
  1497. RAISERROR(' Getting selected index information...', 0, 42) WITH NOWAIT;
  1498. /* Get object names and info */
  1499. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1500. BEGIN
  1501. IF @debugMode = 1
  1502. RAISERROR(' Partition number specific...', 0, 42) WITH NOWAIT;
  1503. 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]
  1504. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  1505. 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))
  1506. ORDER BY partitionNumber ASC; -- ensure that we have always the same sequence in order to continue resumeable operations
  1507. END
  1508. ELSE
  1509. BEGIN
  1510. RAISERROR(' Not partition number specific...', 0, 42) WITH NOWAIT;
  1511. 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]
  1512. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  1513. 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));
  1514. END
  1515. /* Determine maximum partition number for use with stats update*/
  1516. IF @updateStats = 1
  1517. BEGIN
  1518. SELECT @maxpartitionNumber = MAX(partitionNumber), @minpartitionNumber = MIN(partitionNumber)
  1519. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  1520. WHERE objectID = @objectID AND indexID = @indexID AND dbID = @dbID;
  1521. END
  1522. IF @debugMode = 1
  1523. RAISERROR(' Checking if any LOBs exist...', 0, 42) WITH NOWAIT;
  1524. SET @containsLOB = 0
  1525. /* Determine if the index contains LOBs, with info from sys.types */
  1526. IF @ixtype = 2 AND @sqlmajorver < 11 -- Nonclustered and LOBs in INCLUDED columns? Up to SQL 2008R2
  1527. BEGIN
  1528. SELECT @LOB_SQL = 'SELECT @containsLOB_OUT = COUNT(*) FROM ' + @dbName + '.sys.columns c WITH (NOLOCK)
  1529. INNER JOIN ' + @dbName + '.sys.index_columns ic WITH (NOLOCK) ON c.[object_id] = ic.[object_id] AND c.column_id = ic.column_id
  1530. INNER JOIN ' + @dbName + '.sys.indexes i WITH (NOLOCK) ON i.[object_id] = ic.[object_id] and i.index_id = ic.index_id
  1531. WHERE max_length = -1 AND ic.is_included_column = 1
  1532. AND i.object_id = ' + CAST(@objectID AS NVARCHAR(10)) + ' AND i.index_id = ' + CAST(@indexID AS NVARCHAR(10)) + ';'
  1533. /* max_length = -1 for VARBINARY(MAX), VARCHAR(MAX), NVARCHAR(MAX), XML */
  1534. ,@LOB_SQL_Param = '@containsLOB_OUT int OUTPUT';
  1535. EXECUTE sp_executesql @LOB_SQL, @LOB_SQL_Param, @containsLOB_OUT = @containsLOB OUTPUT;
  1536. IF @debugMode = 1 AND @containsLOB > 0 AND @onlineRebuild = 1
  1537. RAISERROR(' Online rebuild not possible on indexes with LOBs in INCLUDED columns...', 0, 42) WITH NOWAIT;
  1538. END
  1539. IF @ixtype = 1 -- Clustered and has LOBs in table?
  1540. BEGIN
  1541. SELECT @LOB_SQL = 'SELECT @containsLOB_OUT = COUNT(*) FROM ' + @dbName + '.sys.columns c WITH (NOLOCK)
  1542. INNER JOIN ' + @dbName + '.sys.indexes i WITH (NOLOCK) ON c.[object_id] = i.[object_id]
  1543. WHERE system_type_id IN (34, 35, 99) ' + CASE WHEN @sqlmajorver < 11 THEN 'OR max_length = -1 ' ELSE '' END +
  1544. 'AND i.object_id = ' + CAST(@objectID AS NVARCHAR(10)) + ' AND i.index_id = ' + CAST(@indexID AS NVARCHAR(10)) + ';'
  1545. /* system_type_id = 34 for IMAGE, 35 for TEXT, 99 for NTEXT,
  1546. max_length = -1 for VARBINARY(MAX), VARCHAR(MAX), NVARCHAR(MAX), XML */
  1547. ,@LOB_SQL_Param = '@containsLOB_OUT int OUTPUT';
  1548. EXECUTE sp_executesql @LOB_SQL, @LOB_SQL_Param, @containsLOB_OUT = @containsLOB OUTPUT;
  1549. IF @debugMode = 1 AND @containsLOB > 0 AND @onlineRebuild = 1
  1550. RAISERROR(' Online rebuild not possible on clustered index when certain LOBs exist in table...', 0, 42) WITH NOWAIT;
  1551. END
  1552. IF @debugMode = 1 AND (@sqlmajorver >= 11 OR @ixtype IN (5,6))
  1553. RAISERROR(' Checking for Columnstore index...', 0, 42) WITH NOWAIT;
  1554. SET @containsColumnstore = 0
  1555. IF @ixtype NOT IN (5,6) -- Not already in the scope of a Columnstore index
  1556. AND @sqlmajorver >= 11 -- Parent table has Columnstore indexes?
  1557. BEGIN
  1558. SELECT @CStore_SQL = 'SELECT @containsColumnstore_OUT = COUNT(*) FROM ' + @dbName + '.sys.indexes i WITH (NOLOCK) WHERE i.object_id = ' + CAST(@objectID AS NVARCHAR(10)) + ' AND i.type IN (5,6);'
  1559. ,@CStore_SQL_Param = '@containsColumnstore_OUT int OUTPUT';
  1560. EXECUTE sp_executesql @CStore_SQL, @CStore_SQL_Param, @containsColumnstore_OUT = @containsColumnstore OUTPUT;
  1561. IF @debugMode = 1 AND @containsColumnstore > 0 AND @onlineRebuild = 1
  1562. RAISERROR(' Online rebuild not possible when parent table has Columnstore index...', 0, 42) WITH NOWAIT;
  1563. END
  1564. IF @ixtype IN (5,6)
  1565. BEGIN
  1566. SET @containsColumnstore = 1
  1567. IF @debugMode = 1 AND @containsColumnstore > 0 AND @onlineRebuild = 1
  1568. RAISERROR(' Online rebuild not possible on Columnstore indexes...', 0, 42) WITH NOWAIT;
  1569. END
  1570. IF @debugMode = 1
  1571. RAISERROR(' Checking if index does not allow page locks...', 0, 42) WITH NOWAIT;
  1572. /* Determine if page locks are not allowed; these must always rebuild; if @forceRescan = 0 then always check in real time in case it has changed*/
  1573. IF @forceRescan = 0
  1574. BEGIN
  1575. SELECT @allowPageLockSQL = 'SELECT @allowPageLocks_OUT = allow_page_locks FROM ' + @dbName + '.sys.indexes WHERE [object_id] = ' + CAST(@objectID AS NVARCHAR(10)) + ' AND [index_id] = ' + CAST(@indexID AS NVARCHAR(10)) + ';'
  1576. ,@allowPageLockSQL_Param = '@allowPageLocks_OUT bit OUTPUT';
  1577. EXECUTE sp_executesql @allowPageLockSQL, @allowPageLockSQL_Param, @allowPageLocks_OUT = @allowPageLocks OUTPUT;
  1578. END
  1579. ELSE
  1580. BEGIN
  1581. SELECT @allowPageLocks = [allow_page_locks] FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE objectID = @objectID AND indexID = @indexID AND [dbID] = @dbID
  1582. END
  1583. IF @debugMode = 1 AND @allowPageLocks = 0
  1584. RAISERROR(' Index does not allow page locks...', 0, 42) WITH NOWAIT;
  1585. IF @debugMode = 1
  1586. BEGIN
  1587. SELECT @debugMessage = ' Found ' + CONVERT(NVARCHAR(10), @fragmentation) + ' percent fragmentation on index ' + @indexName + '...';
  1588. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1589. END
  1590. IF @debugMode = 1
  1591. RAISERROR(' Building SQL statements...', 0, 42) WITH NOWAIT;
  1592. /* If there's not a lot of fragmentation, or if we have a LOB, we should reorganize.
  1593. Filtered indexes or indexes that do not allow page locks should always rebuild. */
  1594. IF (@fragmentation < @rebuildThreshold AND @ixtype IN (1,2) AND @has_filter = 0 AND @allowPageLocks = 1)
  1595. OR (@fragmentation < @rebuildThreshold_cs AND @ixtype IN (5,6))
  1596. BEGIN
  1597. SET @operationFlag = 0
  1598. /* Set Reorg command */
  1599. SET @sqlcommand = N'ALTER INDEX ' + @indexName + N' ON ' + @dbName + N'.' + @schemaName + N'.' + @objectName + N' REORGANIZE';
  1600. /* Set partition reorg options; requires Enterprise Edition; valid only if more than one partition exists */
  1601. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1602. SET @sqlcommand = @sqlcommand + N' PARTITION = ' + CAST(@partitionNumber AS NVARCHAR(10));
  1603. /* Set LOB reorg options; valid only if no more than one partition exists */
  1604. IF @dealLOB = 1 AND @partitionCount = 1 AND @ixtype IN (1,2)
  1605. SET @sqlcommand = @sqlcommand + N' WITH (LOB_COMPACTION = OFF)';
  1606. IF @dealLOB = 0 AND @partitionCount = 1 AND @ixtype IN (1,2)
  1607. SET @sqlcommand = @sqlcommand + N' WITH (LOB_COMPACTION = ON)';
  1608. /* Set Columnstore reorg option to compress all rowgroups, and not just closed ones */
  1609. IF @sqlmajorver >= 12 AND @dealROWG = 1 AND @ixtype IN (5,6)
  1610. SET @sqlcommand = @sqlcommand + N' WITH (COMPRESS_ALL_ROW_GROUPS = ON)';
  1611. SET @sqlcommand = @sqlcommand + N';';
  1612. END
  1613. /* If the index is heavily fragmented and doesn't contain any partitions,
  1614. or if the index does not allow page locks, or if it is a filtered index, rebuild it */
  1615. ELSE IF ((@fragmentation >= @rebuildThreshold AND @ixtype IN (1,2)) OR @rebuildThreshold = 0)
  1616. OR ((@fragmentation >= @rebuildThreshold_cs AND @ixtype IN (5,6)) OR @rebuildThreshold_cs = 0)
  1617. OR @has_filter = 1 OR @allowPageLocks = 0
  1618. BEGIN
  1619. SET @rebuildcommand = N' REBUILD'
  1620. SET @operationFlag = 1
  1621. /* Set partition rebuild options; requires Enterprise Edition; valid only if more than one partition exists */
  1622. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1623. SET @rebuildcommand = @rebuildcommand + N' PARTITION = ' + CAST(@partitionNumber AS NVARCHAR(10));
  1624. --ELSE IF @dealMaxPartition IS NULL AND @editionCheck = 1 AND @partitionCount > 1
  1625. --SET @rebuildcommand = @rebuildcommand + N' PARTITION = ALL';
  1626. /* Disallow disabling indexes on partitioned tables when defraging a subset of existing partitions */
  1627. IF @dealMaxPartition IS NOT NULL AND @partitionCount > 1
  1628. SET @disableNCIX = 0
  1629. /* Set defrag options*/
  1630. SET @rebuildcommand = @rebuildcommand + N' WITH ('
  1631. /* Set index pad options; not compatible with partition operations */
  1632. IF @is_padded = 1 AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
  1633. SET @rebuildcommand = @rebuildcommand + N'PAD_INDEX = ON, '
  1634. /* Sets specific compression options for indexes */
  1635. IF @dataCompression IN ('NONE','PAGE','ROW')
  1636. AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
  1637. AND @ixtype IN (1,2)
  1638. AND (@sqlmajorver > 13 OR (@sqlmajorver = 13 AND @sqlbuild >= 4001) OR @editionCheck = 1) -- SQL 2016 SP1 or higher for compression in non-EE
  1639. SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @dataCompression + ', '
  1640. IF @dataCompression IS NULL
  1641. AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
  1642. AND @ixtype IN (1,2)
  1643. AND (@sqlmajorver > 13 OR (@sqlmajorver = 13 AND @sqlbuild >= 4001) OR @editionCheck = 1) -- SQL 2016 SP1 or higher for compression in non-EE
  1644. SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @currCompression + ', '
  1645. IF @dataCompression IN ('NONE','PAGE','ROW') AND @ixtype IN (1,2)
  1646. AND @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1647. SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @dataCompression + ' ON PARTITIONS (' + CAST(@partitionNumber AS NVARCHAR(10)) + '), '
  1648. IF @dataCompression IS NULL AND @ixtype IN (1,2)
  1649. AND @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1650. SET @rebuildcommand = @rebuildcommand + N'DATA_COMPRESSION = ' + @currCompression + ' ON PARTITIONS (' + CAST(@partitionNumber AS NVARCHAR(10)) + '), '
  1651. /* Set online rebuild options; requires Enterprise Edition; not compatible with partition operations, Columnstore indexes in table and XML or Spatial indexes.
  1652. Up to SQL Server 2008R2, not compatible with clustered indexes with LOB columns in table or non-clustered indexes with LOBs in INCLUDED columns.
  1653. In SQL Server 2012, not compatible with clustered indexes with LOB columns in table.*/
  1654. IF @sqlmajorver <= 11 AND @onlineRebuild = 1 AND @editionCheck = 1
  1655. AND @ixtype IN (1,2) AND @containsLOB = 0
  1656. AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1))
  1657. SET @rebuildcommand = @rebuildcommand + N'ONLINE = ON, ';
  1658. /* Set online rebuild options; requires Enterprise Edition; not compatible with partition operations, Columnstore indexes in table and XML or Spatial indexes.
  1659. In SQL Server 2014, not compatible with clustered indexes with LOB columns in table, but compatible with partition operations.
  1660. Also, we can use Lock Priority with online indexing. */
  1661. IF @sqlmajorver > 11 AND @onlineRebuild = 1 AND @editionCheck = 1
  1662. AND @ixtype IN (1,2) AND @containsLOB = 0
  1663. 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 + ')), '
  1664. /* Set fill factor operation preferences; not compatible with partition operations and Columnstore indexes */
  1665. IF @fillfactor = 1 AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1)) AND @ixtype IN (1,2)
  1666. SET @rebuildcommand = @rebuildcommand + N'FILLFACTOR = ' + CONVERT(NVARCHAR, CASE WHEN @fill_factor = 0 THEN 100 ELSE @fill_factor END) + N', ';
  1667. IF @fillfactor = 0 AND (@dealMaxPartition IS NULL OR (@dealMaxPartition IS NOT NULL AND @partitionCount = 1)) AND @ixtype IN (1,2)
  1668. SET @rebuildcommand = @rebuildcommand + N'FILLFACTOR = 100, ';
  1669. /* Resumable requires an ONLINE rebuild and version >= SQL Server 2017 */
  1670. IF @sqlmajorver >= 14 AND @onlineRebuild = 1 AND @resumableRebuild = 1
  1671. SET @rebuildcommand = @rebuildcommand + N'RESUMABLE = ON, ';
  1672. /* Set sort operation preferences */
  1673. IF @sortInTempDB = 1 AND @ixtype IN (1,2)
  1674. SET @rebuildcommand = @rebuildcommand + N'SORT_IN_TEMPDB = ON, ';
  1675. IF @sortInTempDB = 0 AND @ixtype IN (1,2)
  1676. SET @rebuildcommand = @rebuildcommand + N'SORT_IN_TEMPDB = OFF, ';
  1677. /* Set NO_RECOMPUTE preference */
  1678. IF @ix_statsnorecompute = 1 AND @ixtype IN (1,2)
  1679. SET @sqlcommand = @sqlcommand + N' STATISTICS_NORECOMPUTE = ON, ';
  1680. IF @ix_statsnorecompute = 0 AND @ixtype IN (1,2)
  1681. SET @sqlcommand = @sqlcommand + N' STATISTICS_NORECOMPUTE = OFF, ';
  1682. /* Set processor restriction options; requires Enterprise Edition */
  1683. IF @maxDopRestriction IS NOT NULL AND @editionCheck = 1
  1684. SET @rebuildcommand = @rebuildcommand + N'MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3)) + N');';
  1685. ELSE
  1686. SET @rebuildcommand = @rebuildcommand + N');';
  1687. IF @rebuildcommand LIKE '% WITH ();'
  1688. SET @rebuildcommand = REPLACE(@rebuildcommand, ' WITH ()', '')
  1689. /* Set NCIX disable command, except for clustered index*/
  1690. SET @sqldisablecommand = NULL
  1691. IF @disableNCIX = 1 AND @ixtype = 2 AND @is_primary_key = 0
  1692. BEGIN
  1693. SET @sqldisablecommand = N'ALTER INDEX ' + @indexName + N' ON ' + @dbName + N'.' + @schemaName + N'.' + @objectName + ' DISABLE;';
  1694. END
  1695. /* Set update statistics command for index only, before rebuild, as rebuild performance is dependent on statistics (only working on non-partitioned tables)
  1696. http://blogs.msdn.com/b/psssql/archive/2009/03/18/be-aware-of-parallel-index-creation-performance-issues.aspx */
  1697. SET @sqlprecommand = NULL
  1698. /* Is stat incremental? */
  1699. SELECT TOP 1 @stats_isincremental = [is_incremental] FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  1700. WHERE dbName = @dbName AND schemaName = @schemaName AND objectName = @objectName AND statsName = @indexName;
  1701. /* Are there paused index operations? */
  1702. DECLARE @sqlcmdRI NVARCHAR(100), @paramsRI NVARCHAR(50), @HasRI int
  1703. SET @HasRI = 0
  1704. IF @sqlmajorver > 14
  1705. BEGIN
  1706. SET @sqlcmdRI = 'USE ' + QUOTENAME(@dbName) + '; SELECT @HasRI_OUT = COUNT(*) FROM sys.index_resumable_operations'
  1707. SET @paramsRI = N'@HasRI_OUT int OUTPUT'
  1708. EXECUTE sp_executesql @sqlcmdRI, @paramsRI, @HasRI_OUT = @HasRI OUTPUT
  1709. END;
  1710. IF @HasRI > 0
  1711. BEGIN
  1712. IF @debugMode = 1
  1713. RAISERROR(' Found ongoing resumable index operations - skipping all pre-commands...', 0, 42) WITH NOWAIT;
  1714. SET @sqlprecommand = N''
  1715. END
  1716. ELSE IF (@sqlmajorver < 13 OR @partitionCount = 1) AND @sqldisablecommand IS NULL AND @ixtype IN (1,2)
  1717. BEGIN
  1718. SET @sqlprecommand = N'UPDATE STATISTICS ' + @dbName + N'.' + @schemaName + N'.' + @objectName + N' (' + @indexName + N')'
  1719. /* Set processor restriction options */
  1720. IF @maxDopRestriction IS NOT NULL
  1721. AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
  1722. SET @sqlprecommand = @sqlprecommand + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3)) + N'; ';
  1723. ELSE
  1724. SET @sqlprecommand = @sqlprecommand + N'; ';
  1725. END
  1726. ELSE IF @sqlmajorver >= 13 AND @partitionCount > 1 AND @stats_isincremental = 1 AND @sqldisablecommand IS NULL AND @ixtype IN (1,2)
  1727. BEGIN
  1728. SET @sqlprecommand = N'UPDATE STATISTICS ' + @dbName + N'.' + @schemaName + N'.' + @objectName + N' (' + @indexName + N') WITH RESAMPLE ON PARTITIONS(' + CONVERT(NVARCHAR(10), @partitionNumber) + N')'
  1729. /* Set processor restriction options */
  1730. IF @maxDopRestriction IS NOT NULL
  1731. AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
  1732. SET @sqlprecommand = @sqlprecommand + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3)) + N'; ';
  1733. ELSE
  1734. SET @sqlprecommand = @sqlprecommand + N'; '
  1735. END
  1736. /* Set Rebuild command */
  1737. SET @sqlcommand = N'ALTER INDEX ' + @indexName + N' ON ' + @dbName + N'.' + @schemaName + N'.' + @objectName + REPLACE(@rebuildcommand,', )', ')');
  1738. /* For offline rebuilds, set lock timeout if not default */
  1739. IF @onlineRebuild = 0 AND @offlinelocktimeout > -1 AND @offlinelocktimeout IS NOT NULL
  1740. SET @sqlcommand = 'SET LOCK_TIMEOUT ' + CONVERT(NVARCHAR(15), @offlinelocktimeout) + '; ' + @sqlcommand
  1741. END
  1742. ELSE
  1743. BEGIN
  1744. /* Print an error message if any indexes happen to not meet the criteria above */
  1745. IF @debugMode = 1
  1746. BEGIN
  1747. SET @debugMessage = 'We are unable to defrag index ' + @indexName + N' on table ' + @dbName + N'.' + @schemaName + N'.' + @objectName
  1748. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1749. END
  1750. END;
  1751. IF @operationFlag = 0 AND @sqlprecommand IS NOT NULL
  1752. SET @sqlprecommand = NULL
  1753. IF @operationFlag = 0 AND @sqldisablecommand IS NOT NULL
  1754. SET @sqldisablecommand = NULL
  1755. /* Are we executing the SQL? If so, do it */
  1756. IF @Exec_Print = 1
  1757. BEGIN
  1758. /* Get the time for logging purposes */
  1759. SET @dateTimeStart = GETDATE();
  1760. /* Start log actions */
  1761. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1762. BEGIN
  1763. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_log (dbID, dbName, objectID, objectName, indexID, indexName, partitionNumber, fragmentation, page_count, range_scan_count, fill_factor, dateTimeStart, sqlStatement)
  1764. SELECT @dbID, @dbName, @objectID, @objectName, @indexID, @indexName, @partitionNumber, @fragmentation, @pageCount, @range_scan_count, @fill_factor, @dateTimeStart, ISNULL(@sqlprecommand, '') + @sqlcommand;
  1765. END
  1766. ELSE
  1767. BEGIN
  1768. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_log (dbID, dbName, objectID, objectName, indexID, indexName, partitionNumber, fragmentation, page_count, range_scan_count, fill_factor, dateTimeStart, sqlStatement)
  1769. SELECT @dbID, @dbName, @objectID, @objectName, @indexID, @indexName, 1, @fragmentation, @pageCount, @range_scan_count, @fill_factor, @dateTimeStart, ISNULL(@sqlprecommand, '') + @sqlcommand;
  1770. END
  1771. SET @indexDefrag_id = SCOPE_IDENTITY();
  1772. IF @sqlprecommand IS NULL AND @sqldisablecommand IS NULL
  1773. BEGIN
  1774. SET @debugMessage = ' ' + @sqlcommand;
  1775. END
  1776. ELSE IF @sqlprecommand IS NOT NULL AND @sqldisablecommand IS NULL
  1777. BEGIN
  1778. SET @debugMessage = ' ' + @sqlprecommand + CHAR(10) + ' ' + @sqlcommand;
  1779. END;
  1780. ELSE IF @sqlprecommand IS NULL AND @sqldisablecommand IS NOT NULL
  1781. BEGIN
  1782. SET @debugMessage = ' ' + @sqldisablecommand + CHAR(10) + ' ' + @sqlcommand;
  1783. END;
  1784. ELSE IF @sqlprecommand IS NOT NULL AND @sqldisablecommand IS NOT NULL
  1785. BEGIN
  1786. SET @debugMessage = ' ' + @sqldisablecommand + CHAR(10) + ' ' + @sqlprecommand + CHAR(10) + ' ' + @sqlcommand;
  1787. END;
  1788. /* Print the commands we'll be executing, if specified to do so */
  1789. IF (@debugMode = 1 OR @printCmds = 1) AND @sqlcommand IS NOT NULL
  1790. BEGIN
  1791. RAISERROR(' Printing SQL statements...', 0, 42) WITH NOWAIT;
  1792. SET @debugMessage = ' Executing: ' + CHAR(10) + @debugMessage;
  1793. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1794. END;
  1795. /* Execute default update stats on index only. With better stats, index rebuild process will generally have better performance */
  1796. IF @operationFlag = 1
  1797. BEGIN
  1798. BEGIN TRY
  1799. EXECUTE sp_executesql @sqlprecommand;
  1800. SET @sqlprecommand = NULL
  1801. SET @dateTimeEnd = GETDATE();
  1802. -- /* Update log with completion time */ --> if logged here, completion time after actual rebuild is not logged
  1803. -- UPDATE dbo.tbl_AdaptiveIndexDefrag_log
  1804. -- SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd)
  1805. -- WHERE indexDefrag_id = @indexDefrag_id AND dateTimeEnd IS NULL;
  1806. /* If rebuilding, update statistics log with completion time */
  1807. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1808. BEGIN
  1809. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log (dbID, dbName, objectID, objectName, statsID, statsName, [partitionNumber], [rows], [rows_sampled], [modification_counter], [no_recompute], dateTimeStart, dateTimeEnd, durationSeconds, sqlStatement)
  1810. SELECT @dbID, @dbName, @objectID, @objectName, statsID, statsName, @partitionNumber, -1, -1, -1, [no_recompute], @dateTimeStart, @dateTimeEnd, DATEDIFF(second, @dateTimeStart, @dateTimeEnd), @sqlcommand
  1811. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  1812. WHERE objectID = @objectID AND dbID = @dbID
  1813. AND statsName = @indexName
  1814. AND ((@Exec_Print = 1 AND updateDate IS NULL) OR (@Exec_Print = 0 AND updateDate IS NULL AND printStatus = 0));
  1815. END
  1816. ELSE
  1817. BEGIN
  1818. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log (dbID, dbName, objectID, objectName, statsID, statsName, [partitionNumber], [rows], [rows_sampled], [modification_counter],[no_recompute], dateTimeStart, dateTimeEnd, durationSeconds, sqlStatement)
  1819. SELECT @dbID, @dbName, @objectID, @objectName, statsID, statsName, 1, -1, -1, -1, [no_recompute], @dateTimeStart, @dateTimeEnd, DATEDIFF(second, @dateTimeStart, @dateTimeEnd), @sqlcommand
  1820. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  1821. WHERE objectID = @objectID AND dbID = @dbID
  1822. AND statsName = @indexName
  1823. AND ((@Exec_Print = 1 AND updateDate IS NULL) OR (@Exec_Print = 0 AND updateDate IS NULL AND printStatus = 0));
  1824. END
  1825. END TRY
  1826. BEGIN CATCH
  1827. /* Update log with error message */
  1828. UPDATE dbo.tbl_AdaptiveIndexDefrag_log
  1829. SET dateTimeEnd = GETDATE(), durationSeconds = -1, errorMessage = 'Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing the pre-command for index ' + @indexName +'. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  1830. WHERE indexDefrag_id = @indexDefrag_id AND dateTimeEnd IS NULL;
  1831. IF @debugMode = 1
  1832. BEGIN
  1833. SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing the pre-command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  1834. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1835. --RAISERROR(' An error has occurred executing the pre-command! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 0, 42) WITH NOWAIT;
  1836. END
  1837. END CATCH
  1838. END;
  1839. /* Execute NCIX disable command */
  1840. IF @operationFlag = 1 AND @disableNCIX = 1 AND @indexID > 1 AND (@sqldisablecommand IS NOT NULL OR LEN(@sqldisablecommand) > 0)
  1841. BEGIN
  1842. BEGIN TRY
  1843. EXECUTE sp_executesql @sqldisablecommand;
  1844. /* Insert into working table for disabled state control */
  1845. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus (dbID, objectID, indexID, [is_disabled], dateTimeChange)
  1846. SELECT @dbID, @objectID, @indexID, 1, GETDATE()
  1847. END TRY
  1848. BEGIN CATCH
  1849. /* Delete from working table for disabled state control */
  1850. DELETE FROM dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus
  1851. WHERE dbID = @dbID AND objectID = @objectID AND indexID = @indexID;
  1852. IF @debugMode = 1
  1853. BEGIN
  1854. SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing the disable index command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  1855. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1856. --RAISERROR(' An error has occurred executing the disable index command! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 0, 42) WITH NOWAIT;
  1857. END
  1858. END CATCH
  1859. END;
  1860. /* Execute defrag! */
  1861. BEGIN TRY
  1862. EXECUTE sp_executesql @sqlcommand;
  1863. SET @dateTimeEnd = GETDATE();
  1864. UPDATE dbo.tbl_AdaptiveIndexDefrag_log
  1865. /* Update log with completion time */
  1866. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd)
  1867. WHERE indexDefrag_id = @indexDefrag_id AND dateTimeEnd IS NULL;
  1868. IF @operationFlag = 1 AND @disableNCIX = 1 AND @indexID > 1
  1869. BEGIN
  1870. /* Delete from working table for disabled state control */
  1871. DELETE FROM dbo.tbl_AdaptiveIndexDefrag_IxDisableStatus
  1872. WHERE dbID = @dbID AND objectID = @objectID AND indexID = @indexID;
  1873. END;
  1874. END TRY
  1875. BEGIN CATCH
  1876. /* Update log with error message */
  1877. UPDATE dbo.tbl_AdaptiveIndexDefrag_log
  1878. SET dateTimeEnd = GETDATE(), durationSeconds = -1, errorMessage = 'Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing this command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  1879. WHERE indexDefrag_id = @indexDefrag_id AND dateTimeEnd IS NULL;
  1880. IF @debugMode = 1
  1881. BEGIN
  1882. SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing this command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  1883. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1884. --RAISERROR(' An error has occurred executing this command! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 0, 42) WITH NOWAIT;
  1885. END
  1886. END CATCH
  1887. /* Update working table and resume loop */
  1888. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1889. BEGIN
  1890. UPDATE dbo.tbl_AdaptiveIndexDefrag_Working
  1891. SET defragDate = ISNULL(@dateTimeEnd, GETDATE()), printStatus = 1
  1892. WHERE dbID = @dbID AND objectID = @objectID AND indexID = @indexID AND partitionNumber = @partitionNumber;
  1893. END
  1894. ELSE
  1895. BEGIN
  1896. UPDATE dbo.tbl_AdaptiveIndexDefrag_Working
  1897. SET defragDate = ISNULL(@dateTimeEnd, GETDATE()), printStatus = 1
  1898. WHERE dbID = @dbID AND objectID = @objectID AND indexID = @indexID;
  1899. END
  1900. IF @operationFlag = 1
  1901. BEGIN
  1902. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  1903. SET updateDate = ISNULL(@dateTimeEnd, GETDATE()), printStatus = 1
  1904. WHERE objectID = @objectID AND dbID = @dbID AND statsName = @indexName;
  1905. END
  1906. /* Just a little breather for the server */
  1907. WAITFOR DELAY @defragDelay;
  1908. END;
  1909. ELSE IF @Exec_Print = 0
  1910. BEGIN
  1911. IF @operationFlag = 0 AND @sqlprecommand IS NOT NULL
  1912. SET @sqlprecommand = NULL
  1913. IF @sqlprecommand IS NULL AND (@sqldisablecommand IS NULL OR @sqldisablecommand = '')
  1914. BEGIN
  1915. SET @debugMessage = ' ' + @sqlcommand;
  1916. END
  1917. ELSE IF @sqlprecommand IS NOT NULL AND (@sqldisablecommand IS NULL OR @sqldisablecommand = '')
  1918. BEGIN
  1919. SET @debugMessage = ' ' + @sqlprecommand + CHAR(10) + ' ' + @sqlcommand;
  1920. END;
  1921. ELSE IF @sqlprecommand IS NULL AND (@sqldisablecommand IS NOT NULL OR LEN(@sqldisablecommand) > 0)
  1922. BEGIN
  1923. SET @debugMessage = ' ' + @sqldisablecommand + CHAR(10) + ' ' + @sqlcommand;
  1924. END;
  1925. ELSE IF @sqlprecommand IS NOT NULL AND (@sqldisablecommand IS NOT NULL OR LEN(@sqldisablecommand) > 0)
  1926. BEGIN
  1927. SET @debugMessage = ' ' + @sqldisablecommand + CHAR(10) + ' ' + @sqlprecommand + CHAR(10) + ' ' + @sqlcommand;
  1928. END;
  1929. /* Print the commands we're executing if specified to do so */
  1930. IF (@debugMode = 1 OR @printCmds = 1) AND @sqlcommand IS NOT NULL
  1931. BEGIN
  1932. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1933. END
  1934. /* Update working table and resume loop */
  1935. IF @partitionCount > 1 AND @dealMaxPartition IS NOT NULL AND @editionCheck = 1
  1936. BEGIN
  1937. UPDATE dbo.tbl_AdaptiveIndexDefrag_Working
  1938. SET printStatus = 1
  1939. WHERE dbID = @dbID AND objectID = @objectID AND indexID = @indexID AND partitionNumber = @partitionNumber;
  1940. END
  1941. ELSE
  1942. BEGIN
  1943. UPDATE dbo.tbl_AdaptiveIndexDefrag_Working
  1944. SET printStatus = 1
  1945. WHERE dbID = @dbID AND objectID = @objectID AND indexID = @indexID;
  1946. END
  1947. IF @operationFlag = 1
  1948. BEGIN
  1949. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  1950. SET printStatus = 1
  1951. WHERE objectID = @objectID AND dbID = @dbID AND statsName = @indexName;
  1952. END;
  1953. END;
  1954. IF @operationFlag = 0 AND @updateStats = 1 -- When reorganizing, update stats afterwards
  1955. AND @updateStatsWhere = 0 AND @ixtype NOT IN (5,6,7)
  1956. BEGIN
  1957. IF @debugMode = 1
  1958. RAISERROR(' Updating index related statistics using finer thresholds (if any)...', 0, 42) WITH NOWAIT;
  1959. /* Handling index related statistics */
  1960. IF @debugMode = 1
  1961. RAISERROR(' Selecting a statistic to update...', 0, 42) WITH NOWAIT;
  1962. /* Select the stat */
  1963. BEGIN TRY
  1964. SET @getStatSQL = N'SELECT TOP 1 @statsID_Out = idss.statsID FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss WHERE idss.updateDate IS NULL ' + CASE WHEN @Exec_Print = 0 THEN 'AND idss.printStatus = 0 ' ELSE '' END + ' AND idss.[dbID] = ' + CONVERT(NVARCHAR, @dbID) + ' AND idss.statsName = ''' + @indexName + '''' + ' AND idss.objectID = ' + CONVERT(NVARCHAR, @objectID) + ' AND 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.defragDate IS NOT NULL AND ids.exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0)';
  1965. SET @getStatSQL_Param = N'@statsID_Out int OUTPUT'
  1966. EXECUTE sp_executesql @getStatSQL, @getStatSQL_Param, @statsID_Out = @statsID OUTPUT;
  1967. SET @statsName = @indexName
  1968. END TRY
  1969. BEGIN CATCH
  1970. IF @debugMode = 1
  1971. BEGIN
  1972. SET @debugMessage = ' Error ' + CONVERT(VARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining which statistic to update. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS VARCHAR(10)) + ')'
  1973. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1974. END
  1975. END CATCH
  1976. IF @debugMode = 1
  1977. RAISERROR(' Getting information on selected statistic...', 0, 42) WITH NOWAIT;
  1978. /* Get object name and auto update setting */
  1979. SELECT TOP 1 @statsName = statsName, @partitionNumber = partitionNumber, @stats_norecompute = [no_recompute], @stats_isincremental = [is_incremental]
  1980. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  1981. WHERE objectID = @objectID AND statsID = @statsID AND [dbID] = @dbID;
  1982. IF @debugMode = 1
  1983. BEGIN
  1984. SET @debugMessage = ' Determining modification row counter for statistic ' + @statsName + ' on table or view ' + @objectName + ' of DB ' + @dbName + '...';
  1985. IF @debugMessage IS NOT NULL
  1986. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  1987. END;
  1988. /* Determine modification row counter to ascertain if update stats is required */
  1989. IF ((@sqlmajorver = 12 AND @sqlbuild >= 5000) OR (@sqlmajorver = 13 AND @sqlbuild >= 4000) OR @sqlmajorver > 13) AND ISNULL(@stats_isincremental,1) = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE')
  1990. BEGIN
  1991. IF @debugMode = 1
  1992. RAISERROR(' Using sys.dm_db_incremental_stats_properties DMF...', 0, 42) WITH NOWAIT;
  1993. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = ISNULL(modification_counter,0), @rows_Out = ISNULL(rows,0), @rows_sampled_Out = ISNULL(rows_sampled,0) FROM sys.dm_db_incremental_stats_properties(@statsobjectID_In, @statsID_In) WHERE partition_number = @partitionNumber_In;'
  1994. END
  1995. ELSE IF ((@sqlmajorver = 12 AND @sqlbuild < 5000) OR (@sqlmajorver = 13 AND @sqlbuild < 4000)) AND ISNULL(@stats_isincremental,1) = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE')
  1996. BEGIN
  1997. IF @debugMode = 1
  1998. RAISERROR(' Using sys.dm_db_stats_properties_internal DMF...', 0, 42) WITH NOWAIT;
  1999. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = ISNULL(modification_counter,0), @rows_Out = ISNULL(rows,0), @rows_sampled_Out = ISNULL(rows_sampled,0) FROM sys.dm_db_stats_properties_internal(@statsobjectID_In, @statsID_In) WHERE partition_number = @partitionNumber_In;'
  2000. END
  2001. ELSE IF ((@sqlmajorver = 10 AND @sqlminorver = 50 AND @sqlbuild >= 4000) OR (@sqlmajorver = 11 AND @sqlbuild >= 3000) OR @sqlmajorver >= 12) AND (ISNULL(@stats_isincremental,1) = 0 OR UPPER(@statsSample) = 'FULLSCAN' OR ISNUMERIC(@statsSample) = 1)
  2002. BEGIN
  2003. IF @debugMode = 1
  2004. RAISERROR(' Using sys.dm_db_stats_properties DMF...', 0, 42) WITH NOWAIT;
  2005. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = ISNULL(modification_counter,0), @rows_Out = ISNULL(rows,0), @rows_sampled_Out = ISNULL(rows_sampled,0) FROM sys.dm_db_stats_properties(@statsobjectID_In, @statsID_In);'
  2006. END
  2007. ELSE
  2008. BEGIN
  2009. IF @debugMode = 1
  2010. RAISERROR(' Using sys.sysindexes...', 0, 42) WITH NOWAIT;
  2011. SELECT TOP 1 @surrogateStatsID = indexID FROM dbo.tbl_AdaptiveIndexDefrag_Working (NOLOCK) WHERE objectID = @statsobjectID AND indexName = @statsName
  2012. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = SUM(ISNULL(rowmodctr,0)), @rows_Out = ISNULL(rowcnt,0), @rows_sampled_Out = -1 FROM sys.sysindexes WHERE id = @statsobjectID_In AND indid = @statsID_In AND rowmodctr > 0;'
  2013. IF @statsID IS NULL
  2014. SET @statsID = @surrogateStatsID
  2015. END
  2016. SET @rowmodctrSQL_Param = N'@partitionNumber_In smallint, @statsobjectID_In int, @statsID_In int, @rowmodctr_Out bigint OUTPUT, @rows_Out bigint OUTPUT, @rows_sampled_Out bigint OUTPUT'
  2017. BEGIN TRY
  2018. EXECUTE sp_executesql @rowmodctrSQL, @rowmodctrSQL_Param, @statsobjectID_In = @statsobjectID, @statsID_In = @statsID, @partitionNumber_In = @partitionNumber, @rowmodctr_Out = @rowmodctr OUTPUT, @rows_Out = @rows OUTPUT, @rows_sampled_Out = @rows_sampled OUTPUT;
  2019. SET @rowmodctr = (SELECT ISNULL(@rowmodctr, 0));
  2020. END TRY
  2021. BEGIN CATCH
  2022. IF @debugMode = 1
  2023. BEGIN
  2024. SET @debugMessage = ' Error ' + CONVERT(VARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining row modification counter. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS VARCHAR(10)) + ')'
  2025. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2026. END
  2027. END CATCH
  2028. IF @rows IS NOT NULL AND @rows > 0
  2029. SET @record_count = @rows
  2030. IF @debugMode = 1
  2031. BEGIN
  2032. SELECT @debugMessage = ' Found a row modification counter of ' + CONVERT(NVARCHAR(15), @rowmodctr) + ' and ' + CONVERT(NVARCHAR(15), @record_count) + ' rows' + CASE WHEN ISNULL(@stats_isincremental,0) = 1 THEN ' on partition ' + CONVERT(NVARCHAR(15), @partitionNumber) ELSE '' END + '...';
  2033. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2034. END
  2035. /* Because we are reorganizing, we will update statistics if they have changed since last update with same threshold as TF2371.
  2036. Default rules for auto update stats are:
  2037. If the cardinality for a table is greater than 6, but less than or equal to 500, update status every 500 modifications.
  2038. If the cardinality for a table is greater than 500, update statistics when (500 + 20 percent of the table) changes have occurred.
  2039. Reference: http://docs.microsoft.com/sql/relational-databases/statistics/statistics and http://support.microsoft.com/kb/195565
  2040. */
  2041. IF (@statsThreshold IS NOT NULL AND @statsThreshold BETWEEN 0.001 AND 100.0 AND @statsMinRows IS NULL AND (@rowmodctr*100)/@record_count >= @statsThreshold)
  2042. 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)
  2043. OR (@statsThreshold IS NULL AND (
  2044. (@record_count BETWEEN 6 AND 500 AND @rowmodctr >= 500) OR -- like the default
  2045. (@record_count BETWEEN 501 AND 10000 AND (@rowmodctr >= (@record_count*20)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) OR -- 500 + 20 percent or simulate TF 2371
  2046. (@record_count BETWEEN 10001 AND 100000 AND (@rowmodctr >= (@record_count*15)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) OR -- 500 + 15 percent or simulate TF 2371
  2047. (@record_count BETWEEN 100001 AND 1000000 AND (@rowmodctr >= (@record_count*10)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) OR -- 500 + 10 percent or simulate TF 2371
  2048. (@record_count >= 1000001 AND (@rowmodctr >= (@record_count*5)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) -- 500 + 5 percent or simulate TF 2371
  2049. ))
  2050. BEGIN
  2051. SET @sqlcommand2 = N'UPDATE STATISTICS ' + @dbName + N'.'+ @schemaName + N'.' + @objectName + N' (' + @statsName + N')'
  2052. IF UPPER(@statsSample) = 'FULLSCAN' AND (@partitionNumber = 1 OR @partitionNumber = @maxpartitionNumber)
  2053. SET @sqlcommand2 = @sqlcommand2 + N' WITH FULLSCAN'
  2054. IF ISNUMERIC(@statsSample) = 1 AND (@partitionNumber = 1 OR @partitionNumber = @maxpartitionNumber)
  2055. SET @sqlcommand2 = @sqlcommand2 + N' WITH SAMPLE ' + @statsSample + ' PERCENT'
  2056. IF UPPER(@statsSample) = 'RESAMPLE'
  2057. SET @sqlcommand2 = @sqlcommand2 + N' WITH RESAMPLE'
  2058. IF (UPPER(@statsSample) = 'FULLSCAN' OR ISNUMERIC(@statsSample) = 1) AND @persistStatsSample = 1
  2059. AND UPPER(@sqlcommand2) LIKE '%WITH%' AND @sqlmajorver = 13 AND @sqlbuild >= 4446
  2060. SET @sqlcommand2 = @sqlcommand2 + N', PERSIST_SAMPLE_PERCENT = ON'
  2061. IF (UPPER(@statsSample) = 'FULLSCAN' OR ISNUMERIC(@statsSample) = 1) AND @persistStatsSample = 0
  2062. AND UPPER(@sqlcommand2) LIKE '%WITH%' AND @sqlmajorver = 13 AND @sqlbuild >= 4446
  2063. SET @sqlcommand2 = @sqlcommand2 + N', PERSIST_SAMPLE_PERCENT = OFF'
  2064. IF @partitionCount > 1 AND @stats_isincremental = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE') AND UPPER(@sqlcommand2) LIKE '%WITH%'
  2065. SET @sqlcommand2 = @sqlcommand2 + N' ON PARTITIONS(' + CONVERT(NVARCHAR(10), @partitionNumber) + N');'
  2066. ELSE IF @partitionCount > 1 AND @stats_isincremental = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE') AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2067. SET @sqlcommand2 = @sqlcommand2 + N' WITH RESAMPLE ON PARTITIONS(' + CONVERT(NVARCHAR(10), @partitionNumber) + N')'
  2068. IF @stats_norecompute = 1 AND UPPER(@sqlcommand2) LIKE '%WITH%'
  2069. SET @sqlcommand2 = @sqlcommand2 + N' ,NORECOMPUTE'
  2070. ELSE IF @stats_norecompute = 1 AND @sqlcommand2 NOT LIKE '%WITH%'
  2071. SET @sqlcommand2 = @sqlcommand2 + N' WITH NORECOMPUTE'
  2072. IF @maxDopRestriction IS NOT NULL
  2073. AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
  2074. AND UPPER(@sqlcommand2) LIKE '%WITH%'
  2075. SET @sqlcommand2 = @sqlcommand2 + N' ,MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
  2076. ELSE IF @maxDopRestriction IS NOT NULL
  2077. AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
  2078. AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2079. SET @sqlcommand2 = @sqlcommand2 + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
  2080. /* For list of incremental stats unsupported scenarios check http://docs.microsoft.com/sql/t-sql/statements/update-statistics-transact-sql */
  2081. IF @partitionCount > 1 AND @statsIncremental = 1 AND @has_filter = 0
  2082. BEGIN
  2083. IF UPPER(@sqlcommand2) LIKE '%WITH%'
  2084. SET @sqlcommand2 = @sqlcommand2 + N' ,INCREMENTAL = ON'
  2085. ELSE IF UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2086. SET @sqlcommand2 = @sqlcommand2 + N'WITH INCREMENTAL = ON'
  2087. END
  2088. ELSE IF @statsIncremental = 0
  2089. BEGIN
  2090. IF UPPER(@sqlcommand2) LIKE '%WITH%'
  2091. SET @sqlcommand2 = @sqlcommand2 + N', INCREMENTAL = OFF'
  2092. ELSE IF UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2093. SET @sqlcommand2 = @sqlcommand2 + N'WITH INCREMENTAL = OFF'
  2094. END
  2095. SET @sqlcommand2 = @sqlcommand2 + N';'
  2096. END
  2097. ELSE
  2098. BEGIN
  2099. SET @sqlcommand2 = NULL
  2100. END
  2101. /* Are we executing the SQL? If so, do it */
  2102. IF @Exec_Print = 1 AND @sqlcommand2 IS NOT NULL
  2103. BEGIN
  2104. SET @debugMessage = ' ' + @sqlcommand2;
  2105. /* Print the commands we'll be executing, if specified to do so */
  2106. IF (@printCmds = 1 OR @debugMode = 1)
  2107. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2108. /* Get the time for logging purposes */
  2109. SET @dateTimeStart = GETDATE();
  2110. /* Log actions */
  2111. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log (dbID, dbName, objectID, objectName, statsID, statsName, [partitionNumber], [rows], rows_sampled, modification_counter, [no_recompute], dateTimeStart, sqlStatement)
  2112. SELECT @dbID, @dbName, @objectID, @objectName, @statsID, @statsName, @partitionNumber, @record_count, @rows_sampled, @rowmodctr, @stats_norecompute, @dateTimeStart, @sqlcommand2;
  2113. SET @statsUpdate_id = SCOPE_IDENTITY();
  2114. /* Wrap execution attempt in a TRY/CATCH and log any errors that occur */
  2115. IF @operationFlag = 0
  2116. BEGIN
  2117. BEGIN TRY
  2118. /* Execute update! */
  2119. EXECUTE sp_executesql @sqlcommand2;
  2120. SET @dateTimeEnd = GETDATE();
  2121. SET @sqlcommand2 = NULL
  2122. /* Update log with completion time */
  2123. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2124. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd)
  2125. WHERE statsUpdate_id = @statsUpdate_id AND partitionNumber = @partitionNumber AND dateTimeEnd IS NULL;
  2126. /* Update working table */
  2127. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2128. SET updateDate = GETDATE(), printStatus = 1
  2129. WHERE dbID = @dbID AND objectID = @objectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2130. END TRY
  2131. BEGIN CATCH
  2132. /* Update log with error message */
  2133. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2134. SET dateTimeEnd = GETDATE(), durationSeconds = -1, errorMessage = 'Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing this command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  2135. WHERE statsUpdate_id = @statsUpdate_id AND partitionNumber = @partitionNumber AND dateTimeEnd IS NULL;
  2136. /* Update working table */
  2137. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2138. SET updateDate = GETDATE(), printStatus = 1
  2139. WHERE dbID = @dbID AND objectID = @objectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2140. IF @debugMode = 1
  2141. BEGIN
  2142. SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing this command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  2143. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2144. --RAISERROR(' An error has occurred executing this command. Please review the tbl_AdaptiveIndexDefrag_Stats_log table for details.', 0, 42) WITH NOWAIT;
  2145. END
  2146. END CATCH
  2147. END
  2148. END
  2149. ELSE IF @Exec_Print = 1 AND @sqlcommand2 IS NULL
  2150. BEGIN
  2151. IF @debugMode = 1
  2152. BEGIN
  2153. SELECT @debugMessage = ' No need to update statistic ' + @statsName + ' on table or view ' + @objectName + ' of DB ' + @dbName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2154. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2155. END
  2156. IF @printCmds = 1 AND @debugMode = 0
  2157. BEGIN
  2158. SELECT @debugMessage = ' -- No need to update statistic ' + @statsName + ' on table or view ' + @objectName + ' of DB ' + @dbName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2159. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2160. END
  2161. /* Update working table */
  2162. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2163. SET updateDate = GETDATE(), printStatus = 1
  2164. WHERE dbID = @dbID AND objectID = @objectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2165. /* Log actions */
  2166. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log (dbID, dbName, objectID, objectName, statsID, statsName, [partitionNumber], [rows], rows_sampled, modification_counter, [no_recompute], dateTimeStart, dateTimeEnd, durationSeconds, sqlStatement)
  2167. SELECT @dbID, @dbName, @objectID, @objectName, @statsID, @statsName, @partitionNumber, @record_count, ISNULL(@rows_sampled,-1), @rowmodctr, @stats_norecompute, @dateTimeStart, @dateTimeStart, -1, @sqlcommand2;
  2168. END
  2169. ELSE IF @Exec_Print = 0
  2170. BEGIN
  2171. IF @debugMode = 1 AND @sqlcommand2 IS NULL
  2172. BEGIN
  2173. SET @debugMessage = ' No need to update statistic ' + @statsName + ' on table or view ' + @objectName + ' of DB ' + @dbName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2174. IF @debugMessage IS NOT NULL
  2175. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2176. END
  2177. /* Print the commands we're executing if specified to do so */
  2178. IF (@printCmds = 1 OR @debugMode = 1) AND @sqlcommand2 IS NOT NULL
  2179. BEGIN
  2180. SET @debugMessage = ' ' + @sqlcommand2;
  2181. IF @debugMessage IS NOT NULL
  2182. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2183. END
  2184. IF @printCmds = 1 AND @debugMode = 0 AND @sqlcommand2 IS NULL
  2185. BEGIN
  2186. SET @debugMessage = ' -- No need to update statistic ' + @statsName + ' on table or view ' + @objectName + ' of DB ' + @dbName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2187. IF @debugMessage IS NOT NULL
  2188. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2189. END
  2190. /* Update working table */
  2191. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2192. SET printStatus = 1
  2193. WHERE dbID = @dbID AND objectID = @objectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2194. END
  2195. END
  2196. END;
  2197. /* Handling all the other statistics not covered before*/
  2198. IF @updateStats = 1 -- When reorganizing, update stats afterwards
  2199. AND @updateStatsWhere = 0 -- @updateStatsWhere = 0 then table-wide statistics;
  2200. AND (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss WHERE ((@Exec_Print = 1 AND idss.updateDate IS NULL) OR (@Exec_Print = 0 AND idss.updateDate IS NULL AND idss.printStatus = 0))) > 0 --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)) > 0 -- If any unhandled statistics remain
  2201. BEGIN
  2202. IF @debugMode = 1
  2203. RAISERROR(' Updating all other unhandled statistics using finer thresholds (if any)...', 0, 42) WITH NOWAIT;
  2204. WHILE (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss WHERE ((@Exec_Print = 1 AND idss.updateDate IS NULL) OR (@Exec_Print = 0 AND idss.updateDate IS NULL AND idss.printStatus = 0))) > 0 --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)) > 0
  2205. BEGIN
  2206. /* Check to see if we need to exit loop because of our time limit */
  2207. IF ISNULL(@endDateTime, GETDATE()) < GETDATE()
  2208. RAISERROR('Time limit has been exceeded for this maintenance window!', 16, 42) WITH NOWAIT;
  2209. IF @debugMode = 1
  2210. RAISERROR(' Selecting a statistic to update...', 0, 42) WITH NOWAIT;
  2211. /* Select the stat */
  2212. IF @Exec_Print = 1
  2213. BEGIN
  2214. SELECT TOP 1 @statsID = idss.statsID, @dbID = idss.dbID, @statsobjectID = idss.objectID, @dbName = idss.dbName, @statsobjectName = idss.objectName, @statsschemaName = idss.schemaName, @partitionNumber = idss.partitionNumber
  2215. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss
  2216. 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)
  2217. END
  2218. ELSE IF @Exec_Print = 0
  2219. BEGIN
  2220. SELECT TOP 1 @statsID = idss.statsID, @dbID = idss.dbID, @statsobjectID = idss.objectID, @dbName = idss.dbName, @statsobjectName = idss.objectName, @statsschemaName = idss.schemaName, @partitionNumber = idss.partitionNumber
  2221. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working idss
  2222. WHERE idss.updateDate IS NULL AND idss.printStatus = 0 --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)
  2223. END
  2224. /* Get stat associated table record count */
  2225. BEGIN TRY
  2226. 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'
  2227. SET @getStatSQL_Param = N'@statsID_In int, @dbID_In int, @statsobjectID_In int, @record_count_Out bigint OUTPUT'
  2228. EXECUTE sp_executesql @getStatSQL, @getStatSQL_Param, @statsID_In = @statsID, @dbID_In = @dbID, @statsobjectID_In = @statsobjectID, @record_count_Out = @record_count OUTPUT;
  2229. END TRY
  2230. BEGIN CATCH
  2231. IF @debugMode = 1
  2232. BEGIN
  2233. SET @debugMessage = ' Error ' + CONVERT(VARCHAR(20),ERROR_NUMBER()) + ' has occurred while getting stat associated table row count. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS VARCHAR(10)) + ')'
  2234. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2235. END
  2236. END CATCH
  2237. IF @debugMode = 1
  2238. RAISERROR(' Getting information on selected statistic...', 0, 42) WITH NOWAIT;
  2239. /* Get object name and auto update setting */
  2240. SELECT TOP 1 @statsName = statsName, @stats_norecompute = [no_recompute], @stats_isincremental = [is_incremental]
  2241. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2242. WHERE objectID = @statsobjectID AND statsID = @statsID AND [dbID] = @dbID AND partitionNumber = @partitionNumber;
  2243. IF @debugMode = 1
  2244. BEGIN
  2245. SET @debugMessage = ' Determining modification row counter for statistic ' + @statsName + ' on table or view ' + @statsobjectName + ' of DB ' + @dbName + '...';
  2246. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2247. END
  2248. /* Determine modification row counter to ascertain if update stats is required */
  2249. IF ((@sqlmajorver = 12 AND @sqlbuild >= 5000) OR (@sqlmajorver = 13 AND @sqlbuild >= 4000) OR @sqlmajorver > 13) AND ISNULL(@stats_isincremental,1) = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE')
  2250. BEGIN
  2251. IF @debugMode = 1
  2252. RAISERROR(' Using sys.dm_db_incremental_stats_properties DMF...', 0, 42) WITH NOWAIT;
  2253. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = ISNULL(modification_counter,0), @rows_Out = ISNULL(rows,0), @rows_sampled_Out = ISNULL(rows_sampled,0) FROM sys.dm_db_incremental_stats_properties(@statsobjectID_In, @statsID_In) WHERE partition_number = @partitionNumber_In;'
  2254. END
  2255. ELSE IF ((@sqlmajorver = 12 AND @sqlbuild < 5000) OR (@sqlmajorver = 13 AND @sqlbuild < 4000)) AND ISNULL(@stats_isincremental,1) = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE')
  2256. BEGIN
  2257. IF @debugMode = 1
  2258. RAISERROR(' Using sys.dm_db_stats_properties_internal DMF...', 0, 42) WITH NOWAIT;
  2259. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = ISNULL(modification_counter,0), @rows_Out = ISNULL(rows,0), @rows_sampled_Out = ISNULL(rows_sampled,0) FROM sys.dm_db_stats_properties_internal(@statsobjectID_In, @statsID_In) WHERE partition_number = @partitionNumber_In;'
  2260. END
  2261. ELSE IF ((@sqlmajorver = 10 AND @sqlminorver = 50 AND @sqlbuild >= 4000) OR (@sqlmajorver = 11 AND @sqlbuild >= 3000) OR @sqlmajorver >= 12) AND (ISNULL(@stats_isincremental,1) = 0 OR UPPER(@statsSample) = 'FULLSCAN' OR ISNUMERIC(@statsSample) = 1)
  2262. BEGIN
  2263. IF @debugMode = 1
  2264. RAISERROR(' Using sys.dm_db_stats_properties DMF...', 0, 42) WITH NOWAIT;
  2265. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = ISNULL(modification_counter,0), @rows_Out = ISNULL(rows,0), @rows_sampled_Out = ISNULL(rows_sampled,0) FROM sys.dm_db_stats_properties(@statsobjectID_In, @statsID_In);'
  2266. END
  2267. ELSE
  2268. BEGIN
  2269. IF @debugMode = 1
  2270. RAISERROR(' Using sys.sysindexes...', 0, 42) WITH NOWAIT;
  2271. SELECT TOP 1 @surrogateStatsID = indexID FROM dbo.tbl_AdaptiveIndexDefrag_Working (NOLOCK) WHERE objectID = @statsobjectID AND indexName = @statsName
  2272. SELECT @rowmodctrSQL = N'USE ' + @dbName + '; SELECT @rowmodctr_Out = SUM(ISNULL(rowmodctr,0)), @rows_Out = ISNULL(rowcnt,0), @rows_sampled_Out = -1 FROM sys.sysindexes WHERE id = @statsobjectID_In AND indid = @statsID_In AND rowmodctr > 0;'
  2273. IF @statsID IS NULL
  2274. SET @statsID = @surrogateStatsID
  2275. END
  2276. SET @rowmodctrSQL_Param = N'@partitionNumber_In smallint, @statsobjectID_In int, @statsID_In int, @rowmodctr_Out bigint OUTPUT, @rows_Out bigint OUTPUT, @rows_sampled_Out bigint OUTPUT'
  2277. BEGIN TRY
  2278. EXECUTE sp_executesql @rowmodctrSQL, @rowmodctrSQL_Param, @statsobjectID_In = @statsobjectID, @statsID_In = @statsID, @partitionNumber_In = @partitionNumber, @rowmodctr_Out = @rowmodctr OUTPUT, @rows_Out = @rows OUTPUT, @rows_sampled_Out = @rows_sampled OUTPUT;
  2279. SET @rowmodctr = (SELECT ISNULL(@rowmodctr, 0));
  2280. END TRY
  2281. BEGIN CATCH
  2282. IF @debugMode = 1
  2283. BEGIN
  2284. SET @debugMessage = ' Error ' + CONVERT(VARCHAR(20),ERROR_NUMBER()) + ' has occurred while determining row modification counter. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS VARCHAR(10)) + ')'
  2285. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2286. END
  2287. END CATCH
  2288. IF @rows IS NOT NULL AND @rows > 0
  2289. SET @record_count = @rows
  2290. IF @debugMode = 1
  2291. BEGIN
  2292. SELECT @debugMessage = ' Found a row modification counter of ' + CONVERT(NVARCHAR(15), @rowmodctr) + ' and ' + CONVERT(NVARCHAR(15), CASE WHEN @rows IS NOT NULL AND @rows < @record_count THEN @rows ELSE @record_count END) + ' rows' + CASE WHEN @stats_isincremental = 1 THEN ' on partition ' + CONVERT(NVARCHAR(15), @partitionNumber) ELSE '' END + '...';
  2293. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2294. --select @debugMessage
  2295. END
  2296. /* We will update statistics if they have changed since last update with customized, more finer values, just like when TF2371 is enabled for Auto-Update.
  2297. Default rules for auto update stats are:
  2298. If the cardinality for a table is greater than 6, but less than or equal to 500, update status every 500 modifications.
  2299. If the cardinality for a table is greater than 500, update statistics when (500 + 20 percent of the table) changes have occurred.
  2300. */
  2301. IF (@statsThreshold IS NOT NULL AND @statsThreshold BETWEEN 0.001 AND 100.0 AND @statsMinRows IS NULL AND (@rowmodctr*100)/@record_count >= @statsThreshold)
  2302. 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)
  2303. OR (@statsThreshold IS NULL AND (
  2304. (@record_count BETWEEN 6 AND 500 AND @rowmodctr >= 500) OR -- like the default
  2305. (@record_count BETWEEN 501 AND 10000 AND (@rowmodctr >= (@record_count*20)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) OR -- 500 + 20 percent or simulate TF 2371
  2306. (@record_count BETWEEN 10001 AND 100000 AND (@rowmodctr >= (@record_count*15)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) OR -- 500 + 15 percent or simulate TF 2371
  2307. (@record_count BETWEEN 100001 AND 1000000 AND (@rowmodctr >= (@record_count*10)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) OR -- 500 + 10 percent or simulate TF 2371
  2308. (@record_count >= 1000001 AND (@rowmodctr >= (@record_count*5)/100 + 500 OR @rowmodctr >= SQRT(@record_count*1000))) -- 500 + 5 percent or simulate TF 2371
  2309. ))
  2310. BEGIN
  2311. SET @sqlcommand2 = N'UPDATE STATISTICS ' + @dbName + N'.' + @statsschemaName + N'.' + @statsobjectName + N' (' + @statsName + N')'
  2312. IF UPPER(@statsSample) = 'FULLSCAN' AND (@partitionNumber = 1 OR @partitionNumber = @maxpartitionNumber)
  2313. SET @sqlcommand2 = @sqlcommand2 + N' WITH FULLSCAN'
  2314. IF ISNUMERIC(@statsSample) = 1 AND (@partitionNumber = 1 OR @partitionNumber = @maxpartitionNumber)
  2315. SET @sqlcommand2 = @sqlcommand2 + N' WITH SAMPLE ' + @statsSample + ' PERCENT'
  2316. IF UPPER(@statsSample) = 'RESAMPLE'
  2317. SET @sqlcommand2 = @sqlcommand2 + N' WITH RESAMPLE'
  2318. IF (UPPER(@statsSample) = 'FULLSCAN' OR ISNUMERIC(@statsSample) = 1) AND @persistStatsSample = 1
  2319. AND UPPER(@sqlcommand2) LIKE '%WITH%' AND @sqlmajorver = 13 AND @sqlbuild >= 4446
  2320. SET @sqlcommand2 = @sqlcommand2 + N', PERSIST_SAMPLE_PERCENT = ON'
  2321. IF (UPPER(@statsSample) = 'FULLSCAN' OR ISNUMERIC(@statsSample) = 1) AND @persistStatsSample = 0
  2322. AND UPPER(@sqlcommand2) LIKE '%WITH%' AND @sqlmajorver = 13 AND @sqlbuild >= 4446
  2323. SET @sqlcommand2 = @sqlcommand2 + N', PERSIST_SAMPLE_PERCENT = OFF'
  2324. IF @stats_isincremental = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE') AND UPPER(@sqlcommand2) LIKE '%WITH%'
  2325. SET @sqlcommand2 = @sqlcommand2 + N' ON PARTITIONS(' + CONVERT(NVARCHAR(10), @partitionNumber) + N');'
  2326. ELSE IF @stats_isincremental = 1 AND (@statsSample IS NULL OR UPPER(@statsSample) = 'RESAMPLE') AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2327. SET @sqlcommand2 = @sqlcommand2 + N' WITH RESAMPLE ON PARTITIONS(' + CONVERT(NVARCHAR(10), @partitionNumber) + N')'
  2328. IF @stats_norecompute = 1 AND UPPER(@sqlcommand2) LIKE '%WITH%'
  2329. SET @sqlcommand2 = @sqlcommand2 + N' ,NORECOMPUTE'
  2330. ELSE IF @stats_norecompute = 1 AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2331. SET @sqlcommand2 = @sqlcommand2 + N' WITH NORECOMPUTE'
  2332. IF @maxDopRestriction IS NOT NULL
  2333. AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
  2334. AND UPPER(@sqlcommand2) LIKE '%WITH%'
  2335. SET @sqlcommand2 = @sqlcommand2 + N' ,MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
  2336. ELSE IF @maxDopRestriction IS NOT NULL
  2337. AND ((@sqlmajorver >= 14 AND @sqlbuild >= 3015) /*OR (@sqlmajorver = 13 AND @sqlbuild >= xxxx)*/) -- SQL 2016 SP2, SQL 2017 CU3 or higher for MAXDOP in stats
  2338. AND UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2339. SET @sqlcommand2 = @sqlcommand2 + N' WITH MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(3));
  2340. /* For list of incremental stats unsupported scenarios check http://docs.microsoft.com/sql/t-sql/statements/update-statistics-transact-sql */
  2341. IF @partitionCount > 1 AND @statsIncremental = 1 AND @has_filter = 0
  2342. BEGIN
  2343. IF UPPER(@sqlcommand2) LIKE '%WITH%'
  2344. SET @sqlcommand2 = @sqlcommand2 + N' ,INCREMENTAL = ON'
  2345. ELSE IF UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2346. SET @sqlcommand2 = @sqlcommand2 + N'WITH INCREMENTAL = ON'
  2347. END
  2348. ELSE IF @statsIncremental = 0
  2349. BEGIN
  2350. IF UPPER(@sqlcommand2) LIKE '%WITH%'
  2351. SET @sqlcommand2 = @sqlcommand2 + N', INCREMENTAL = OFF'
  2352. ELSE IF UPPER(@sqlcommand2) NOT LIKE '%WITH%'
  2353. SET @sqlcommand2 = @sqlcommand2 + N'WITH INCREMENTAL = OFF'
  2354. END
  2355. SET @sqlcommand2 = @sqlcommand2 + N';'
  2356. END
  2357. ELSE
  2358. BEGIN
  2359. SET @sqlcommand2 = NULL
  2360. END;
  2361. /* Are we executing the SQL? If so, do it */
  2362. IF @Exec_Print = 1 AND @sqlcommand2 IS NOT NULL
  2363. BEGIN
  2364. SET @debugMessage = ' ' + @sqlcommand2;
  2365. /* Print the commands we're executing if specified to do so */
  2366. IF (@printCmds = 1 OR @debugMode = 1)
  2367. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2368. /* Get the time for logging purposes */
  2369. SET @dateTimeStart = GETDATE();
  2370. /* Log actions */
  2371. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log (dbID, dbName, objectID, objectName, statsID, statsName, [partitionNumber], [rows], rows_sampled, modification_counter, [no_recompute], dateTimeStart, sqlStatement)
  2372. SELECT @dbID, @dbName, @statsobjectID, @statsobjectName, @statsID, @statsName, @partitionNumber, @record_count, @rows_sampled, @rowmodctr, @stats_norecompute, @dateTimeStart, @sqlcommand2;
  2373. SET @statsUpdate_id = SCOPE_IDENTITY();
  2374. /* Wrap execution attempt in a TRY/CATCH and log any errors that occur */
  2375. BEGIN TRY
  2376. /* Execute update! */
  2377. EXECUTE sp_executesql @sqlcommand2;
  2378. SET @dateTimeEnd = GETDATE();
  2379. SET @sqlcommand2 = NULL
  2380. /* Update log with completion time */
  2381. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2382. SET dateTimeEnd = @dateTimeEnd, durationSeconds = DATEDIFF(second, @dateTimeStart, @dateTimeEnd)
  2383. WHERE statsUpdate_id = @statsUpdate_id AND partitionNumber = @partitionNumber AND dateTimeEnd IS NULL;
  2384. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2385. SET updateDate = GETDATE(), printStatus = 1
  2386. WHERE dbID = @dbID AND objectID = @statsobjectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2387. END TRY
  2388. BEGIN CATCH
  2389. /* Update log with error message */
  2390. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2391. SET dateTimeEnd = GETDATE(), durationSeconds = -1, errorMessage = 'Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing this command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  2392. WHERE statsUpdate_id = @statsUpdate_id AND partitionNumber = @partitionNumber AND dateTimeEnd IS NULL;
  2393. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2394. SET updateDate = GETDATE(), printStatus = 1
  2395. WHERE dbID = @dbID AND objectID = @statsobjectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2396. IF @debugMode = 1
  2397. BEGIN
  2398. SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred executing this command. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  2399. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2400. --RAISERROR(' An error has occurred executing this command. Please review the tbl_AdaptiveIndexDefrag_Stats_log table for details.', 0, 42) WITH NOWAIT;
  2401. END
  2402. END CATCH
  2403. END
  2404. ELSE IF @Exec_Print = 1 AND @sqlcommand2 IS NULL
  2405. BEGIN
  2406. IF @debugMode = 1
  2407. BEGIN
  2408. SET @debugMessage = ' No need to update statistic ' + @statsName + ' on DB ' + @dbName + ' and object ' + @statsobjectName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2409. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2410. END
  2411. IF @printCmds = 1 AND @debugMode = 0
  2412. BEGIN
  2413. SET @debugMessage = ' -- No need to update statistic ' + @statsName + ' on DB ' + @dbName + ' and object ' + @statsobjectName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2414. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2415. END
  2416. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2417. SET updateDate = GETDATE(), printStatus = 1
  2418. WHERE dbID = @dbID AND objectID = @statsobjectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2419. /* Get the time for logging purposes */
  2420. IF @dateTimeStart IS NULL
  2421. SET @dateTimeStart = GETDATE();
  2422. /* Log actions */
  2423. INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Stats_log (dbID, dbName, objectID, objectName, statsID, statsName, [partitionNumber], [rows], rows_sampled, modification_counter, [no_recompute], dateTimeStart, dateTimeEnd, durationSeconds, sqlStatement)
  2424. SELECT @dbID, @dbName, @objectID, @objectName, @statsID, @statsName, @partitionNumber, @record_count, ISNULL(@rows_sampled,-1), @rowmodctr, @stats_norecompute, @dateTimeStart, @dateTimeStart, -1, @sqlcommand2;
  2425. END
  2426. ELSE IF @Exec_Print = 0
  2427. BEGIN
  2428. IF @debugMode = 1 AND @sqlcommand2 IS NULL
  2429. BEGIN
  2430. SET @debugMessage = ' No need to update statistic ' + @statsName + ' on DB ' + @dbName + ' and object ' + @statsobjectName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2431. IF @debugMessage IS NOT NULL
  2432. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2433. END
  2434. /* Print the commands we're executing if specified to do so */
  2435. IF (@printCmds = 1 OR @debugMode = 1) AND @sqlcommand2 IS NOT NULL
  2436. BEGIN
  2437. SET @debugMessage = ' ' + @sqlcommand2;
  2438. IF @debugMessage IS NOT NULL
  2439. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2440. END
  2441. IF @printCmds = 1 AND @debugMode = 0 AND @sqlcommand2 IS NULL
  2442. BEGIN
  2443. SET @debugMessage = ' -- No need to update statistic ' + @statsName + ' on DB ' + @dbName + ' and object ' + @statsobjectName + CASE WHEN @stats_isincremental = 1 THEN ', on partition ' + CONVERT(NVARCHAR(10), @partitionNumber) ELSE '' END + '...';
  2444. IF @debugMessage IS NOT NULL
  2445. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2446. END
  2447. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2448. SET printStatus = 1
  2449. WHERE dbID = @dbID AND objectID = @statsobjectID AND statsID = @statsID AND partitionNumber = @partitionNumber;
  2450. END
  2451. END
  2452. IF (@printCmds = 1 OR @debugMode = 1)
  2453. PRINT ' No remaining statistics to update...';
  2454. END
  2455. ELSE
  2456. BEGIN
  2457. IF (@printCmds = 1 OR @debugMode = 1)
  2458. PRINT ' No remaining statistics to update...';
  2459. END
  2460. /* Output results? */
  2461. IF @outputResults = 1 AND @Exec_Print = 1
  2462. BEGIN
  2463. IF (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate >= @startDateTime) > 0
  2464. OR (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working WHERE updateDate >= @startDateTime) > 0
  2465. BEGIN
  2466. IF @debugMode = 1
  2467. RAISERROR(' Displaying a summary of our actions...', 0, 42) WITH NOWAIT;
  2468. SELECT [dbName], objectName, indexName, partitionNumber, CONVERT(decimal(9,2),fragmentation) AS fragmentation, page_count, fill_factor, range_scan_count, defragDate
  2469. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2470. WHERE defragDate >= @startDateTime
  2471. ORDER BY defragDate;
  2472. SELECT [dbName], [statsName], partitionNumber, [no_recompute], [is_incremental], updateDate
  2473. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2474. WHERE updateDate >= @startDateTime
  2475. ORDER BY updateDate;
  2476. IF @debugMode = 1 AND (SELECT COUNT(*) FROM dbo.tbl_AdaptiveIndexDefrag_log WHERE errorMessage IS NOT NULL AND dateTimeStart >= @startDateTime) > 0
  2477. BEGIN
  2478. RAISERROR('Displaying a summary of all errors...', 0, 42) WITH NOWAIT;
  2479. SELECT dbName, objectName, indexName, partitionNumber, dateTimeStart, dateTimeEnd, sqlStatement, errorMessage
  2480. FROM dbo.tbl_AdaptiveIndexDefrag_log
  2481. WHERE errorMessage IS NOT NULL AND dateTimeStart >= @startDateTime
  2482. ORDER BY dateTimeStart;
  2483. END
  2484. IF @debugMode = 1
  2485. RAISERROR(' Displaying some statistical information about this defragmentation run...', 0, 42) WITH NOWAIT;
  2486. SELECT TOP 10 'Longest time' AS Comment, dbName, objectName, indexName, partitionNumber, dateTimeStart, dateTimeEnd, durationSeconds
  2487. FROM dbo.tbl_AdaptiveIndexDefrag_log
  2488. WHERE dateTimeStart >= @startDateTime
  2489. ORDER BY durationSeconds DESC;
  2490. END
  2491. END;
  2492. END TRY
  2493. BEGIN CATCH
  2494. SET @debugMessage = ' Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ' has occurred. Message: ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')'
  2495. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2496. END CATCH;
  2497. /* Reset printStatus */
  2498. IF @debugMode = 1
  2499. RAISERROR(' Reseting working table statuses.', 0, 42) WITH NOWAIT;
  2500. UPDATE dbo.tbl_AdaptiveIndexDefrag_Working
  2501. SET printStatus = 0;
  2502. UPDATE dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2503. SET printStatus = 0;
  2504. /* Drop all temp tables */
  2505. IF @debugMode = 1
  2506. RAISERROR(' Dropping temporary objects', 0, 42) WITH NOWAIT;
  2507. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragDatabaseList'))
  2508. DROP TABLE #tblIndexDefragDatabaseList;
  2509. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragmaxPartitionList'))
  2510. DROP TABLE #tblIndexDefragmaxPartitionList;
  2511. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexDefragScanWorking'))
  2512. DROP TABLE #tblIndexDefragScanWorking;
  2513. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#tblIndexFindInDatabaseList'))
  2514. DROP TABLE #tblIndexFindInDatabaseList;
  2515. IF @debugMode = 1
  2516. RAISERROR('All done!', 0, 42) WITH NOWAIT;
  2517. IF @Exec_Print = 0
  2518. BEGIN
  2519. IF @ignoreDropObj = 0
  2520. BEGIN
  2521. IF (SELECT COUNT([errorMessage]) FROM dbo.vw_LastRun_Log) > 0 AND @ignoreDropObj = 0
  2522. BEGIN
  2523. RAISERROR('Defrag job found execution errors! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 16, 42) WITH NOWAIT;
  2524. RETURN -1
  2525. END
  2526. ELSE
  2527. BEGIN
  2528. RETURN 0
  2529. END
  2530. END
  2531. ELSE
  2532. BEGIN
  2533. IF (SELECT COUNT([errorMessage]) FROM dbo.vw_LastRun_Log WHERE [errorMessage] NOT LIKE 'Table%does not exist%') > 0
  2534. BEGIN
  2535. RAISERROR('Defrag job found execution errors! Please review the tbl_AdaptiveIndexDefrag_log table for details.', 16, 42) WITH NOWAIT;
  2536. RETURN -1
  2537. END
  2538. ELSE
  2539. BEGIN
  2540. RETURN 0
  2541. END
  2542. END
  2543. END
  2544. END
  2545. GO
  2546. --EXEC sys.sp_MS_marksystemobject 'usp_AdaptiveIndexDefrag'
  2547. --GO
  2548. PRINT 'Procedure usp_AdaptiveIndexDefrag created';
  2549. GO
  2550. ------------------------------------------------------------------------------------------------------------------------------
  2551. CREATE VIEW vw_ErrLst30Days
  2552. AS
  2553. SELECT TOP 100 PERCENT dbName, objectName, indexName, partitionNumber, NULL AS statsName, dateTimeStart, dateTimeEnd, sqlStatement, errorMessage
  2554. FROM dbo.tbl_AdaptiveIndexDefrag_log
  2555. WHERE errorMessage IS NOT NULL AND dateTimeStart >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2556. UNION ALL
  2557. SELECT TOP 100 PERCENT dbName, objectName, NULL AS indexName, NULL AS partitionNumber, statsName, dateTimeStart, dateTimeEnd, sqlStatement, errorMessage
  2558. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2559. WHERE errorMessage IS NOT NULL AND dateTimeStart >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2560. ORDER BY dateTimeStart;
  2561. GO
  2562. CREATE VIEW vw_ErrLst24Hrs
  2563. AS
  2564. SELECT TOP 100 PERCENT dbName, objectName, indexName, partitionNumber, NULL AS statsName, dateTimeStart, dateTimeEnd, sqlStatement, errorMessage
  2565. FROM dbo.tbl_AdaptiveIndexDefrag_log
  2566. WHERE errorMessage IS NOT NULL AND dateTimeStart >= DATEADD(hh, -24, GETDATE())
  2567. UNION ALL
  2568. SELECT TOP 100 PERCENT dbName, objectName, NULL AS indexName, partitionNumber, statsName, dateTimeStart, dateTimeEnd, sqlStatement, errorMessage
  2569. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2570. WHERE errorMessage IS NOT NULL AND dateTimeStart >= DATEADD(hh, -24, GETDATE())
  2571. ORDER BY dateTimeStart;
  2572. GO
  2573. CREATE VIEW vw_AvgTimeLst30Days
  2574. AS
  2575. SELECT TOP 100 PERCENT 'Longest time' AS Comment, dbName, objectName, indexName, partitionNumber, AVG(durationSeconds) AS Avg_durationSeconds
  2576. FROM dbo.tbl_AdaptiveIndexDefrag_log
  2577. WHERE dateTimeStart >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2578. GROUP BY dbName, objectName, indexName, partitionNumber
  2579. ORDER BY AVG(durationSeconds) DESC, dbName, objectName, indexName, partitionNumber;
  2580. GO
  2581. CREATE VIEW vw_AvgFragLst30Days
  2582. AS
  2583. SELECT TOP 100 PERCENT 'Most fragmented' AS Comment, dbName, objectName, indexName, partitionNumber, CONVERT(decimal(9,2),AVG(fragmentation)) AS Avg_fragmentation
  2584. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2585. WHERE defragDate >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2586. GROUP BY dbName, objectName, indexName, partitionNumber
  2587. ORDER BY AVG(fragmentation) DESC, dbName, objectName, indexName, partitionNumber;
  2588. GO
  2589. CREATE VIEW vw_AvgSamplingLst30Days
  2590. AS
  2591. SELECT TOP 100 PERCENT 'Avg_Sampling' AS Comment, dbName, objectName, partitionNumber, statsName, CAST((rows_sampled/([rows]*1.00))*100.0 AS DECIMAL(5,2)) AS sampling, dateTimeStart, dateTimeEnd, sqlStatement, errorMessage
  2592. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2593. WHERE errorMessage IS NOT NULL AND dateTimeStart >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2594. ORDER BY dateTimeStart;
  2595. GO
  2596. CREATE VIEW vw_AvgLargestLst30Days
  2597. AS
  2598. SELECT TOP 100 PERCENT 'Largest' AS Comment, dbName, objectName, indexName, partitionNumber, AVG(page_count)*8 AS Avg_size_KB, fill_factor
  2599. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2600. WHERE defragDate >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2601. GROUP BY dbName, objectName, indexName, partitionNumber, fill_factor
  2602. ORDER BY AVG(page_count) DESC, dbName, objectName, indexName, partitionNumber
  2603. GO
  2604. CREATE VIEW vw_AvgMostUsedLst30Days
  2605. AS
  2606. SELECT TOP 100 PERCENT 'Most used' AS Comment, dbName, objectName, indexName, partitionNumber, AVG(range_scan_count) AS Avg_range_scan_count
  2607. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2608. WHERE defragDate >= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -30)
  2609. GROUP BY dbName, objectName, indexName, partitionNumber
  2610. ORDER BY AVG(range_scan_count) DESC;
  2611. GO
  2612. CREATE VIEW vw_LastRun_Log
  2613. AS
  2614. SELECT TOP 100 percent [dbName]
  2615. ,[objectName]
  2616. ,[indexName]
  2617. , NULL AS [statsName]
  2618. ,[partitionNumber]
  2619. ,[fragmentation]
  2620. ,[page_count]
  2621. ,[range_scan_count]
  2622. ,[dateTimeStart]
  2623. ,[dateTimeEnd]
  2624. ,[durationSeconds]
  2625. ,CASE WHEN [sqlStatement] LIKE '%REORGANIZE%' THEN 'Reorg' ELSE 'Rebuild' END AS [Operation]
  2626. ,[errorMessage]
  2627. FROM dbo.tbl_AdaptiveIndexDefrag_log ixlog
  2628. CROSS APPLY (SELECT TOP 1 minIxDate = CASE WHEN defragDate IS NULL THEN CONVERT(DATETIME, CONVERT(NVARCHAR, scanDate, 112))
  2629. ELSE CONVERT(DATETIME, CONVERT(NVARCHAR, defragDate, 112)) END
  2630. FROM [dbo].[tbl_AdaptiveIndexDefrag_Working]
  2631. ORDER BY defragDate ASC, scanDate ASC) AS minDateIxCte
  2632. WHERE dateTimeStart >= minIxDate
  2633. UNION ALL
  2634. SELECT TOP 100 percent [dbName]
  2635. ,[objectName]
  2636. ,NULL AS [indexName]
  2637. ,[statsName]
  2638. ,NULL AS [partitionNumber]
  2639. ,NULL AS [fragmentation]
  2640. ,NULL AS [page_count]
  2641. ,NULL AS [range_scan_count]
  2642. ,[dateTimeStart]
  2643. ,[dateTimeEnd]
  2644. ,[durationSeconds]
  2645. ,'UpdateStats' AS [Operation]
  2646. ,[errorMessage]
  2647. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log statlog
  2648. CROSS APPLY (SELECT TOP 1 minStatDate = CASE WHEN updateDate IS NULL THEN CONVERT(DATETIME, CONVERT(NVARCHAR, scanDate, 112))
  2649. ELSE CONVERT(DATETIME, CONVERT(NVARCHAR, updateDate, 112)) END
  2650. FROM [dbo].[tbl_AdaptiveIndexDefrag_Stats_Working]
  2651. ORDER BY updateDate ASC, scanDate ASC) AS minDateStatCte
  2652. WHERE dateTimeStart >= minStatDate
  2653. ORDER BY dateTimeEnd ASC
  2654. GO
  2655. PRINT 'Reporting views created';
  2656. GO
  2657. ------------------------------------------------------------------------------------------------------------------------------
  2658. CREATE PROCEDURE usp_AdaptiveIndexDefrag_PurgeLogs @daystokeep smallint = 90
  2659. AS
  2660. /*
  2661. usp_AdaptiveIndexDefrag_PurgeLogs.sql - [email protected] (http://aka.ms/AID)
  2662. Purge log tables to avoid indefinite growth.
  2663. Default is data older than 90 days.
  2664. Change @daystokeep as you deem fit.
  2665. */
  2666. SET NOCOUNT ON;
  2667. SET DATEFORMAT ymd;
  2668. DELETE FROM dbo.tbl_AdaptiveIndexDefrag_log
  2669. WHERE dateTimeStart <= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -@daystokeep);
  2670. DELETE FROM dbo.tbl_AdaptiveIndexDefrag_Stats_log
  2671. WHERE dateTimeStart <= DATEADD(dd, DATEDIFF(dd, 0, GETDATE()), -@daystokeep);
  2672. GO
  2673. --EXEC sys.sp_MS_marksystemobject 'usp_AdaptiveIndexDefrag_PurgeLogs'
  2674. --GO
  2675. PRINT 'Procedure usp_AdaptiveIndexDefrag_PurgeLogs created (Default purge is 90 days old)';
  2676. GO
  2677. ------------------------------------------------------------------------------------------------------------------------------
  2678. CREATE PROCEDURE usp_AdaptiveIndexDefrag_CurrentExecStats @dbname NVARCHAR(255) = NULL
  2679. AS
  2680. /*
  2681. usp_AdaptiveIndexDefrag_CurrentExecStats.sql - [email protected] (http://aka.ms/AID)
  2682. Allows monitoring of what has been done so far in the defrag loop.
  2683. Use @dbname to monitor a specific database
  2684. Example:
  2685. EXEC usp_AdaptiveIndexDefrag_CurrentExecStats @dbname = 'AdventureWorks2008R2'
  2686. */
  2687. SET NOCOUNT ON;
  2688. IF @dbname IS NULL
  2689. BEGIN
  2690. WITH cte1 ([Database_Name], Total_indexes) AS (SELECT [dbName], COUNT(indexID) AS Total_Indexes FROM dbo.tbl_AdaptiveIndexDefrag_Working GROUP BY [dbName]),
  2691. cte2 ([Database_Name], Defraged_Indexes) AS (SELECT [dbName], COUNT(indexID) AS Total_Indexes FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE defragDate IS NOT NULL OR printStatus = 1 GROUP BY [dbName]),
  2692. cte3 ([Database_Name], Total_statistics) AS (SELECT [dbName], COUNT(statsID) AS Total_statistics FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working GROUP BY [dbName]),
  2693. cte4 ([Database_Name], Updated_statistics) AS (SELECT [dbName], COUNT(statsID) AS Updated_statistics FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working WHERE updateDate IS NOT NULL OR printStatus = 1 GROUP BY [dbName])
  2694. SELECT cte1.[Database_Name], SUM(cte1.Total_indexes) AS Total_indexes, SUM(ISNULL(cte2.Defraged_Indexes, 0)) AS Defraged_Indexes,
  2695. SUM(cte3.Total_statistics) AS Total_statistics, SUM(ISNULL(cte4.Updated_statistics, 0)) AS Updated_statistics
  2696. FROM cte1 INNER JOIN cte3 ON cte1.Database_Name = cte3.Database_Name
  2697. LEFT JOIN cte2 ON cte1.Database_Name = cte2.Database_Name
  2698. LEFT JOIN cte4 ON cte1.Database_Name = cte4.Database_Name
  2699. GROUP BY cte1.[Database_Name];
  2700. SELECT 'Index' AS [Type], 'Done' AS [Result], dbName, objectName, indexName
  2701. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2702. WHERE defragDate IS NOT NULL OR printStatus = 1
  2703. UNION ALL
  2704. SELECT 'Index' AS [Type], 'To do' AS [Result], dbName, objectName, indexName
  2705. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2706. WHERE defragDate IS NULL AND printStatus = 0
  2707. ORDER BY 2, dbName, objectName, indexName;
  2708. SELECT 'Statistic' AS [Type], 'Done' AS [Result], dbName, objectName, statsName
  2709. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2710. WHERE updateDate IS NOT NULL OR printStatus = 1
  2711. UNION ALL
  2712. SELECT 'Statistic' AS [Type], 'To do' AS [Result], dbName, objectName, statsName
  2713. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2714. WHERE updateDate IS NULL AND printStatus = 0
  2715. ORDER BY 2, dbName, objectName, statsName;
  2716. END
  2717. ELSE
  2718. BEGIN
  2719. WITH cte1 ([Database_Name], Total_indexes) AS (SELECT [dbName], COUNT(indexID) AS Total_Indexes FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE [dbName] = QUOTENAME(@dbname) GROUP BY [dbName]),
  2720. cte2 ([Database_Name], Defraged_Indexes) AS (SELECT [dbName], COUNT(indexID) AS Total_Indexes FROM dbo.tbl_AdaptiveIndexDefrag_Working WHERE [dbName] = QUOTENAME(@dbname) AND defragDate IS NOT NULL OR printStatus = 1 GROUP BY [dbName]),
  2721. cte3 ([Database_Name], Total_statistics) AS (SELECT [dbName], COUNT(statsID) AS Total_statistics FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working WHERE [dbName] = QUOTENAME(@dbname) GROUP BY [dbName]),
  2722. cte4 ([Database_Name], Updated_statistics) AS (SELECT [dbName], COUNT(statsID) AS Updated_statistics FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working WHERE [dbName] = QUOTENAME(@dbname) AND updateDate IS NOT NULL OR printStatus = 1 GROUP BY [dbName])
  2723. SELECT cte1.[Database_Name], SUM(cte1.Total_indexes) AS Total_indexes, SUM(ISNULL(cte2.Defraged_Indexes, 0)) AS Defraged_Indexes,
  2724. SUM(cte3.Total_statistics) AS Total_statistics, SUM(ISNULL(cte4.Updated_statistics, 0)) AS Updated_statistics
  2725. FROM cte1 INNER JOIN cte3 ON cte1.Database_Name = cte3.Database_Name
  2726. LEFT JOIN cte2 ON cte1.Database_Name = cte2.Database_Name
  2727. LEFT JOIN cte4 ON cte1.Database_Name = cte4.Database_Name
  2728. GROUP BY cte1.[Database_Name];
  2729. SELECT 'Index' AS [Type], 'Done' AS [Result], dbName, objectName, indexName, partitionNumber
  2730. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2731. WHERE [dbName] = QUOTENAME(@dbname) AND (defragDate IS NOT NULL OR printStatus = 1)
  2732. UNION ALL
  2733. SELECT 'Index' AS [Type], 'To do' AS [Result], dbName, objectName, indexName, partitionNumber
  2734. FROM dbo.tbl_AdaptiveIndexDefrag_Working
  2735. WHERE [dbName] = QUOTENAME(@dbname) AND defragDate IS NULL AND printStatus = 0
  2736. ORDER BY 2, dbName, objectName, indexName;
  2737. SELECT 'Statistic' AS [Type], 'Done' AS [Result], dbName, objectName, statsName
  2738. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2739. WHERE [dbName] = QUOTENAME(@dbname) AND ([updateDate] IS NOT NULL OR printStatus = 1)
  2740. UNION ALL
  2741. SELECT 'Statistic' AS [Type], 'To do' AS [Result], dbName, objectName, statsName
  2742. FROM dbo.tbl_AdaptiveIndexDefrag_Stats_Working
  2743. WHERE [dbName] = QUOTENAME(@dbname) AND [updateDate] IS NULL AND printStatus = 0
  2744. ORDER BY 2, dbName, objectName, statsName;
  2745. END
  2746. GO
  2747. --EXEC sys.sp_MS_marksystemobject 'usp_AdaptiveIndexDefrag_CurrentExecStats'
  2748. --GO
  2749. PRINT 'Procedure usp_AdaptiveIndexDefrag_CurrentExecStats created (Use this to monitor defrag loop progress)';
  2750. GO
  2751. ------------------------------------------------------------------------------------------------------------------------------
  2752. CREATE PROCEDURE usp_AdaptiveIndexDefrag_Exceptions @exceptionMask_DB NVARCHAR(255) = NULL,
  2753. @exceptionMask_days NVARCHAR(27) = NULL,
  2754. @exceptionMask_tables NVARCHAR(500) = NULL,
  2755. @exceptionMask_indexes NVARCHAR(500) = NULL
  2756. AS
  2757. /*
  2758. usp_AdaptiveIndexDefrag_Exceptions.sql - [email protected] (http://aka.ms/AID)
  2759. To insert info into the Exceptions table, use the following guidelines:
  2760. For @exceptionMask_DB, enter only one database name at a time.
  2761. For @exceptionMask_days, enter weekdays in short form, between commas.
  2762. * NOTE: Keep only the weekdays you DO NOT WANT to ALLOW defrag. *
  2763. Order is not mandatory, but weekday short names are important AS IS ('Sun,Mon,Tue,Wed,Thu,Fri,Sat').
  2764. * NOTE: If you WANT to NEVER allow defrag, set as NULL or leave blank *
  2765. For @exceptionMask_tables (optional) enter table names separated by commas ('table_name_1, table_name_2, table_name_3').
  2766. For @exceptionMask_indexes (optional) enter index names separated by commas ('index_name_1, index_name_2, index_name_3').
  2767. If you want to exclude all indexes in a given table, enter its name but don't add index names.
  2768. Example:
  2769. EXEC usp_AdaptiveIndexDefrag_Exceptions @exceptionMask_DB = 'AdventureWorks2008R2',
  2770. @exceptionMask_days = 'Mon,Wed',
  2771. @exceptionMask_tables = 'Employee',
  2772. @exceptionMask_indexes = 'AK_Employee_LoginID'
  2773. */
  2774. SET NOCOUNT ON;
  2775. IF @exceptionMask_DB IS NULL OR QUOTENAME(@exceptionMask_DB) NOT IN (SELECT QUOTENAME(name) FROM sys.databases)
  2776. RAISERROR('Syntax error. Please input a valid database name.', 15, 42) WITH NOWAIT;
  2777. IF @exceptionMask_days IS NOT NULL AND
  2778. (@exceptionMask_days NOT LIKE '___' AND
  2779. @exceptionMask_days NOT LIKE '___,___' AND
  2780. @exceptionMask_days NOT LIKE '___,___,___' AND
  2781. @exceptionMask_days NOT LIKE '___,___,___,___' AND
  2782. @exceptionMask_days NOT LIKE '___,___,___,___,___' AND
  2783. @exceptionMask_days NOT LIKE '___,___,___,___,___,___' AND
  2784. @exceptionMask_days NOT LIKE '___,___,___,___,___,___,___')
  2785. RAISERROR('Syntax error. Please input weekdays in short form, between commas, or leave NULL to always exclude.', 15, 42) WITH NOWAIT;
  2786. IF @exceptionMask_days LIKE '[___,___,___,___,___,___,___]'
  2787. RAISERROR('Warning. You chose to permanently exclude a table and/or index from being defragmented.', 0, 42) WITH NOWAIT;
  2788. IF @exceptionMask_tables IS NOT NULL AND @exceptionMask_tables LIKE '%.%'
  2789. RAISERROR('Syntax error. Please do not input schema with table name(s).', 15, 42) WITH NOWAIT;
  2790. DECLARE @debugMessage NVARCHAR(4000), @sqlcmd NVARCHAR(4000), @sqlmajorver int
  2791. /* Find sql server version */
  2792. SELECT @sqlmajorver = CONVERT(int, (@@microsoftversion / 0x1000000) & 0xff);
  2793. BEGIN TRY
  2794. --Always exclude from defrag?
  2795. IF @exceptionMask_days IS NULL OR @exceptionMask_days = ''
  2796. BEGIN
  2797. SET @exceptionMask_days = 127
  2798. END
  2799. ELSE
  2800. BEGIN
  2801. -- 1=Sunday, 2=Monday, 4=Tuesday, 8=Wednesday, 16=Thursday, 32=Friday, 64=Saturday, 127=AllWeek
  2802. SET @exceptionMask_days = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@exceptionMask_days,',','+'),'Sun',1),'Mon',2),'Tue',4),'Wed',8),'Thu',16),'Fri',32),'Sat',64);
  2803. END
  2804. --Just get everything as it should be
  2805. SET @exceptionMask_tables = CHAR(39) + REPLACE(REPLACE(@exceptionMask_tables, ' ', ''),',', CHAR(39) + ',' + CHAR(39)) + CHAR(39)
  2806. SET @exceptionMask_indexes = CHAR(39) + REPLACE(REPLACE(@exceptionMask_indexes, ' ', ''),',', CHAR(39) + ',' + CHAR(39)) + CHAR(39)
  2807. --Get the exceptions insert command
  2808. IF @sqlmajorver > 9
  2809. BEGIN
  2810. SELECT @sqlcmd = 'MERGE dbo.tbl_AdaptiveIndexDefrag_Exceptions AS target
  2811. USING (SELECT ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB)) + ' AS dbID, si.[object_id] AS objectID, si.index_id AS indexID,
  2812. ''' + @exceptionMask_DB + ''' AS dbName, OBJECT_NAME(si.[object_id], ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB)) + ') AS objectName, si.[name] AS indexName,
  2813. ' + CONVERT(NVARCHAR,@exceptionMask_days) + ' AS exclusionMask
  2814. FROM ' + QUOTENAME(@exceptionMask_DB) + '.sys.indexes si
  2815. INNER JOIN ' + QUOTENAME(@exceptionMask_DB) + '.sys.objects so ON si.object_id = so.object_id
  2816. WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
  2817. AND si.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + @exceptionMask_DB + '].sys.internal_tables AS sit)' -- Exclude Heaps, Internal and Hypothetical objects
  2818. + CASE WHEN @exceptionMask_tables IS NOT NULL THEN ' AND OBJECT_NAME(si.[object_id], ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB)) + ') IN (' + @exceptionMask_tables + ')' ELSE '' END
  2819. + CASE WHEN @exceptionMask_indexes IS NOT NULL THEN ' AND si.[name] IN (' + @exceptionMask_indexes + ')' ELSE '' END
  2820. + ') AS source
  2821. ON (target.[dbID] = source.[dbID] AND target.objectID = source.objectID AND target.indexID = source.indexID)
  2822. WHEN MATCHED THEN
  2823. UPDATE SET exclusionMask = source.exclusionMask
  2824. WHEN NOT MATCHED THEN
  2825. INSERT (dbID, objectID, indexID, dbName, objectName, indexName, exclusionMask)
  2826. VALUES (source.dbID, source.objectID, source.indexID, source.dbName, source.objectName, source.indexName, source.exclusionMask);';
  2827. END
  2828. ELSE
  2829. BEGIN
  2830. SELECT @sqlcmd = 'DELETE FROM dbo.tbl_AdaptiveIndexDefrag_Exceptions
  2831. WHERE dbID = ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB))
  2832. + CASE WHEN @exceptionMask_tables IS NOT NULL THEN ' AND [objectName] IN (' + @exceptionMask_tables + ')' ELSE '' END
  2833. + CASE WHEN @exceptionMask_indexes IS NOT NULL THEN ' AND [indexName] IN (' + @exceptionMask_indexes + ');' ELSE ';' END +
  2834. 'INSERT INTO dbo.tbl_AdaptiveIndexDefrag_Exceptions
  2835. SELECT ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB)) + ' AS dbID, si.[object_id] AS objectID, si.index_id AS indexID,
  2836. ''' + @exceptionMask_DB + ''' AS dbName, OBJECT_NAME(si.[object_id], ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB)) + ') AS objectName, si.[name] AS indexName,
  2837. ' + CONVERT(NVARCHAR,@exceptionMask_days) + ' AS exclusionMask
  2838. FROM ' + QUOTENAME(@exceptionMask_DB) + '.sys.indexes si
  2839. INNER JOIN ' + QUOTENAME(@exceptionMask_DB) + '.sys.objects so ON si.object_id = so.object_id
  2840. WHERE so.is_ms_shipped = 0 AND si.index_id > 0 AND si.is_hypothetical = 0
  2841. AND si.[object_id] NOT IN (SELECT sit.[object_id] FROM [' + @exceptionMask_DB + '].sys.internal_tables AS sit)' -- Exclude Heaps, Internal and Hypothetical objects
  2842. + CASE WHEN @exceptionMask_tables IS NOT NULL THEN ' AND OBJECT_NAME(si.[object_id], ' + CONVERT(NVARCHAR,DB_ID(@exceptionMask_DB)) + ') IN (' + @exceptionMask_tables + ')' ELSE '' END
  2843. + CASE WHEN @exceptionMask_indexes IS NOT NULL THEN ' AND si.[name] IN (' + @exceptionMask_indexes + ')' ELSE '' END;
  2844. END;
  2845. EXEC sp_executesql @sqlcmd;
  2846. END TRY
  2847. BEGIN CATCH
  2848. SET @debugMessage = 'Error ' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + ': ' + ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS NVARCHAR(10)) + ')';
  2849. RAISERROR(@debugMessage, 0, 42) WITH NOWAIT;
  2850. END CATCH;
  2851. GO
  2852. --EXEC sys.sp_MS_marksystemobject 'usp_AdaptiveIndexDefrag_Exceptions'
  2853. --GO
  2854. PRINT 'Procedure usp_AdaptiveIndexDefrag_Exceptions created (If the defrag should not be daily, use this to set on which days to disallow it. It can be on entire DBs, tables and/or indexes)';
  2855. PRINT 'All done!'
  2856. GO