usp_AdaptiveIndexDefrag.sql 185 KB

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