usp_AdaptiveIndexDefrag.sql 191 KB

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