usp_AdaptiveIndexDefrag.sql 187 KB

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