2_usp_AdaptiveIndexDefrag.sql 196 KB

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