├── LICENSE ├── README.md ├── admin ├── dba_findWastedSpace_sp.sql ├── dba_recompile_sp.sql ├── dba_replicationLatencyGet_sp.sql ├── dba_replicationLatencyMonitor_sp.sql └── sql_agent_job_history.sql ├── dev ├── bcp_script_generator.sql ├── dba_parseString_udf.sql ├── insert_statement_generator.sql └── teradata_ddl_generator.sql ├── indexes ├── dba_indexDefrag_sp.sql ├── dba_indexLookup_sp.sql ├── dba_indexStats_sp.sql ├── dba_missingIndexStoredProc_sp.sql ├── index_definition.sql ├── missing.sql └── unused.sql └── misc └── dba_viewPageData_sp.sql /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "{}" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright {yyyy} {name of copyright owner} 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | sql-scripts 2 | =========== 3 | Repo for sharing my SQL Server scripts and stored procedures. These have largely been tested on both Standard & Enterprise versions of SQL 2005, 2008, 2008R2, and 2012; you may need to tweak for 2014 and newer versions. 4 | 5 | # what's available 6 | 7 | ## admin 8 | * dba_findWastedSpace_sp.sql 9 | * Finds wasted space on a database and/or table 10 | * dba_recompile_sp.sql 11 | * Recompiles all procs in a specific database or all procs; can recompile a specific table, too. 12 | * dba_replicationLatencyGet_sp.sql 13 | * Retrieves the amount of replication latency in seconds 14 | * dba_replicationLatencyMonitor_sp.sql 15 | * Stored procedure for retrieving & storing the amount of replication latency in seconds 16 | * sql-agent-job-history.sql 17 | * Explores SQL Agent Job metadata to get job statuses — when the job last ran, when it will run again, an aggregate count of the number of successful and failed executions in the queried time period, T-SQL code to disable the job, etc. 18 | 19 | ## dev 20 | * bcp_script_generator.sql 21 | * Generates bcp scripts using SQL Server metadata 22 | * dba_parseString_udf.sql 23 | * This function parses string input using a variable delimiter. 24 | * insert_statement_generator.sql 25 | * Generates insert statements for Teradata using SQL Server metadata. This is useful for easily migrating small tables (i.e. < 1000 rows) from SQL Server to Teradata. DO NOT use on large tables. 26 | * teradata_ddl_generator.sql 27 | * Generates Teradata DDL using SQL Server metadata 28 | 29 | ## indexes 30 | * dba_indexDefrag_sp.sql 31 | * award-winning index defrag script 32 | * dba_indexLookup_sp.sql 33 | * Retrieves index information for the specified table name. 34 | * dba_indexStats_sp.sql 35 | * etrieves information regarding indexes; will return drop SQL statement for non-clustered indexes. 36 | * dba_missingIndexStoredProc_sp.sql 37 | * Retrieves stored procedures with missing indexes in their cached query plans. 38 | * index_definition.sql 39 | * Displays the definition of indexes; useful to audit indexes across servers & environments 40 | * missing.sql 41 | * Displays potential missing indexes for a given database. Adding the indexes via the provided CREATE scripts may improve server performance. 42 | * unused.sql 43 | * Displays potential unused indexes for the current database. Dropping these indexes may improve database performance. These statistics are reset each time the server is rebooted, so make sure to review the [sqlserver_start_time] value to ensure the statistics are captured for a meaningful time period. 44 | 45 | ## misc 46 | * dba_viewPageData_sp.sql 47 | * Retrieves page data for the specified table/page. 48 | 49 | 50 | # contributing 51 | Contributions are welcome! To contribute a change or enhancement, please issue a pull request for me to review and merge. If you have any questions, I can be reached on Twitter @sqlfool. 52 | -------------------------------------------------------------------------------- /admin/dba_findWastedSpace_sp.sql: -------------------------------------------------------------------------------- 1 | If ObjectProperty(Object_ID('dbo.dba_findWastedSpace_sp'), N'IsProcedure') Is Null 2 | Begin 3 | Execute ('Create Procedure dbo.dba_findWastedSpace_sp As Print ''Hello World!''') 4 | RaisError('Procedure dba_findWastedSpace_sp created.', 10, 1); 5 | End; 6 | Go 7 | 8 | Set ANSI_Nulls On; 9 | Set Quoted_Identifier On; 10 | Go 11 | 12 | Alter Procedure dbo.dba_findWastedSpace_sp 13 | 14 | /* Declare Parameters */ 15 | @databaseName sysname = 'AdventureWorks' 16 | , @tableName sysname = 'Sales.SalesOrderDetail' 17 | , @percentGrowth tinyint = 10 /* allow for up to 10% growth by default */ 18 | , @displayUnit char(2) = 'GB' /* KB, MB, GB, or TB */ 19 | , @debug bit = 1 20 | 21 | As 22 | /********************************************************************************************************** 23 | 24 | NAME: dba_findWastedSpace_sp 25 | 26 | SYNOPSIS: Finds wasted space on a database and/or table 27 | 28 | DEPENDENCIES: The following dependencies are required to execute this script: 29 | - SQL Server 2005 or newer 30 | 31 | AUTHOR: Michelle Ufford, http://sqlfool.com 32 | 33 | CREATED: 2011-03-14 34 | 35 | VERSION: 1.0 36 | 37 | LICENSE: Apache License v2 38 | 39 | ---------------------------------------------------------------------------- 40 | DISCLAIMER: 41 | This code and information are provided "AS IS" without warranty of any kind, 42 | either expressed or implied, including but not limited to the implied 43 | warranties or merchantability and/or fitness for a particular purpose. 44 | ---------------------------------------------------------------------------- 45 | 46 | --------------------------------------------------------------------------------------------------------- 47 | -- DATE VERSION AUTHOR DESCRIPTION -- 48 | --------------------------------------------------------------------------------------------------------- 49 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 50 | **********************************************************************************************************/ 51 | 52 | Set NoCount On; 53 | Set XACT_Abort On; 54 | Set Ansi_Padding On; 55 | Set Ansi_Warnings On; 56 | Set ArithAbort On; 57 | Set Concat_Null_Yields_Null On; 58 | Set Numeric_RoundAbort Off; 59 | 60 | Begin 61 | 62 | /* Make sure our environment is clean and ready to go */ 63 | If Exists(Select object_id From tempdb.sys.tables Where name = '##values') 64 | Drop Table ##values; 65 | 66 | If Exists(Select object_id From tempdb.sys.tables Where name = '##definition') 67 | Drop Table ##definition; 68 | 69 | If Exists(Select object_id From tempdb.sys.tables Where name = '##spaceRequired') 70 | Drop Table ##spaceRequired; 71 | 72 | If Exists(Select object_id From tempdb.sys.tables Where name = '##results') 73 | Drop Table ##results; 74 | 75 | /* Declare Variables */ 76 | Declare @sqlStatement_getColumnList nvarchar(max) 77 | , @sqlStatement_values nvarchar(max) 78 | , @sqlStatement_columns nvarchar(max) 79 | , @sqlStatement_tableDefinition1 nvarchar(max) 80 | , @sqlStatement_tableDefinition2 nvarchar(max) 81 | , @sqlStatement_tableDefinition3 nvarchar(max) 82 | , @sqlStatement_spaceRequired nvarchar(max) 83 | , @sqlStatement_results nvarchar(max) 84 | , @sqlStatement_displayResults nvarchar(max) 85 | , @sqlStatement_total nvarchar(max) 86 | , @currentRecord int 87 | , @growthPercentage float; 88 | 89 | Declare @columnList Table 90 | ( 91 | id int identity(1,1) 92 | , table_id int 93 | , columnName varchar(128) 94 | , user_type_id tinyint 95 | , max_length smallint 96 | , columnStatus tinyint 97 | ); 98 | 99 | /* Initialize variables 100 | I'm doing it this way to support 2005 environments, too */ 101 | Select @sqlStatement_tableDefinition1 = '' 102 | , @sqlStatement_tableDefinition2 = '' 103 | , @sqlStatement_tableDefinition3 = '' 104 | , @sqlStatement_spaceRequired = 'Select ' 105 | , @sqlStatement_results = 'Select ' 106 | , @sqlStatement_displayResults = '' 107 | , @sqlStatement_total = 'Select ''Total'', Null, ' 108 | , @sqlStatement_values = 'Select ' 109 | , @sqlStatement_columns = 'Select ' 110 | , @growthPercentage = 1+(@percentGrowth/100.0); 111 | 112 | Set @sqlStatement_getColumnList = ' 113 | Select c.object_id As [table_id] 114 | , c.name 115 | , t.user_type_id 116 | , c.max_length 117 | , 0 /* not yet columnStatus */ 118 | From ' + @databaseName + '.sys.columns As c 119 | Join ' + @databaseName + '.sys.types As t 120 | On c.user_type_id = t.user_type_id 121 | Where c.object_id = IsNull(Object_Id(''' + @databaseName + '.' + @tableName + '''), c.object_id) 122 | And t.user_type_id In (48, 52, 56, 127, 167, 175, 231, 239);' 123 | 124 | If @Debug = 1 125 | Begin 126 | Select @sqlStatement_getColumnList; 127 | End; 128 | 129 | Insert Into @columnList 130 | Execute sp_executeSQL @sqlStatement_getColumnList; 131 | 132 | If @Debug = 1 133 | Begin 134 | Select * From @columnList; 135 | End; 136 | 137 | /* Begin our loop. We're going to run through this for every column. */ 138 | While Exists(Select * From @columnList Where columnStatus = 0) 139 | Begin 140 | 141 | /* Grab a column that hasn't been processed yet */ 142 | Select Top 1 @currentRecord = id 143 | From @columnList 144 | Where columnStatus = 0 145 | Order By id; 146 | 147 | /* First, let's build the statement we're going to use to get our min/max values */ 148 | Select @sqlStatement_values = @sqlStatement_values + Case When user_type_id In (48, 52, 56, 127) 149 | Then 'Max(' + columnName + ') As [' + columnName + '], ' 150 | + 'Min(' + columnName + ') As [min' + columnName + '], ' 151 | Else 'Max(Len(' + columnName + ')) As [' + columnName + '], ' 152 | + 'Avg(Len(' + columnName + ')) As [avg' + columnName + '], ' 153 | End 154 | From @columnList 155 | Where id = @currentRecord; 156 | 157 | /* Next, let's build the statement that's going to show us how much space the column is currently consuming */ 158 | Select @sqlStatement_columns = @sqlStatement_columns 159 | + Case When user_type_id = 48 Then '1' -- tinyint 160 | When user_type_id = 52 Then '2' -- smallint 161 | When user_type_id = 56 Then '4' -- int 162 | When user_type_id = 127 Then '8' -- bigint 163 | When user_type_id In (167, 175) Then Cast(max_length As varchar(10))-- varchar or char 164 | Else Cast(max_length * 2 As varchar(10)) -- nvarchar or nchar 165 | --Else '0' 166 | End + ' As [' + columnName + '], ' 167 | From @columnList 168 | Where id = @currentRecord; 169 | 170 | /* This section is used to build a table definition */ 171 | Select @sqlStatement_tableDefinition1 = @sqlStatement_tableDefinition1 + '[' + columnName + '] ' 172 | + Case 173 | When user_type_id = 48 Then 'tinyint' 174 | When user_type_id = 52 Then 'smallint' 175 | When user_type_id = 56 Then 'int' 176 | When user_type_id = 127 Then 'bigint' 177 | Else 'smallint' 178 | End + ', ' 179 | + Case When user_type_id In (48, 52, 56, 127) Then '[min' Else '[avg' End + columnName + '] ' 180 | + Case 181 | When user_type_id = 48 Then 'tinyint' 182 | When user_type_id = 52 Then 'smallint' 183 | When user_type_id = 56 Then 'int' 184 | When user_type_id = 127 Then 'bigint' 185 | Else 'smallint' 186 | End + ', ' 187 | From @columnList 188 | Where id = @currentRecord; 189 | 190 | /* More dynamic table definition code */ 191 | Select @sqlStatement_tableDefinition2 = @sqlStatement_tableDefinition2 + '[' + columnName + '] ' 192 | + Case 193 | When user_type_id = 48 Then 'tinyint' 194 | When user_type_id = 52 Then 'smallint' 195 | When user_type_id = 56 Then 'int' 196 | When user_type_id = 127 Then 'bigint' 197 | Else 'smallint' 198 | End + ', ' 199 | From @columnList 200 | Where id = @currentRecord; 201 | 202 | /* And yet more dynamic table definition code */ 203 | Select @sqlStatement_tableDefinition3 = @sqlStatement_tableDefinition3 + columnName + ' smallint, ' 204 | + columnName + '_bytes bigint, ' 205 | From @columnList 206 | Where id = @currentRecord; 207 | 208 | /* This is where we see how much space we actually need, based on our min/max values. 209 | This is where we consider the % of growth that we expect to see in a reasonable period of time. */ 210 | Select @sqlStatement_spaceRequired = @sqlStatement_spaceRequired + 211 | Case When user_type_id In (48, 52, 56, 127) 212 | Then 'Case When ([' + columnName + '] * ' + Cast(@growthPercentage As varchar(5)) + ') <= 255 213 | And [min' + columnName + '] >= 0 214 | Then 1 215 | When ([' + columnName + '] * ' + Cast(@growthPercentage As varchar(5)) + ') <= 32768 216 | And [min' + columnName + '] >= -32768 217 | Then 2 218 | When ([' + columnName + '] * ' + Cast(@growthPercentage As varchar(5)) + ') <= 2147483647 219 | And [min' + columnName + '] >= -2147483647 220 | Then 4 221 | Else 8 End ' 222 | Else columnName 223 | End + ' As [' + columnName + '], ' 224 | From @columnList 225 | Where id = @currentRecord; 226 | 227 | /* This is where the analysis occurs to tell us how much space we're potentially wasting */ 228 | Select @sqlStatement_results = @sqlStatement_results + 229 | 'd.[' + columnName + '] - sr.[' + columnName + '] As [' + columnName + '], ' + 230 | '(d.[' + columnName + '] - sr.[' + columnName + ']) * rowCnt As [bytes], ' 231 | From @columnList 232 | Where id = @currentRecord; 233 | 234 | /* This is where we get our pretty results table from */ 235 | Select @sqlStatement_displayResults = @sqlStatement_displayResults + 'Select ''' + columnName + ''' As [columnName] ' 236 | + ', ' + columnName + ' As [byteReduction] ' 237 | -- + ', ' + columnName + '_bytes As [estimatedSpaceSavings] ' 238 | + ', ' + columnName + '_bytes / 1024.0 / 1024.0 As [estimatedSpaceSavings] ' 239 | + ' From ##results' 240 | + ' Union All ' 241 | From @columnList 242 | Where id = @currentRecord; 243 | 244 | /* And lastly, this is where we get our total from */ 245 | Select @sqlStatement_total = @sqlStatement_total + '([' + columnName + '_bytes] / 1024.0 / 1024.0) + ' 246 | From @columnList 247 | Where id = @currentRecord; 248 | 249 | 250 | /* Mark the column as processed so we can move on to the next one */ 251 | Update @columnList 252 | Set columnStatus = 1 253 | Where id = @currentRecord; 254 | 255 | End; 256 | 257 | Select @sqlStatement_values = @sqlStatement_values + ' Count(*) As [rowCnt], 1 As [id] From ' + @databaseName + '.' + @tableName + ' Option (MaxDop 1);' 258 | , @sqlStatement_columns = @sqlStatement_columns + ' ' + Cast(@currentRecord As varchar(4)) + ' As [columnCnt], 1 As [id];'; 259 | 260 | Set @sqlStatement_tableDefinition1 = 'Create Table ##values(' 261 | + @sqlStatement_tableDefinition1 262 | + ' rowCnt bigint, id tinyint)'; 263 | 264 | Set @sqlStatement_tableDefinition2 = 'Create Table ##definition(' 265 | + @sqlStatement_tableDefinition2 266 | + ' columnCnt bigint, id tinyint)'; 267 | 268 | Set @sqlStatement_tableDefinition3 = 'Create Table ##results(' 269 | + @sqlStatement_tableDefinition3 270 | + ' id tinyint)'; 271 | 272 | Set @sqlStatement_spaceRequired = @sqlStatement_spaceRequired + '1 As [id] Into ##spaceRequired From ##values;' 273 | 274 | Set @sqlStatement_results = @sqlStatement_results + '1 As [id] From ##definition As d Join ##spaceRequired As sr On d.id = sr.id Join ##values As v On d.id = v.id;' 275 | 276 | Set @sqlStatement_displayResults = @sqlStatement_displayResults + @sqlStatement_total + '0 From ##results'; 277 | 278 | /* Print our dynamic SQL statements in case we need to troubleshoot */ 279 | If @debug = 1 280 | Begin 281 | Select @sqlStatement_values As '@sqlStatement_values' 282 | , @sqlStatement_columns As '@sqlStatement_columns' 283 | , @sqlStatement_tableDefinition1 As '@sqlStatement_tableDefinition1' 284 | , @sqlStatement_tableDefinition2 As '@sqlStatement_tableDefinition2' 285 | , @sqlStatement_spaceRequired As '@sqlStatement_spaceRequired' 286 | , @sqlStatement_results As '@sqlStatement_results' 287 | , @sqlStatement_displayResults As '@sqlStatement_displayResults' 288 | , @sqlStatement_total As '@sqlStatement_total'; 289 | End; 290 | 291 | Select @sqlStatement_tableDefinition1 As 'Table Definition 1'; 292 | Execute sp_executeSQL @sqlStatement_tableDefinition1; 293 | 294 | Select @sqlStatement_tableDefinition2 As 'Table Definition 2'; 295 | Execute sp_executeSQL @sqlStatement_tableDefinition2; 296 | 297 | Select @sqlStatement_tableDefinition3 As 'Table Definition 3'; 298 | Execute sp_executeSQL @sqlStatement_tableDefinition3; 299 | 300 | Select @sqlStatement_values As 'Insert 1'; 301 | Insert Into ##values 302 | Execute sp_executeSQL @sqlStatement_values; 303 | 304 | Select @sqlStatement_columns As 'Insert 2'; 305 | Insert Into ##definition 306 | Execute sp_executeSQL @sqlStatement_columns; 307 | 308 | Select @sqlStatement_spaceRequired As 'Execute space required'; 309 | Execute sp_executeSQL @sqlStatement_spaceRequired; 310 | 311 | Select @sqlStatement_results As 'Execute results'; 312 | Insert Into ##results 313 | Execute sp_executeSQL @sqlStatement_results; 314 | 315 | /* Output our table values for troubleshooting purposes */ 316 | If @debug = 1 317 | Begin 318 | Select 'definition' As 'tableType', * From ##definition y 319 | Select 'values' As 'tableType', * from ##values x 320 | Select 'spaceRequired' As 'tableType', * From ##spaceRequired; 321 | Select 'results' As 'tableType', * From ##results; 322 | End; 323 | 324 | Select @sqlStatement_displayResults As 'Final results'; 325 | Execute sp_executeSQL @sqlStatement_displayResults; 326 | 327 | /* Clean up our mess */ 328 | --Drop Table ##values; 329 | --Drop Table ##definition; 330 | --Drop Table ##spaceRequired; 331 | --Drop Table ##results; 332 | 333 | Set NoCount Off; 334 | Return 0; 335 | End 336 | Go 337 | 338 | Set Quoted_Identifier Off; 339 | Go -------------------------------------------------------------------------------- /admin/dba_recompile_sp.sql: -------------------------------------------------------------------------------- 1 | Use dbaTools; 2 | Go 3 | 4 | If ObjectProperty(Object_ID('dbo.dba_recompile_sp'), N'IsProcedure') Is Null 5 | Begin 6 | Execute ('Create Procedure dbo.dba_recompile_sp As Print ''Hello World!''') 7 | RaisError('Procedure dba_recompile_sp created.', 10, 1); 8 | End; 9 | Go 10 | 11 | Set ANSI_Nulls On; 12 | Set Quoted_Identifier On; 13 | Go 14 | 15 | Alter Procedure dbo.dba_recompile_sp 16 | 17 | /* Declare Parameters */ 18 | @databaseName nvarchar(128) = Null /* Null = all databases */ 19 | , @tableName nvarchar(128) = Null /* Null = all tables */ 20 | 21 | As 22 | /********************************************************************************************************** 23 | 24 | NAME: dba_recompile_sp 25 | 26 | SYNOPSIS: Recompiles all procs in a specific database or all procs; can recompile a specific table, too. 27 | 28 | DEPENDENCIES: The following dependencies are required to execute this script: 29 | - SQL Server 2005 or newer 30 | 31 | AUTHOR: Michelle Ufford, http://sqlfool.com 32 | 33 | CREATED: 2009-09-12 34 | 35 | VERSION: 1.0 36 | 37 | LICENSE: Apache License v2 38 | 39 | ---------------------------------------------------------------------------- 40 | DISCLAIMER: 41 | This code and information are provided "AS IS" without warranty of any kind, 42 | either expressed or implied, including but not limited to the implied 43 | warranties or merchantability and/or fitness for a particular purpose. 44 | ---------------------------------------------------------------------------- 45 | 46 | --------------------------------------------------------------------------------------------------------- 47 | -- DATE VERSION AUTHOR DESCRIPTION -- 48 | --------------------------------------------------------------------------------------------------------- 49 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 50 | **********************************************************************************************************/ 51 | 52 | Set NoCount On; 53 | Set XACT_Abort On; 54 | Set Ansi_Padding On; 55 | Set Ansi_Warnings On; 56 | Set ArithAbort On; 57 | Set Concat_Null_Yields_Null On; 58 | Set Numeric_RoundAbort Off; 59 | 60 | Begin 61 | 62 | /* Make sure the global temp tables do not already exist, i.e. failed execution */ 63 | If Exists(Select * From tempdb.sys.tables Where name = '###databaseList') 64 | Drop Table #databaseList; 65 | 66 | If Exists(Select * From tempdb.sys.tables Where name = '##tableList') 67 | Drop Table tableList; 68 | 69 | /* Declare Temp Tables */ 70 | Create Table ##databaseList 71 | ( 72 | databaseName nvarchar(128) 73 | , processed bit 74 | ); 75 | 76 | Create Table ##tableList 77 | ( 78 | databaseName nvarchar(128) 79 | , tableName nvarchar(128) 80 | , processed bit 81 | ); 82 | 83 | Insert Into ##databaseList 84 | Select name As databaseName 85 | , 0 As processed 86 | From sys.databases 87 | Where name = IsNull(@databaseName, name); 88 | 89 | While Exists(Select Top 1 databaseName From ##databaseList Where processed = 0) 90 | Begin 91 | 92 | Execute sp_msforeachdb 'Use ?; 93 | Select name As tableName 94 | Into ##tableList 95 | From sys.tables 96 | Where name = IsNull(@tableName, name); 97 | 98 | Declare @tableName nvarchar(128) = (Select Top 1 tableName From #tableList); 99 | 100 | While Exists(Select Top 1 * From #tableList) 101 | Begin 102 | Execute sp_recompile @tableName; 103 | Delete From #tableList Where tableName = @tableName; 104 | Select Top 1 @tableName = tableName From #tableList Order By tableName; 105 | End; 106 | 107 | Drop Table ##tableList;' 108 | 109 | End 110 | 111 | Set NoCount Off; 112 | Return 0; 113 | End 114 | Go 115 | 116 | Set Quoted_Identifier Off; 117 | Go 118 | 119 | If ObjectProperty(Object_ID('dbo.dba_recompile_sp'), N'IsProcedure') = 1 120 | RaisError('Procedure dba_recompile_sp was successfully updated.', 10, 1); 121 | Else 122 | RaisError('Procedure dba_recompile_sp FAILED to create!', 16, 1); 123 | Go -------------------------------------------------------------------------------- /admin/dba_replicationLatencyGet_sp.sql: -------------------------------------------------------------------------------- 1 | If ObjectProperty(Object_ID('dbo.dba_replicationLatencyGet_sp'), N'IsProcedure') = 1 2 | Begin 3 | Drop Procedure dbo.dba_replicationLatencyGet_sp; 4 | Print 'Procedure dba_replicationLatencyGet_sp dropped'; 5 | End; 6 | Go 7 | 8 | Set Quoted_Identifier On 9 | Go 10 | Set ANSI_Nulls On 11 | Go 12 | 13 | Create Procedure dbo.dba_replicationLatencyGet_sp 14 | 15 | /* Declare Parameters */ 16 | @publicationToTest sysname = N'goDaddyWebsiteTracking01' 17 | , @replicationDelay varchar(10) = N'00:00:30' 18 | , @iterations int = 5 19 | , @iterationDelay varchar(10) = N'00:00:30' 20 | , @deleteTokens bit = 1 21 | , @deleteTempTable bit = 1 22 | As 23 | /********************************************************************************************************** 24 | 25 | NAME: dba_replicationLatencyGet_sp 26 | 27 | SYNOPSIS: Retrieves the amount of replication latency in seconds 28 | 29 | DEPENDENCIES: The following dependencies are required to execute this script: 30 | - SQL Server 2005 or newer 31 | 32 | NOTES: Default settings will run 1 test every minute for 5 minutes. 33 | 34 | @publicationToTest = defaults to goDaddyWebsiteTracking publication 35 | 36 | @replicationDelay = how long to wait for the token to replicate; 37 | probably should not set to anything less than 10 (in seconds) 38 | 39 | @iterations = how many tokens you want to test 40 | 41 | @iterationDelay = how long to wait between sending test tokens 42 | (in seconds) 43 | 44 | @deleteTokens = whether you want to retain tokens when done 45 | 46 | @deleteTempTable = whether or not to retain the temporary table 47 | when done. Data stored to ##tokenResults; set @deleteTempTable 48 | flag to 0 if you do not want to delete when done. 49 | 50 | AUTHOR: Michelle Ufford, http://sqlfool.com 51 | 52 | CREATED: 2008-05-22 53 | 54 | VERSION: 1.0 55 | 56 | LICENSE: Apache License v2 57 | 58 | USAGE: EXEC dbo.dba_replicationLatencyGet_sp 59 | @publicationToTest = N'your_publication' 60 | , @replicationDelay = N'00:00:05' 61 | , @iterations = 1 62 | , @iterationDelay = N'00:00:05' 63 | , @deleteTokens = 1 64 | , @deleteTempTable = 1; 65 | 66 | ---------------------------------------------------------------------------- 67 | DISCLAIMER: 68 | This code and information are provided "AS IS" without warranty of any kind, 69 | either expressed or implied, including but not limited to the implied 70 | warranties or merchantability and/or fitness for a particular purpose. 71 | ---------------------------------------------------------------------------- 72 | 73 | --------------------------------------------------------------------------------------------------------- 74 | -- DATE VERSION AUTHOR DESCRIPTION -- 75 | --------------------------------------------------------------------------------------------------------- 76 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 77 | **********************************************************************************************************/ 78 | 79 | Set NoCount On; 80 | Set XACT_Abort On; 81 | 82 | Begin 83 | 84 | /* Declare Variables */ 85 | Declare @currentIteration int 86 | , @tokenID bigint 87 | , @currentDateTime smalldatetime; 88 | 89 | If Object_ID('tempdb.dbo.##tokenResults') Is Null 90 | Begin 91 | Create Table ##tokenResults 92 | ( iteration int Null 93 | , tracer_id int Null 94 | , distributor_latency int Null 95 | , subscriber varchar(1000) Null 96 | , subscriber_db varchar(1000) Null 97 | , subscriber_latency int Null 98 | , overall_latency int Null ); 99 | End; 100 | 101 | /* Initialize our variables */ 102 | Select @currentIteration = 0 103 | , @currentDateTime = GetDate(); 104 | 105 | While @currentIteration < @iterations 106 | Begin 107 | 108 | /* Insert a new tracer token in the publication database */ 109 | Execute sys.sp_postTracerToken 110 | @publication = @publicationToTest, 111 | @tracer_token_id = @tokenID OutPut; 112 | 113 | /* Give a few seconds to allow the record to reach the subscriber */ 114 | WaitFor Delay @replicationDelay; 115 | 116 | /* Store our results in a temp table for retrieval later */ 117 | Insert Into ##tokenResults 118 | ( 119 | distributor_latency 120 | , subscriber 121 | , subscriber_db 122 | , subscriber_latency 123 | , overall_latency 124 | ) 125 | Execute sys.sp_helpTracerTokenHistory @publicationToTest, @tokenID; 126 | 127 | /* Assign the iteration and token id to the results for easier investigation */ 128 | Update ##tokenResults 129 | Set iteration = @currentIteration + 1 130 | , tracer_id = @tokenID 131 | Where iteration Is Null; 132 | 133 | /* Wait for the specified time period before creating another token */ 134 | WaitFor Delay @iterationDelay; 135 | 136 | /* Avoid endless looping... :) */ 137 | Set @currentIteration = @currentIteration + 1; 138 | 139 | End; 140 | 141 | Select * From ##tokenResults; 142 | 143 | If @deleteTempTable = 1 144 | Begin 145 | Drop Table ##tokenResults; 146 | End; 147 | 148 | If @deleteTokens = 1 149 | Begin 150 | Execute sp_deleteTracerTokenHistory @publication = @publicationToTest, @cutoff_date = @currentDateTime; 151 | End; 152 | 153 | Set NoCount Off; 154 | Return 0; 155 | End 156 | Go 157 | 158 | Set Quoted_Identifier Off; 159 | Go 160 | Set ANSI_Nulls On; 161 | Go 162 | 163 | If ObjectProperty(Object_ID('dbo.dba_replicationLatencyGet_sp'), N'IsProcedure') = 1 164 | RaisError('Procedure dba_replicationLatencyGet_sp was successfully created.', 10, 1); 165 | Else 166 | RaisError('Procedure dba_replicationLatencyGet_sp FAILED to create!', 16, 1); 167 | Go 168 | -------------------------------------------------------------------------------- /admin/dba_replicationLatencyMonitor_sp.sql: -------------------------------------------------------------------------------- 1 | Use DBAHoldings; 2 | Go 3 | 4 | If Object_ID('dbo.dba_replicationMonitor') Is Null 5 | Begin 6 | Create Table dbo.dba_replicationMonitor 7 | ( 8 | monitor_id int Identity(1,1) Not Null 9 | , monitorDate smalldatetime Not Null 10 | , publicationName sysname Not Null 11 | , publicationDB sysname Not Null 12 | , iteration int Null 13 | , tracer_id int Null 14 | , distributor_latency int Null 15 | , subscriber varchar(1000) Null 16 | , subscriber_db varchar(1000) Null 17 | , subscriber_latency int Null 18 | , overall_latency int Null 19 | ); 20 | End; 21 | 22 | If ObjectProperty(Object_ID('dbo.dba_replicationLatencyMonitor_sp'), N'IsProcedure') = 1 23 | Begin 24 | Drop Procedure dbo.dba_replicationLatencyMonitor_sp; 25 | Print 'Procedure dba_replicationLatencyMonitor_sp dropped'; 26 | End; 27 | Go 28 | 29 | Set Quoted_Identifier On 30 | Go 31 | Set ANSI_Nulls On 32 | Go 33 | 34 | Create Procedure dbo.dba_replicationLatencyMonitor_sp 35 | 36 | /* Declare Parameters */ 37 | @publicationToTest sysname = N'YourPublication01' 38 | , @publicationDB sysname = N'YourPublicationDB' 39 | , @replicationDelay varchar(10) = N'00:00:30' 40 | , @iterations int = 5 41 | , @iterationDelay varchar(10) = N'00:00:30' 42 | , @displayResults bit = 0 43 | , @deleteTokens bit = 1 44 | As 45 | /********************************************************************************************************** 46 | 47 | NAME: dba_replicationLatencyMonitor_sp 48 | 49 | SYNOPSIS: Retrieves the amount of replication latency in seconds 50 | 51 | DEPENDENCIES: The following dependencies are required to execute this script: 52 | - SQL Server 2005 or newer 53 | 54 | NOTES: Default settings will run 1 test every minute for 5 minutes. 55 | 56 | @publicationToTest = defaults to the specified publication 57 | 58 | @publicationDB = the database that is the source for the publication. 59 | The tracer procs are found in the publishing DB. 60 | 61 | @replicationDelay = how long to wait for the token to replicate; 62 | probably should not set to anything less than 10 (in seconds) 63 | 64 | @iterations = how many tokens you want to test 65 | 66 | @iterationDelay = how long to wait between sending test tokens 67 | (in seconds) 68 | 69 | @displayResults = print results to screen when complete 70 | 71 | @deleteTokens = whether you want to retain tokens when done 72 | 73 | AUTHOR: Michelle Ufford, http://sqlfool.com 74 | 75 | CREATED: 2008-11-23 76 | 77 | VERSION: 1.0 78 | 79 | LICENSE: Apache License v2 80 | 81 | USAGE: EXEC dbo.dba_replicationLatencyMonitor_sp 82 | @publicationToTest = N'myTestPublication' 83 | , @publicationDB = N'sandbox_publisher' 84 | , @replicationDelay = N'00:00:05' 85 | , @iterations = 1 86 | , @iterationDelay = N'00:00:05' 87 | , @displayResults = 1 88 | , @deleteTokens = 1; 89 | 90 | ---------------------------------------------------------------------------- 91 | DISCLAIMER: 92 | This code and information are provided "AS IS" without warranty of any kind, 93 | either expressed or implied, including but not limited to the implied 94 | warranties or merchantability and/or fitness for a particular purpose. 95 | ---------------------------------------------------------------------------- 96 | 97 | --------------------------------------------------------------------------------------------------------- 98 | -- DATE VERSION AUTHOR DESCRIPTION -- 99 | --------------------------------------------------------------------------------------------------------- 100 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 101 | **********************************************************************************************************/ 102 | 103 | Set NoCount On; 104 | Set XACT_Abort On; 105 | 106 | Begin 107 | 108 | /* Declare Variables */ 109 | Declare @currentIteration int 110 | , @tokenID bigint 111 | , @currentDateTime smalldatetime 112 | , @sqlStatement nvarchar(200) 113 | , @parmDefinition nvarchar(500); 114 | 115 | Declare @tokenResults Table 116 | ( 117 | iteration int Null 118 | , tracer_id int Null 119 | , distributor_latency int Null 120 | , subscriber varchar(1000) Null 121 | , subscriber_db varchar(1000) Null 122 | , subscriber_latency int Null 123 | , overall_latency int Null 124 | ); 125 | 126 | /* Initialize our variables */ 127 | Select @currentIteration = 0 128 | , @currentDateTime = GetDate(); 129 | 130 | While @currentIteration < @iterations 131 | Begin 132 | 133 | /* Prepare the stored procedure execution string */ 134 | Set @sqlStatement = N'Execute ' + @publicationDB + N'.sys.sp_postTracerToken ' + 135 | N'@publication = @VARpublicationToTest , ' + 136 | N'@tracer_token_id = @VARtokenID OutPut;' 137 | 138 | /* Define the parameters used by the sp_ExecuteSQL later */ 139 | Set @parmDefinition = N'@VARpublicationToTest sysname, ' + 140 | N'@VARtokenID bigint OutPut'; 141 | 142 | /* Insert a new tracer token in the publication database */ 143 | Execute sp_executesql 144 | @sqlStatement 145 | , @parmDefinition 146 | , @VARpublicationToTest = @publicationToTest 147 | , @VARtokenID = @TokenID OutPut; 148 | 149 | /* Give a few seconds to allow the record to reach the subscriber */ 150 | WaitFor Delay @replicationDelay; 151 | 152 | /* Prepare our statement to retrieve tracer token data */ 153 | Select @sqlStatement = 'Execute ' + @publicationDB + '.sys.sp_helpTracerTokenHistory ' + 154 | N'@publication = @VARpublicationToTest , ' + 155 | N'@tracer_id = @VARtokenID' 156 | , @parmDefinition = N'@VARpublicationToTest sysname, ' + 157 | N'@VARtokenID bigint'; 158 | 159 | /* Store our results for retrieval later */ 160 | Insert Into @tokenResults 161 | ( 162 | distributor_latency 163 | , subscriber 164 | , subscriber_db 165 | , subscriber_latency 166 | , overall_latency 167 | ) 168 | Execute sp_executesql 169 | @sqlStatement 170 | , @parmDefinition 171 | , @VARpublicationToTest = @publicationToTest 172 | , @VARtokenID = @TokenID; 173 | 174 | /* Assign the iteration and token id to the results for easier investigation */ 175 | Update @tokenResults 176 | Set iteration = @currentIteration + 1 177 | , tracer_id = @tokenID 178 | Where iteration Is Null; 179 | 180 | /* Wait for the specified time period before creating another token */ 181 | WaitFor Delay @iterationDelay; 182 | 183 | /* Avoid endless looping... :) */ 184 | Set @currentIteration = @currentIteration + 1; 185 | 186 | End; 187 | 188 | /* Display our results */ 189 | If @displayResults = 1 190 | Begin 191 | Select 192 | iteration 193 | , tracer_id 194 | , IsNull(distributor_latency, 0) As 'distributor_latency' 195 | , subscriber 196 | , subscriber_db 197 | , IsNull(subscriber_latency, 0) As 'subscriber_latency' 198 | , IsNull(overall_latency, 199 | IsNull(distributor_latency, 0) + IsNull(subscriber_latency, 0)) 200 | As 'overall_latency' 201 | From @tokenResults; 202 | End; 203 | 204 | /* Store our results */ 205 | Insert Into dbo.dba_replicationMonitor 206 | ( 207 | monitorDate 208 | , publicationName 209 | , publicationDB 210 | , iteration 211 | , tracer_id 212 | , distributor_latency 213 | , subscriber 214 | , subscriber_db 215 | , subscriber_latency 216 | , overall_latency 217 | ) 218 | Select 219 | @currentDateTime 220 | , @publicationToTest 221 | , @publicationDB 222 | , iteration 223 | , tracer_id 224 | , IsNull(distributor_latency, 0) 225 | , subscriber 226 | , subscriber_db 227 | , IsNull(subscriber_latency, 0) 228 | , IsNull(overall_latency, 229 | IsNull(distributor_latency, 0) + IsNull(subscriber_latency, 0)) 230 | From @tokenResults; 231 | 232 | /* Delete the tracer tokens if requested */ 233 | If @deleteTokens = 1 234 | Begin 235 | 236 | Select @sqlStatement = 'Execute ' + @publicationDB + '.sys.sp_deleteTracerTokenHistory ' + 237 | N'@publication = @VARpublicationToTest , ' + 238 | N'@cutoff_date = @VARcurrentDateTime' 239 | , @parmDefinition = N'@VARpublicationToTest sysname, ' + 240 | N'@VARcurrentDateTime datetime'; 241 | 242 | Execute sp_executesql 243 | @sqlStatement 244 | , @parmDefinition 245 | , @VARpublicationToTest = @publicationToTest 246 | , @VARcurrentDateTime = @currentDateTime; 247 | 248 | End; 249 | 250 | Set NoCount Off; 251 | Return 0; 252 | End 253 | Go 254 | 255 | Set Quoted_Identifier Off; 256 | Go 257 | Set ANSI_Nulls On; 258 | Go 259 | 260 | If ObjectProperty(Object_ID('dbo.dba_replicationLatencyMonitor_sp'), N'IsProcedure') = 1 261 | RaisError('Procedure dba_replicationLatencyMonitor_sp was successfully created.', 10, 1); 262 | Else 263 | RaisError('Procedure dba_replicationLatencyMonitor_sp FAILED to create!', 16, 1); 264 | Go 265 | -------------------------------------------------------------------------------- /admin/sql_agent_job_history.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: sql-agent-job-history.sql 4 | 5 | SYNOPSIS: Explores SQL Agent Job metadata to get job statuses — when the job last ran, when it 6 | will run again, an aggregate count of the number of successful and failed executions 7 | in the queried time period, T-SQL code to disable the job, etc. 8 | 9 | DEPENDENCIES: The following dependencies are required to execute this script: 10 | - SQL Server 2005 or newer 11 | 12 | AUTHOR: Michelle Ufford, http://sqlfool.com 13 | 14 | CREATED: 2012-12-18 15 | 16 | VERSION: 1.0 17 | 18 | LICENSE: Apache License v2 19 | 20 | ---------------------------------------------------------------------------- 21 | DISCLAIMER: 22 | This code and information are provided "AS IS" without warranty of any kind, 23 | either expressed or implied, including but not limited to the implied 24 | warranties or merchantability and/or fitness for a particular purpose. 25 | ---------------------------------------------------------------------------- 26 | 27 | --------------------------------------------------------------------------------------------------------- 28 | -- DATE VERSION AUTHOR DESCRIPTION -- 29 | --------------------------------------------------------------------------------------------------------- 30 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 31 | **********************************************************************************************************/ 32 | 33 | DECLARE @jobHistory TABLE 34 | ( 35 | job_id UNIQUEIDENTIFIER 36 | , success INT 37 | , cancel INT 38 | , fail INT 39 | , retry INT 40 | , last_execution_id INT 41 | , last_duration CHAR(8) 42 | , last_execution_start DATETIME 43 | ); 44 | 45 | WITH lastExecution 46 | AS 47 | ( 48 | SELECT job_id 49 | , MAX(instance_id) AS last_instance_id 50 | FROM msdb.dbo.sysjobhistory 51 | WHERE step_id = 0 52 | GROUP BY job_id 53 | ) 54 | 55 | INSERT INTO @jobHistory 56 | SELECT sjh.job_id 57 | , SUM(CASE WHEN sjh.run_status = 1 AND step_id = 0 THEN 1 ELSE 0 END) AS success 58 | , SUM(CASE WHEN sjh.run_status = 3 AND step_id = 0 THEN 1 ELSE 0 END) AS cancel 59 | , SUM(CASE WHEN sjh.run_status = 0 AND step_id = 0 THEN 1 ELSE 0 END) AS fail 60 | , SUM(CASE WHEN sjh.run_status = 2 THEN 1 ELSE 0 END) AS retry 61 | , MAX(CASE WHEN sjh.step_id = 0 THEN instance_id ELSE NULL END) last_execution_id 62 | , SUBSTRING(CAST(MAX(CASE WHEN le.job_id IS NOT NULL THEN sjh.run_duration ELSE NULL END) + 1000000 AS VARCHAR(7)),2,2) + ':' 63 | + SUBSTRING(CAST(MAX(CASE WHEN le.job_id IS NOT NULL THEN sjh.run_duration ELSE NULL END) + 1000000 AS VARCHAR(7)),4,2) + ':' 64 | + SUBSTRING(CAST(MAX(CASE WHEN le.job_id IS NOT NULL THEN sjh.run_duration ELSE NULL END) + 1000000 AS VARCHAR(7)),6,2) 65 | AS last_duration 66 | , MAX(CASE WHEN le.last_instance_id IS NOT NULL THEN 67 | CONVERT(datetime, RTRIM(run_date)) 68 | + ((run_time / 10000 * 3600) 69 | + ((run_time % 10000) / 100 * 60) 70 | + (run_time % 10000) % 100) / (86399.9964) 71 | ELSE '1900-01-01' END) AS last_execution_start 72 | FROM msdb.dbo.sysjobhistory AS sjh 73 | LEFT JOIN lastExecution AS le 74 | ON sjh.job_id = le.job_id 75 | AND sjh.instance_id = le.last_instance_id 76 | GROUP BY sjh.job_id; 77 | 78 | /* We need to parse the schedule into something we can understand */ 79 | DECLARE @weekDay TABLE ( 80 | mask INT 81 | , maskValue VARCHAR(32) 82 | ); 83 | 84 | INSERT INTO @weekDay 85 | SELECT 1, 'Sunday' UNION ALL 86 | SELECT 2, 'Monday' UNION ALL 87 | SELECT 4, 'Tuesday' UNION ALL 88 | SELECT 8, 'Wednesday' UNION ALL 89 | SELECT 16, 'Thursday' UNION ALL 90 | SELECT 32, 'Friday' UNION ALL 91 | SELECT 64, 'Saturday'; 92 | 93 | 94 | /* Now let's get our schedule information */ 95 | WITH myCTE 96 | AS( 97 | SELECT sched.name AS 'scheduleName' 98 | , sched.schedule_id 99 | , jobsched.job_id 100 | , CASE 101 | WHEN sched.freq_type = 1 102 | THEN 'Once' 103 | WHEN sched.freq_type = 4 104 | AND sched.freq_interval = 1 105 | THEN 'Daily' 106 | WHEN sched.freq_type = 4 107 | THEN 'Every ' + CAST(sched.freq_interval AS VARCHAR(5)) + ' days' 108 | WHEN sched.freq_type = 8 THEN 109 | REPLACE( REPLACE( REPLACE(( 110 | SELECT maskValue 111 | FROM @weekDay AS x 112 | WHERE sched.freq_interval & x.mask <> 0 113 | ORDER BY mask FOR XML RAW) 114 | , '"/>', '') 115 | + CASE 116 | WHEN sched.freq_recurrence_factor <> 0 117 | AND sched.freq_recurrence_factor = 1 118 | THEN '; weekly' 119 | WHEN sched.freq_recurrence_factor <> 0 120 | THEN '; every ' 121 | + CAST(sched.freq_recurrence_factor AS VARCHAR(10)) + ' weeks' END 122 | WHEN sched.freq_type = 16 THEN 'On day ' 123 | + CAST(sched.freq_interval AS VARCHAR(10)) + ' of every ' 124 | + CAST(sched.freq_recurrence_factor AS VARCHAR(10)) + ' months' 125 | WHEN sched.freq_type = 32 THEN 126 | CASE 127 | WHEN sched.freq_relative_interval = 1 THEN 'First' 128 | WHEN sched.freq_relative_interval = 2 THEN 'Second' 129 | WHEN sched.freq_relative_interval = 4 THEN 'Third' 130 | WHEN sched.freq_relative_interval = 8 THEN 'Fourth' 131 | WHEN sched.freq_relative_interval = 16 THEN 'Last' 132 | END + 133 | CASE 134 | WHEN sched.freq_interval = 1 THEN ' Sunday' 135 | WHEN sched.freq_interval = 2 THEN ' Monday' 136 | WHEN sched.freq_interval = 3 THEN ' Tuesday' 137 | WHEN sched.freq_interval = 4 THEN ' Wednesday' 138 | WHEN sched.freq_interval = 5 THEN ' Thursday' 139 | WHEN sched.freq_interval = 6 THEN ' Friday' 140 | WHEN sched.freq_interval = 7 THEN ' Saturday' 141 | WHEN sched.freq_interval = 8 THEN ' Day' 142 | WHEN sched.freq_interval = 9 THEN ' Weekday' 143 | WHEN sched.freq_interval = 10 THEN ' Weekend' 144 | END 145 | + CASE 146 | WHEN sched.freq_recurrence_factor <> 0 147 | AND sched.freq_recurrence_factor = 1 148 | THEN '; monthly' 149 | WHEN sched.freq_recurrence_factor <> 0 150 | THEN '; every ' 151 | + CAST(sched.freq_recurrence_factor AS VARCHAR(10)) + ' months' 152 | END 153 | WHEN sched.freq_type = 64 THEN 'StartUp' 154 | WHEN sched.freq_type = 128 THEN 'Idle' 155 | END AS 'frequency' 156 | , ISNULL('Every ' + CAST(sched.freq_subday_interval AS VARCHAR(10)) + 157 | CASE 158 | WHEN sched.freq_subday_type = 2 THEN ' seconds' 159 | WHEN sched.freq_subday_type = 4 THEN ' minutes' 160 | WHEN sched.freq_subday_type = 8 THEN ' hours' 161 | END, 'Once') AS 'subFrequency' 162 | , REPLICATE('0', 6 - LEN(sched.active_start_time)) 163 | + CAST(sched.active_start_time AS VARCHAR(6)) AS 'startTime' 164 | , REPLICATE('0', 6 - LEN(sched.active_end_time)) 165 | + CAST(sched.active_end_time AS VARCHAR(6)) AS 'endTime' 166 | , REPLICATE('0', 6 - LEN(jobsched.next_run_time)) 167 | + CAST(jobsched.next_run_time AS VARCHAR(6)) AS 'nextRunTime' 168 | , CAST(jobsched.next_run_date AS CHAR(8)) AS 'nextRunDate' 169 | FROM msdb.dbo.sysschedules AS sched 170 | JOIN msdb.dbo.sysjobschedules AS jobsched 171 | ON sched.schedule_id = jobsched.schedule_id 172 | WHERE sched.enabled = 1 173 | ) 174 | 175 | /* Finally, let's look at our actual jobs and tie it all together */ 176 | SELECT CONVERT(NVARCHAR(128), SERVERPROPERTY('Servername')) AS [serverName] 177 | , job.job_id AS [jobID] 178 | , job.name AS [jobName] 179 | , CASE WHEN job.enabled = 1 THEN 'Enabled' ELSE 'Disabled' END AS [jobStatus] 180 | , COALESCE(sched.scheduleName, '(unscheduled)') AS [scheduleName] 181 | , COALESCE(sched.frequency, '') AS [frequency] 182 | , COALESCE(sched.subFrequency, '') AS [subFrequency] 183 | , COALESCE(SUBSTRING(sched.startTime, 1, 2) + ':' 184 | + SUBSTRING(sched.startTime, 3, 2) + ' - ' 185 | + SUBSTRING(sched.endTime, 1, 2) + ':' 186 | + SUBSTRING(sched.endTime, 3, 2), '') AS [scheduleTime] -- HH:MM 187 | , COALESCE(SUBSTRING(sched.nextRunDate, 1, 4) + '/' 188 | + SUBSTRING(sched.nextRunDate, 5, 2) + '/' 189 | + SUBSTRING(sched.nextRunDate, 7, 2) + ' ' 190 | + SUBSTRING(sched.nextRunTime, 1, 2) + ':' 191 | + SUBSTRING(sched.nextRunTime, 3, 2), '') AS [nextRunDate] 192 | /* Note: the sysjobschedules table refreshes every 20 min, so nextRunDate may be out of date */ 193 | , COALESCE(jh.success, 0) AS [success] 194 | , COALESCE(jh.cancel, 0) AS [cancel] 195 | , COALESCE(jh.fail, 0) AS [fail] 196 | , COALESCE(jh.retry, 0) AS [retry] 197 | , COALESCE(jh.last_execution_id, 0) AS [lastExecutionID] 198 | , jh.last_execution_start AS [lastExecutionStart] 199 | , COALESCE(jh.last_duration, '00:00:01') AS [lastDuration] 200 | , 'EXECUTE msdb.dbo.sp_update_job @job_id = ''' 201 | + CAST(job.job_id AS CHAR(36)) + ''', @enabled = 0;' AS [disableSQLScript] 202 | FROM msdb.dbo.sysjobs AS job 203 | LEFT JOIN myCTE AS sched 204 | ON job.job_id = sched.job_id 205 | LEFT JOIN @jobHistory AS jh 206 | ON job.job_id = jh.job_id 207 | WHERE job.enabled = 1 -- do not display disabled jobs 208 | --AND jh.last_execution_start >= DATEADD(day, -1, GETDATE()) /* Pull just the last 24 hours */ 209 | ORDER BY nextRunDate; -------------------------------------------------------------------------------- /dev/bcp_script_generator.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: bcp_script_generator.sql 4 | 5 | SYNOPSIS: Generates bcp scripts using SQL Server metadata 6 | 7 | DEPENDENCIES: The following dependencies are required to execute this script: 8 | - SQL Server 2005 or newer 9 | 10 | AUTHOR: Michelle Ufford, http://sqlfool.com 11 | 12 | CREATED: 2012-05-17 13 | 14 | VERSION: 1.0 15 | 16 | LICENSE: Apache License v2 17 | 18 | ---------------------------------------------------------------------------- 19 | DISCLAIMER: 20 | This code and information are provided "AS IS" without warranty of any kind, 21 | either expressed or implied, including but not limited to the implied 22 | warranties or merchantability and/or fitness for a particular purpose. 23 | ---------------------------------------------------------------------------- 24 | 25 | --------------------------------------------------------------------------------------------------------- 26 | -- DATE VERSION AUTHOR DESCRIPTION -- 27 | --------------------------------------------------------------------------------------------------------- 28 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 29 | **********************************************************************************************************/ 30 | 31 | -- User-defined variables -- 32 | 33 | DECLARE @tableToBCP NVARCHAR(128) = 'sandbox.dbo.example_table' 34 | , @Top VARCHAR(10) = NULL -- Leave NULL for all rows 35 | , @Delimiter VARCHAR(4) = '|' 36 | , @UseNULL BIT = 1 37 | , @OverrideChar CHAR(1) = '~' 38 | , @MaxDop CHAR(1) = '1' 39 | , @Directory VARCHAR(256) = 'D:\dba\mufford\scripts'; 40 | 41 | 42 | -- Script-defined variables -- 43 | 44 | DECLARE @columnList TABLE (columnID INT); 45 | 46 | DECLARE @bcpStatement NVARCHAR(MAX) = 'BCP "SELECT ' 47 | , @currentID INT 48 | , @firstID INT; 49 | 50 | INSERT INTO @columnList 51 | SELECT column_id 52 | FROM sys.columns 53 | WHERE object_id = OBJECT_ID(@tableToBCP) 54 | ORDER BY column_id; 55 | 56 | IF @Top IS NOT NULL 57 | SET @bcpStatement = @bcpStatement + 'TOP (' + @Top + ') '; 58 | 59 | SELECT @firstID = MIN(columnID) FROM @columnList; 60 | 61 | WHILE EXISTS(SELECT * FROM @columnList) 62 | BEGIN 63 | 64 | SELECT @currentID = MIN(columnID) FROM @columnList; 65 | 66 | IF @currentID <> @firstID 67 | SET @bcpStatement = @bcpStatement + ','; 68 | 69 | SELECT @bcpStatement = @bcpStatement + 70 | CASE 71 | WHEN user_type_id IN (231, 167, 175, 239) 72 | THEN 'CASE WHEN ' + name + ' = '''' THEN ' 73 | + CASE 74 | WHEN is_nullable = 1 THEN 'NULL' 75 | ELSE '''' + REPLICATE(@OverrideChar, max_length) + '''' 76 | END 77 | + ' WHEN ' + name + ' LIKE ''%' + @Delimiter + '%''' 78 | + ' OR ' + name + ' LIKE ''%'' + CHAR(9) + ''%''' -- tab 79 | + ' OR ' + name + ' LIKE ''%'' + CHAR(10) + ''%''' -- line feed 80 | + ' OR ' + name + ' LIKE ''%'' + CHAR(13) + ''%''' -- carriage return 81 | + ' THEN ' 82 | + CASE 83 | WHEN is_nullable = 1 THEN 'NULL' 84 | ELSE '''' + REPLICATE(@OverrideChar, max_length) + '''' 85 | END 86 | + ' ELSE ' + name + ' END' 87 | ELSE name 88 | END 89 | FROM sys.columns 90 | WHERE object_id = OBJECT_ID(@tableToBCP) 91 | AND column_id = @currentID; 92 | 93 | DELETE FROM @columnList WHERE columnID = @currentID; 94 | 95 | 96 | END; 97 | 98 | SET @bcpStatement = @bcpStatement + ' FROM ' + @tableToBCP 99 | + ' WITH (NOLOCK) OPTION (MAXDOP 1);" queryOut ' 100 | + @Directory + REPLACE(@tableToBCP, '.', '_') + '.dat -S' + @@SERVERNAME 101 | + ' -T -t"' + @Delimiter + '" -c -C;' 102 | 103 | SELECT @bcpStatement; -------------------------------------------------------------------------------- /dev/dba_parseString_udf.sql: -------------------------------------------------------------------------------- 1 | 2 | /* Let's create our parsing function... */ 3 | CREATE FUNCTION dbo.dba_parseString_udf 4 | ( 5 | @stringToParse VARCHAR(8000) 6 | , @delimiter CHAR(1) 7 | ) 8 | RETURNS @parsedString TABLE (stringValue VARCHAR(128)) 9 | AS 10 | /********************************************************************************* 11 | Name: dba_parseString_udf 12 | 13 | Author: Michelle Ufford, http://sqlfool.com 14 | 15 | Purpose: This function parses string input using a variable delimiter. 16 | 17 | Notes: Two common delimiter values are space (' ') and comma (',') 18 | 19 | Date Initials Description 20 | ---------------------------------------------------------------------------- 21 | 2011-05-20 MFU Initial Release 22 | ********************************************************************************* 23 | Usage: 24 | SELECT * 25 | FROM dba_parseString_udf(, ); 26 | 27 | Test Cases: 28 | 29 | 1. multiple strings separated by space 30 | SELECT * FROM dbo.dba_parseString_udf(' aaa bbb ccc ', ' '); 31 | 32 | 2. multiple strings separated by comma 33 | SELECT * FROM dbo.dba_parseString_udf(',aaa,bbb,,,ccc,', ','); 34 | *********************************************************************************/ 35 | BEGIN 36 | 37 | /* Declare variables */ 38 | DECLARE @trimmedString VARCHAR(8000); 39 | 40 | /* We need to trim our string input in case the user entered extra spaces */ 41 | SET @trimmedString = LTRIM(RTRIM(@stringToParse)); 42 | 43 | /* Let's create a recursive CTE to break down our string for us */ 44 | WITH parseCTE (StartPos, EndPos) 45 | AS 46 | ( 47 | SELECT 1 AS StartPos 48 | , CHARINDEX(@delimiter, @trimmedString + @delimiter) AS EndPos 49 | UNION ALL 50 | SELECT EndPos + 1 AS StartPos 51 | , CharIndex(@delimiter, @trimmedString + @delimiter , EndPos + 1) AS EndPos 52 | FROM parseCTE 53 | WHERE CHARINDEX(@delimiter, @trimmedString + @delimiter, EndPos + 1) <> 0 54 | ) 55 | 56 | /* Let's take the results and stick it in a table */ 57 | INSERT INTO @parsedString 58 | SELECT SUBSTRING(@trimmedString, StartPos, EndPos - StartPos) 59 | FROM parseCTE 60 | WHERE LEN(LTRIM(RTRIM(SUBSTRING(@trimmedString, StartPos, EndPos - StartPos)))) > 0 61 | OPTION (MaxRecursion 8000); 62 | 63 | RETURN; 64 | END -------------------------------------------------------------------------------- /dev/insert_statement_generator.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: insert_statement_generator.sql 4 | 5 | SYNOPSIS: Generates insert statements for Teradata using SQL Server metadata. 6 | This is useful for easily migrating small tables (i.e. < 1000 rows) 7 | from SQL Server to Teradata. DO NOT use on large tables. 8 | 9 | DEPENDENCIES: The following dependencies are required to execute this script: 10 | - SQL Server 2005 or newer 11 | 12 | AUTHOR: Michelle Ufford, http://sqlfool.com 13 | 14 | CREATED: 2012-07-26 15 | 16 | VERSION: 1.0 17 | 18 | LICENSE: Apache License v2 19 | 20 | ---------------------------------------------------------------------------- 21 | DISCLAIMER: 22 | This code and information are provided "AS IS" without warranty of any kind, 23 | either expressed or implied, including but not limited to the implied 24 | warranties or merchantability and/or fitness for a particular purpose. 25 | ---------------------------------------------------------------------------- 26 | 27 | --------------------------------------------------------------------------------------------------------- 28 | -- DATE VERSION AUTHOR DESCRIPTION -- 29 | --------------------------------------------------------------------------------------------------------- 30 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 31 | **********************************************************************************************************/ 32 | 33 | -- User-defined variables -- 34 | DECLARE 35 | @tableName NVARCHAR(128) = 'dbo.example_table' 36 | , @Top VARCHAR(10) = 1000 -- Leave NULL for all rows 37 | , @Execute BIT = 1 38 | , @GenerateSchema BIT = 1 39 | , @GenerateTruncate BIT = 1 40 | , @TeradataDatabase VARCHAR(30) = 'mufford' 41 | , @TeradataTable VARCHAR(30) = NULL -- Will generate if you leave NULL 42 | 43 | -- Script-defined variables -- 44 | 45 | DECLARE @columnList TABLE (columnID INT); 46 | DECLARE @TeradataTableName VARCHAR(60); 47 | 48 | IF @TeradataTable IS NULL 49 | SET @TeradataTableName = @TeradataDatabase + '.tmp_' + SUBSTRING(@tableName,PATINDEX('%.%',@tableName)+1,26); 50 | ELSE 51 | SET @TeradataTableName = @TeradataDatabase + '.' + @TeradataTable; 52 | 53 | DECLARE @insertStatement NVARCHAR(MAX) = '' --= 'SELECT ' 54 | , @columnStatement NVARCHAR(MAX) = 'INSERT INTO ' + @TeradataTableName + ' (' 55 | , @schemaStatement NVARCHAR(MAX) = 'CREATE TABLE ' + @TeradataTableName + '(' 56 | , @currentID INT 57 | , @firstID INT; 58 | 59 | INSERT INTO @columnList 60 | SELECT column_id 61 | FROM sys.columns 62 | WHERE object_id = OBJECT_ID(@tableName) 63 | ORDER BY column_id; 64 | 65 | SELECT @firstID = MIN(columnID) FROM @columnList; 66 | 67 | WHILE EXISTS(SELECT * FROM @columnList) 68 | BEGIN 69 | 70 | SELECT @currentID = MIN(columnID) FROM @columnList; 71 | 72 | IF @currentID <> @firstID 73 | BEGIN 74 | SELECT 75 | @columnStatement = @columnStatement + ',' 76 | , @schemaStatement = @schemaStatement + ',' 77 | , @insertStatement = @insertStatement + '+'',''+'; 78 | END 79 | 80 | SELECT @columnStatement = @columnStatement + '"' + SUBSTRING(name, 1, 30) + '"' 81 | FROM sys.columns 82 | WHERE object_id = OBJECT_ID(@tableName) 83 | AND column_id = @currentID; 84 | 85 | SELECT @schemaStatement = @schemaStatement + '"' + SUBSTRING(c.name, 1, 30) + '" ' 86 | + CASE 87 | WHEN t.name = 'BIT' THEN 'BYTEINT' 88 | WHEN t.name = 'TINYINT' THEN 'SMALLINT' 89 | WHEN t.name = 'UNIQUEIDENTIFIER' THEN 'CHAR(38)' 90 | WHEN t.name = 'DATETIME' THEN 'TIMESTAMP(3)' 91 | WHEN t.name = 'MONEY' THEN 'DECIMAL(18,4)' 92 | WHEN t.name = 'XML' THEN 'CLOB' 93 | WHEN t.name IN ('SMALLDATETIME', 'DATETIME2') THEN 'TIMESTAMP(0)' 94 | WHEN t.name IN ('NVARCHAR','NCHAR') 95 | THEN SUBSTRING(t.name, 2, 10) + '(' + CAST(c.max_length / 2 AS VARCHAR(4)) + ') CHARACTER SET UNICODE NOT CASESPECIFIC' 96 | WHEN t.name IN ('VARCHAR','CHAR') 97 | THEN t.name + '(' + CAST(c.max_length AS VARCHAR(4)) + ')' 98 | ELSE t.name 99 | END 100 | + CASE 101 | WHEN c.is_nullable = 1 THEN ' NULL' 102 | ELSE ' NOT NULL' 103 | END 104 | FROM sys.columns AS c 105 | JOIN sys.types AS t 106 | ON c.system_type_id = t.system_type_id 107 | WHERE c.object_id = OBJECT_ID(@tableName) 108 | AND c.column_id = @currentID; 109 | 110 | SELECT DISTINCT @insertStatement = @insertStatement 111 | + 'CASE WHEN ' + QUOTENAME(c.name) + ' IS NULL THEN ''NULL'' ELSE ' + 112 | + CASE 113 | WHEN t.name IN ('tinyint','smallint','int','real','float','bit','decimal','numeric','smallmoney','bigint') /* number-based columns */ 114 | THEN 'CAST(' + QUOTENAME(c.name) + ' AS VARCHAR(' + CAST(c.precision AS VARCHAR(10)) + '))' 115 | WHEN t.name IN ('datetime', 'date', 'datetime2', 'smalldatetime') /* date-based columns */ 116 | THEN '''''''''+' + 'CONVERT(VARCHAR(23),' + QUOTENAME(c.name) + ',126)' + '+''''''''' 117 | WHEN t.name IN ('uniqueidentifier') /* guid columns */ 118 | THEN '''''''''+' + 'CAST(' + QUOTENAME(c.name) + ' AS CHAR(36))' + '+''''''''' 119 | WHEN t.name IN ('XML') /* xml columns */ 120 | THEN '''''''''+' + 'CAST(' + QUOTENAME(c.name) + ' AS VARCHAR(MAX))' + '+''''''''' 121 | ELSE '''''''''+REPLACE(' + QUOTENAME(c.name) + ','''''''','''''''''''')+''''''''' --'''+''''''+''' /* character-based columns */ 122 | END 123 | + ' END ' 124 | FROM sys.columns AS c 125 | JOIN sys.types AS t 126 | ON c.system_type_id = t.system_type_id 127 | WHERE c.object_id = OBJECT_ID(@tableName) 128 | AND c.column_id = @currentID; 129 | 130 | DELETE FROM @columnList WHERE columnID = @currentID; 131 | 132 | END; 133 | 134 | SET @insertStatement = 'SELECT ' + CASE WHEN @Top IS NOT NULL THEN 'TOP (' + @Top + ') ' ELSE '' END + '''' + @columnStatement + ') VALUES (''+' + @insertStatement + '+'');'' FROM ' + @tableName + ' WITH (NOLOCK);'; 135 | 136 | IF @GenerateSchema = 1 137 | SELECT @schemaStatement + ');' AS 'Execute this statement in Teradata to create the table:' 138 | 139 | IF @GenerateTruncate = 1 140 | SELECT 'DELETE FROM ' + @TeradataTableName + ';' AS 'Execute this statement in Teradata to truncate the table:' 141 | 142 | IF @Execute = 1 143 | EXECUTE sp_executeSQL @insertStatement; 144 | ELSE 145 | SELECT @insertStatement AS 'Execute this statement in SQL Server to generate commands:'; 146 | -------------------------------------------------------------------------------- /dev/teradata_ddl_generator.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: teradata_ddl_generator.sql 4 | 5 | SYNOPSIS: Generates Teradata DDL using SQL Server metadata 6 | 7 | DEPENDENCIES: The following dependencies are required to execute this script: 8 | - SQL Server 2005 or newer 9 | 10 | AUTHOR: Michelle Ufford, http://sqlfool.com 11 | 12 | CREATED: 2012-05-17 13 | 14 | VERSION: 1.0 15 | 16 | LICENSE: Apache License v2 17 | 18 | ---------------------------------------------------------------------------- 19 | DISCLAIMER: 20 | This code and information are provided "AS IS" without warranty of any kind, 21 | either expressed or implied, including but not limited to the implied 22 | warranties or merchantability and/or fitness for a particular purpose. 23 | ---------------------------------------------------------------------------- 24 | 25 | --------------------------------------------------------------------------------------------------------- 26 | -- DATE VERSION AUTHOR DESCRIPTION -- 27 | --------------------------------------------------------------------------------------------------------- 28 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 29 | **********************************************************************************************************/ 30 | 31 | -- User-defined variables -- 32 | DECLARE 33 | @tableName NVARCHAR(128) = 'dbo.example_table' 34 | , @TeradataDatabase VARCHAR(30) = 'mufford' 35 | , @TeradataTable VARCHAR(30) = NULL -- Will generate if you leave NULL 36 | 37 | 38 | -- Script-defined variables -- 39 | 40 | DECLARE @columnList TABLE (columnID INT); 41 | DECLARE @TeradataTableName VARCHAR(60); 42 | 43 | IF @TeradataTable IS NULL 44 | SET @TeradataTableName = @TeradataDatabase + '.tmp_' + SUBSTRING(@tableName,PATINDEX('%.%',@tableName)+1,26); 45 | ELSE 46 | SET @TeradataTableName = @TeradataDatabase + '.' + @TeradataTable; 47 | 48 | DECLARE 49 | @schemaStatement NVARCHAR(MAX) = 'CREATE TABLE ' + @TeradataTableName + '(' 50 | , @currentID INT 51 | , @firstID INT; 52 | 53 | INSERT INTO @columnList 54 | SELECT column_id 55 | FROM sys.columns 56 | WHERE object_id = OBJECT_ID(@tableName) 57 | ORDER BY column_id; 58 | 59 | SELECT @firstID = MIN(columnID) FROM @columnList; 60 | 61 | WHILE EXISTS(SELECT * FROM @columnList) 62 | BEGIN 63 | 64 | SELECT @currentID = MIN(columnID) FROM @columnList; 65 | 66 | IF @currentID <> @firstID 67 | BEGIN 68 | SELECT 69 | @schemaStatement = @schemaStatement + ','; 70 | END 71 | 72 | SELECT @schemaStatement = @schemaStatement + '"' + c.name + '" ' 73 | + CASE 74 | WHEN t.name = 'BIT' THEN 'BYTEINT' 75 | WHEN t.name = 'TINYINT' THEN 'SMALLINT' 76 | WHEN t.name = 'UNIQUEIDENTIFIER' THEN 'CHAR(38)' 77 | WHEN t.name = 'DATETIME' THEN 'TIMESTAMP(3)' 78 | WHEN t.name = 'MONEY' THEN 'DECIMAL(18,4)' 79 | WHEN t.name = 'XML' THEN 'CLOB' 80 | WHEN t.name IN ('SMALLDATETIME', 'DATETIME2') THEN 'TIMESTAMP(0)' 81 | WHEN t.name IN ('NVARCHAR','NCHAR') 82 | THEN SUBSTRING(t.name, 2, 10) + '(' + CAST(c.max_length / 2 AS VARCHAR(4)) + ') CHARACTER SET UNICODE NOT CASESPECIFIC' 83 | WHEN t.name IN ('VARCHAR','CHAR') 84 | THEN t.name + '(' + CAST(c.max_length AS VARCHAR(4)) + ')' 85 | ELSE t.name 86 | END 87 | + CASE 88 | WHEN c.is_nullable = 1 THEN ' NULL' 89 | ELSE ' NOT NULL' 90 | END 91 | FROM sys.columns AS c 92 | JOIN sys.types AS t 93 | ON c.system_type_id = t.system_type_id 94 | WHERE c.object_id = OBJECT_ID(@tableName) 95 | AND c.column_id = @currentID; 96 | 97 | DELETE FROM @columnList WHERE columnID = @currentID; 98 | 99 | END; 100 | 101 | SELECT @schemaStatement + ');' AS 'Execute this statement in Teradata to create the table:' -------------------------------------------------------------------------------- /indexes/dba_indexDefrag_sp.sql: -------------------------------------------------------------------------------- 1 | /*** Scroll down to the see important notes, disclaimers, and licensing information ***/ 2 | 3 | /* Let's create our parsing function... */ 4 | IF EXISTS ( SELECT [object_id] 5 | FROM sys.objects 6 | WHERE name = 'dba_parseString_udf' ) 7 | DROP FUNCTION dbo.dba_parseString_udf; 8 | GO 9 | 10 | CREATE FUNCTION dbo.dba_parseString_udf 11 | ( 12 | @stringToParse VARCHAR(8000) 13 | , @delimiter CHAR(1) 14 | ) 15 | RETURNS @parsedString TABLE (stringValue VARCHAR(128)) 16 | AS 17 | /********************************************************************************* 18 | Name: dba_parseString_udf 19 | 20 | Author: Michelle Ufford, http://sqlfool.com 21 | 22 | Purpose: This function parses string input using a variable delimiter. 23 | 24 | Notes: Two common delimiter values are space (' ') and comma (',') 25 | 26 | Date Initials Description 27 | ---------------------------------------------------------------------------- 28 | 2011-05-20 MFU Initial Release 29 | ********************************************************************************* 30 | Usage: 31 | SELECT * 32 | FROM dba_parseString_udf(, ); 33 | 34 | Test Cases: 35 | 36 | 1. multiple strings separated by space 37 | SELECT * FROM dbo.dba_parseString_udf(' aaa bbb ccc ', ' '); 38 | 39 | 2. multiple strings separated by comma 40 | SELECT * FROM dbo.dba_parseString_udf(',aaa,bbb,,,ccc,', ','); 41 | *********************************************************************************/ 42 | BEGIN 43 | 44 | /* Declare variables */ 45 | DECLARE @trimmedString VARCHAR(8000); 46 | 47 | /* We need to trim our string input in case the user entered extra spaces */ 48 | SET @trimmedString = LTRIM(RTRIM(@stringToParse)); 49 | 50 | /* Let's create a recursive CTE to break down our string for us */ 51 | WITH parseCTE (StartPos, EndPos) 52 | AS 53 | ( 54 | SELECT 1 AS StartPos 55 | , CHARINDEX(@delimiter, @trimmedString + @delimiter) AS EndPos 56 | UNION ALL 57 | SELECT EndPos + 1 AS StartPos 58 | , CHARINDEX(@delimiter, @trimmedString + @delimiter , EndPos + 1) AS EndPos 59 | FROM parseCTE 60 | WHERE CHARINDEX(@delimiter, @trimmedString + @delimiter, EndPos + 1) <> 0 61 | ) 62 | 63 | /* Let's take the results and stick it in a table */ 64 | INSERT INTO @parsedString 65 | SELECT SUBSTRING(@trimmedString, StartPos, EndPos - StartPos) 66 | FROM parseCTE 67 | WHERE LEN(LTRIM(RTRIM(SUBSTRING(@trimmedString, StartPos, EndPos - StartPos)))) > 0 68 | OPTION (MaxRecursion 8000); 69 | 70 | RETURN; 71 | END 72 | GO 73 | 74 | /* First, we need to take care of schema updates, in case you have a legacy 75 | version of the script installed */ 76 | DECLARE @indexDefragLog_rename VARCHAR(128) 77 | , @indexDefragExclusion_rename VARCHAR(128) 78 | , @indexDefragStatus_rename VARCHAR(128); 79 | 80 | SELECT @indexDefragLog_rename = 'dba_indexDefragLog_obsolete_' + CONVERT(VARCHAR(10), GETDATE(), 112) 81 | , @indexDefragExclusion_rename = 'dba_indexDefragExclusion_obsolete_' + CONVERT(VARCHAR(10), GETDATE(), 112); 82 | 83 | IF EXISTS ( SELECT [object_id] 84 | FROM sys.indexes 85 | WHERE name = 'PK_indexDefragLog' ) 86 | EXECUTE sp_rename dba_indexDefragLog, @indexDefragLog_rename; 87 | 88 | IF EXISTS ( SELECT [object_id] 89 | FROM sys.indexes 90 | WHERE name = 'PK_indexDefragExclusion' ) 91 | EXECUTE sp_rename dba_indexDefragExclusion, @indexDefragExclusion_rename; 92 | 93 | IF NOT EXISTS ( SELECT [object_id] 94 | FROM sys.indexes 95 | WHERE name = 'PK_indexDefragLog_v40' ) 96 | BEGIN 97 | 98 | CREATE TABLE dbo.dba_indexDefragLog 99 | ( 100 | indexDefrag_id INT IDENTITY(1, 1) NOT NULL 101 | , databaseID INT NOT NULL 102 | , databaseName NVARCHAR(128) NOT NULL 103 | , objectID INT NOT NULL 104 | , objectName NVARCHAR(128) NOT NULL 105 | , indexID INT NOT NULL 106 | , indexName NVARCHAR(128) NOT NULL 107 | , partitionNumber SMALLINT NOT NULL 108 | , fragmentation FLOAT NOT NULL 109 | , page_count INT NOT NULL 110 | , dateTimeStart DATETIME NOT NULL 111 | , dateTimeEnd DATETIME NULL 112 | , durationSeconds INT NULL 113 | , sqlStatement VARCHAR(4000) NULL 114 | , errorMessage VARCHAR(1000) NULL 115 | 116 | CONSTRAINT PK_indexDefragLog_v40 117 | PRIMARY KEY CLUSTERED (indexDefrag_id) 118 | ); 119 | 120 | PRINT 'dba_indexDefragLog Table Created'; 121 | 122 | END 123 | 124 | IF NOT EXISTS ( SELECT [object_id] 125 | FROM sys.indexes 126 | WHERE name = 'PK_indexDefragExclusion_v40' ) 127 | BEGIN 128 | 129 | CREATE TABLE dbo.dba_indexDefragExclusion 130 | ( 131 | databaseID INT NOT NULL 132 | , databaseName NVARCHAR(128) NOT NULL 133 | , objectID INT NOT NULL 134 | , objectName NVARCHAR(128) NOT NULL 135 | , indexID INT NOT NULL 136 | , indexName NVARCHAR(128) NOT NULL 137 | , exclusionMask INT NOT NULL 138 | /* 1=Sunday, 2=Monday, 4=Tuesday, 8=Wednesday, 16=Thursday, 32=Friday, 64=Saturday */ 139 | 140 | CONSTRAINT PK_indexDefragExclusion_v40 141 | PRIMARY KEY CLUSTERED (databaseID, objectID, indexID) 142 | ); 143 | 144 | PRINT 'dba_indexDefragExclusion Table Created'; 145 | 146 | END 147 | 148 | IF NOT EXISTS ( SELECT [object_id] 149 | FROM sys.indexes 150 | WHERE name = 'PK_indexDefragStatus_v40' ) 151 | BEGIN 152 | 153 | CREATE TABLE dbo.dba_indexDefragStatus 154 | ( 155 | databaseID INT NOT NULL 156 | , databaseName NVARCHAR(128) NOT NULL 157 | , objectID INT NOT NULL 158 | , indexID INT NOT NULL 159 | , partitionNumber SMALLINT NOT NULL 160 | , fragmentation FLOAT NOT NULL 161 | , page_count INT NOT NULL 162 | , range_scan_count BIGINT NOT NULL 163 | , schemaName NVARCHAR(128) NULL 164 | , objectName NVARCHAR(128) NULL 165 | , indexName NVARCHAR(128) NULL 166 | , scanDate DATETIME NOT NULL 167 | , defragDate DATETIME NULL 168 | , printStatus BIT DEFAULT (0) NOT NULL 169 | , exclusionMask INT DEFAULT (0) NOT NULL 170 | 171 | CONSTRAINT PK_indexDefragStatus_v40 172 | PRIMARY KEY CLUSTERED (databaseID, objectID, indexID, partitionNumber) 173 | ); 174 | 175 | PRINT 'dba_indexDefragStatus Table Created'; 176 | 177 | END; 178 | 179 | IF OBJECTPROPERTY(OBJECT_ID('dbo.dba_indexDefrag_sp'), N'IsProcedure') = 1 180 | BEGIN 181 | DROP PROCEDURE dbo.dba_indexDefrag_sp; 182 | PRINT 'Procedure dba_indexDefrag_sp dropped'; 183 | END; 184 | Go 185 | 186 | CREATE PROCEDURE dbo.dba_indexDefrag_sp 187 | 188 | /* Declare Parameters */ 189 | @minFragmentation FLOAT = 10.0 190 | /* in percent, will not defrag if fragmentation less than specified */ 191 | , @rebuildThreshold FLOAT = 30.0 192 | /* in percent, greater than @rebuildThreshold will result in rebuild instead of reorg */ 193 | , @executeSQL BIT = 1 194 | /* 1 = execute; 0 = print command only */ 195 | , @defragOrderColumn NVARCHAR(20) = 'range_scan_count' 196 | /* Valid options are: range_scan_count, fragmentation, page_count */ 197 | , @defragSortOrder NVARCHAR(4) = 'DESC' 198 | /* Valid options are: ASC, DESC */ 199 | , @timeLimit INT = 720 /* defaulted to 12 hours */ 200 | /* Optional time limitation; expressed in minutes */ 201 | , @database VARCHAR(128) = NULL 202 | /* Option to specify one or more database names, separated by commas; NULL will return all */ 203 | , @tableName VARCHAR(4000) = NULL -- databaseName.schema.tableName 204 | /* Option to specify a table name; null will return all */ 205 | , @forceRescan BIT = 0 206 | /* Whether or not to force a rescan of indexes; 1 = force, 0 = use existing scan, if available */ 207 | , @scanMode VARCHAR(10) = N'LIMITED' 208 | /* Options are LIMITED, SAMPLED, and DETAILED */ 209 | , @minPageCount INT = 8 210 | /* MS recommends > 1 extent (8 pages) */ 211 | , @maxPageCount INT = NULL 212 | /* NULL = no limit */ 213 | , @excludeMaxPartition BIT = 0 214 | /* 1 = exclude right-most populated partition; 0 = do not exclude; see notes for caveats */ 215 | , @onlineRebuild BIT = 1 216 | /* 1 = online rebuild; 0 = offline rebuild; only in Enterprise */ 217 | , @sortInTempDB BIT = 1 218 | /* 1 = perform sort operation in TempDB; 0 = perform sort operation in the index's database */ 219 | , @maxDopRestriction TINYINT = NULL 220 | /* Option to restrict the number of processors for the operation; only in Enterprise */ 221 | , @printCommands BIT = 0 222 | /* 1 = print commands; 0 = do not print commands */ 223 | , @printFragmentation BIT = 0 224 | /* 1 = print fragmentation prior to defrag; 225 | 0 = do not print */ 226 | , @defragDelay CHAR(8) = '00:00:05' 227 | /* time to wait between defrag commands */ 228 | , @debugMode BIT = 0 229 | /* display some useful comments to help determine if/WHERE issues occur */ 230 | AS /********************************************************************************* 231 | Name: dba_indexDefrag_sp 232 | 233 | Author: Michelle Ufford, http://sqlfool.com 234 | 235 | Purpose: Defrags one or more indexes for one or more databases 236 | 237 | Notes: 238 | 239 | CAUTION: TRANSACTION LOG SIZE SHOULD BE MONITORED CLOSELY WHEN DEFRAGMENTING. 240 | DO NOT RUN UNATTENDED ON LARGE DATABASES DURING BUSINESS HOURS. 241 | 242 | @minFragmentation defaulted to 10%, will not defrag if fragmentation 243 | is less than that 244 | 245 | @rebuildThreshold defaulted to 30% AS recommended by Microsoft in BOL; 246 | greater than 30% will result in rebuild instead 247 | 248 | @executeSQL 1 = execute the SQL generated by this proc; 249 | 0 = print command only 250 | 251 | @defragOrderColumn Defines how to prioritize the order of defrags. Only 252 | used if @executeSQL = 1. 253 | Valid options are: 254 | range_scan_count = count of range and table scans on the 255 | index; in general, this is what benefits 256 | the most FROM defragmentation 257 | fragmentation = amount of fragmentation in the index; 258 | the higher the number, the worse it is 259 | page_count = number of pages in the index; affects 260 | how long it takes to defrag an index 261 | 262 | @defragSortOrder The sort order of the ORDER BY clause. 263 | Valid options are ASC (ascending) or DESC (descending). 264 | 265 | @timeLimit Optional, limits how much time can be spent performing 266 | index defrags; expressed in minutes. 267 | 268 | NOTE: The time limit is checked BEFORE an index defrag 269 | is begun, thus a long index defrag can exceed the 270 | time limitation. 271 | 272 | @database Optional, specify specific database name to defrag; 273 | If not specified, all non-system databases will 274 | be defragged. 275 | 276 | @tableName Specify if you only want to defrag indexes for a 277 | specific table, format = databaseName.schema.tableName; 278 | if not specified, all tables will be defragged. 279 | 280 | @forceRescan Whether or not to force a rescan of indexes. If set 281 | to 0, a rescan will not occur until all indexes have 282 | been defragged. This can span multiple executions. 283 | 1 = force a rescan 284 | 0 = use previous scan, if there are indexes left to defrag 285 | 286 | @scanMode Specifies which scan mode to use to determine 287 | fragmentation levels. Options are: 288 | LIMITED - scans the parent level; quickest mode, 289 | recommended for most cases. 290 | SAMPLED - samples 1% of all data pages; if less than 291 | 10k pages, performs a DETAILED scan. 292 | DETAILED - scans all data pages. Use great care with 293 | this mode, AS it can cause performance issues. 294 | 295 | @minPageCount Specifies how many pages must exist in an index in order 296 | to be considered for a defrag. Defaulted to 8 pages, AS 297 | Microsoft recommends only defragging indexes with more 298 | than 1 extent (8 pages). 299 | 300 | NOTE: The @minPageCount will restrict the indexes that 301 | are stored in dba_indexDefragStatus table. 302 | 303 | @maxPageCount Specifies the maximum number of pages that can exist in 304 | an index and still be considered for a defrag. Useful 305 | for scheduling small indexes during business hours and 306 | large indexes for non-business hours. 307 | 308 | NOTE: The @maxPageCount will restrict the indexes that 309 | are defragged during the current operation; it will not 310 | prevent indexes FROM being stored in the 311 | dba_indexDefragStatus table. This way, a single scan 312 | can support multiple page count thresholds. 313 | 314 | @excludeMaxPartition If an index is partitioned, this option specifies whether 315 | to exclude the right-most populated partition. Typically, 316 | this is the partition that is currently being written to in 317 | a sliding-window scenario. Enabling this feature may reduce 318 | contention. This may not be applicable in other types of 319 | partitioning scenarios. Non-partitioned indexes are 320 | unaffected by this option. 321 | 1 = exclude right-most populated partition 322 | 0 = do not exclude 323 | 324 | @onlineRebuild 1 = online rebuild; 325 | 0 = offline rebuild 326 | 327 | @sortInTempDB Specifies whether to defrag the index in TEMPDB or in the 328 | database the index belongs to. Enabling this option may 329 | result in faster defrags and prevent database file size 330 | inflation. 331 | 1 = perform sort operation in TempDB 332 | 0 = perform sort operation in the index's database 333 | 334 | @maxDopRestriction Option to specify a processor limit for index rebuilds 335 | 336 | @printCommands 1 = print commands to screen; 337 | 0 = do not print commands 338 | 339 | @printFragmentation 1 = print fragmentation to screen; 340 | 0 = do not print fragmentation 341 | 342 | @defragDelay Time to wait between defrag commands; gives the 343 | server a little time to catch up 344 | 345 | @debugMode 1 = display debug comments; helps with troubleshooting 346 | 0 = do not display debug comments 347 | 348 | Called by: SQL Agent Job or DBA 349 | 350 | ---------------------------------------------------------------------------- 351 | DISCLAIMER: 352 | This code and information are provided "AS IS" without warranty of any kind, 353 | either expressed or implied, including but not limited to the implied 354 | warranties or merchantability and/or fitness for a particular purpose. 355 | ---------------------------------------------------------------------------- 356 | LICENSE: 357 | This index defrag script is free to download and use for personal, educational, 358 | and internal corporate purposes, provided that this header is preserved. 359 | Redistribution or sale of this index defrag script, in whole or in part, is 360 | prohibited without the author's express written consent. 361 | ---------------------------------------------------------------------------- 362 | Date Initials Version Description 363 | ---------------------------------------------------------------------------- 364 | 2007-12-18 MFU 1.0 Initial Release 365 | 2008-10-17 MFU 1.1 Added @defragDelay, CIX_temp_indexDefragList 366 | 2008-11-17 MFU 1.2 Added page_count to log table 367 | , added @printFragmentation option 368 | 2009-03-17 MFU 2.0 Provided support for centralized execution 369 | , consolidated Enterprise & Standard versions 370 | , added @debugMode, @maxDopRestriction 371 | , modified LOB and partition logic 372 | 2009-06-18 MFU 3.0 Fixed bug in LOB logic, added @scanMode option 373 | , added support for stat rebuilds (@rebuildStats) 374 | , support model and msdb defrag 375 | , added columns to the dba_indexDefragLog table 376 | , modified logging to show "in progress" defrags 377 | , added defrag exclusion list (scheduling) 378 | 2009-08-28 MFU 3.1 Fixed read_only bug for database lists 379 | 2010-04-20 MFU 4.0 Added time limit option 380 | , added static table with rescan logic 381 | , added parameters for page count & SORT_IN_TEMPDB 382 | , added try/catch logic and additional debug options 383 | , added options for defrag prioritization 384 | , fixed bug for indexes with allow_page_lock = off 385 | , added option to exclude right-most partition 386 | , removed @rebuildStats option 387 | , refer to http://sqlfool.com for full release notes 388 | 2011-04-28 MFU 4.1 Bug fixes for databases requiring [] 389 | , cleaned up the create table section 390 | , updated syntax for case-sensitive databases 391 | , comma-delimited list for @database now supported 392 | ********************************************************************************* 393 | Example of how to call this script: 394 | 395 | EXECUTE dbo.dba_indexDefrag_sp 396 | @executeSQL = 1 397 | , @printCommands = 1 398 | , @debugMode = 1 399 | , @printFragmentation = 1 400 | , @forceRescan = 1 401 | , @maxDopRestriction = 1 402 | , @minPageCount = 8 403 | , @maxPageCount = NULL 404 | , @minFragmentation = 1 405 | , @rebuildThreshold = 30 406 | , @defragDelay = '00:00:05' 407 | , @defragOrderColumn = 'page_count' 408 | , @defragSortOrder = 'DESC' 409 | , @excludeMaxPartition = 1 410 | , @timeLimit = NULL 411 | , @database = 'sandbox,sandbox_caseSensitive'; 412 | *********************************************************************************/ 413 | SET NOCOUNT ON; 414 | SET XACT_ABORT ON; 415 | SET QUOTED_IDENTIFIER ON; 416 | 417 | BEGIN 418 | 419 | BEGIN TRY 420 | 421 | /* Just a little validation... */ 422 | IF @minFragmentation IS NULL 423 | OR @minFragmentation NOT BETWEEN 0.00 AND 100.0 424 | SET @minFragmentation = 10.0; 425 | 426 | IF @rebuildThreshold IS NULL 427 | OR @rebuildThreshold NOT BETWEEN 0.00 AND 100.0 428 | SET @rebuildThreshold = 30.0; 429 | 430 | IF @defragDelay NOT LIKE '00:[0-5][0-9]:[0-5][0-9]' 431 | SET @defragDelay = '00:00:05'; 432 | 433 | IF @defragOrderColumn IS NULL 434 | OR @defragOrderColumn NOT IN ('range_scan_count', 'fragmentation', 'page_count') 435 | SET @defragOrderColumn = 'range_scan_count'; 436 | 437 | IF @defragSortOrder IS NULL 438 | OR @defragSortOrder NOT IN ('ASC', 'DESC') 439 | SET @defragSortOrder = 'DESC'; 440 | 441 | IF @scanMode NOT IN ('LIMITED', 'SAMPLED', 'DETAILED') 442 | SET @scanMode = 'LIMITED'; 443 | 444 | IF @executeSQL IS NULL 445 | SET @executeSQL = 0; 446 | 447 | IF @debugMode IS NULL 448 | SET @debugMode = 0; 449 | 450 | IF @forceRescan IS NULL 451 | SET @forceRescan = 0; 452 | 453 | IF @minPageCount IS NULL 454 | SET @minPageCount = 8; 455 | 456 | IF @sortInTempDB IS NULL 457 | SET @sortInTempDB = 1; 458 | 459 | IF @onlineRebuild IS NULL 460 | SET @onlineRebuild = 0; 461 | 462 | IF @debugMode = 1 RAISERROR('Undusting the cogs AND starting up...', 0, 42) WITH NOWAIT; 463 | 464 | /* Declare our variables */ 465 | DECLARE @objectID INT 466 | , @databaseID INT 467 | , @databaseName NVARCHAR(128) 468 | , @indexID INT 469 | , @partitionCount BIGINT 470 | , @schemaName NVARCHAR(128) 471 | , @objectName NVARCHAR(128) 472 | , @indexName NVARCHAR(128) 473 | , @partitionNumber SMALLINT 474 | , @fragmentation FLOAT 475 | , @pageCount INT 476 | , @sqlCommand NVARCHAR(4000) 477 | , @rebuildCommand NVARCHAR(200) 478 | , @datetimestart DATETIME 479 | , @dateTimeEnd DATETIME 480 | , @containsLOB BIT 481 | , @editionCheck BIT 482 | , @debugMessage NVARCHAR(4000) 483 | , @updateSQL NVARCHAR(4000) 484 | , @partitionSQL NVARCHAR(4000) 485 | , @partitionSQL_Param NVARCHAR(1000) 486 | , @LOB_SQL NVARCHAR(4000) 487 | , @LOB_SQL_Param NVARCHAR(1000) 488 | , @indexDefrag_id INT 489 | , @startdatetime DATETIME 490 | , @enddatetime DATETIME 491 | , @getIndexSQL NVARCHAR(4000) 492 | , @getIndexSQL_Param NVARCHAR(4000) 493 | , @allowPageLockSQL NVARCHAR(4000) 494 | , @allowPageLockSQL_Param NVARCHAR(4000) 495 | , @allowPageLocks INT 496 | , @excludeMaxPartitionSQL NVARCHAR(4000); 497 | 498 | /* Initialize our variables */ 499 | SELECT @startdatetime = GETDATE() 500 | , @enddatetime = DATEADD(minute, @timeLimit, GETDATE()); 501 | 502 | /* Create our temporary tables */ 503 | CREATE TABLE #databaseList 504 | ( 505 | databaseID INT 506 | , databaseName VARCHAR(128) 507 | , scanStatus BIT 508 | ); 509 | 510 | CREATE TABLE #processor 511 | ( 512 | [index] INT 513 | , Name VARCHAR(128) 514 | , Internal_Value INT 515 | , Character_Value INT 516 | ); 517 | 518 | CREATE TABLE #maxPartitionList 519 | ( 520 | databaseID INT 521 | , objectID INT 522 | , indexID INT 523 | , maxPartition INT 524 | ); 525 | 526 | IF @debugMode = 1 RAISERROR('Beginning validation...', 0, 42) WITH NOWAIT; 527 | 528 | /* Make sure we're not exceeding the number of processors we have available */ 529 | INSERT INTO #processor 530 | EXECUTE xp_msver 'ProcessorCount'; 531 | 532 | IF @maxDopRestriction IS NOT NULL AND @maxDopRestriction > (SELECT Internal_Value FROM #processor) 533 | SELECT @maxDopRestriction = Internal_Value 534 | FROM #processor; 535 | 536 | /* Check our server version; 1804890536 = Enterprise, 610778273 = Enterprise Evaluation, -2117995310 = Developer */ 537 | IF (SELECT ServerProperty('EditionID')) IN (1804890536, 610778273, -2117995310) 538 | SET @editionCheck = 1 -- supports online rebuilds 539 | ELSE 540 | SET @editionCheck = 0; -- does not support online rebuilds 541 | 542 | /* Output the parameters we're working with */ 543 | IF @debugMode = 1 544 | BEGIN 545 | 546 | SELECT @debugMessage = 'Your SELECTed parameters are... 547 | Defrag indexes WITH fragmentation greater than ' + CAST(@minFragmentation AS VARCHAR(10)) + '; 548 | REBUILD indexes WITH fragmentation greater than ' + CAST(@rebuildThreshold AS VARCHAR(10)) + '; 549 | You' + CASE WHEN @executeSQL = 1 THEN ' DO' ELSE ' DO NOT' END + ' want the commands to be executed automatically; 550 | You want to defrag indexes in ' + @defragSortOrder + ' order of the ' + UPPER(@defragOrderColumn) + ' value; 551 | You have' + CASE WHEN @timeLimit IS NULL THEN ' NOT specified a time limit;' ELSE ' specified a time limit of ' 552 | + CAST(@timeLimit AS VARCHAR(10)) END + ' minutes; 553 | ' + CASE WHEN @database IS NULL THEN 'ALL databases' ELSE 'The ' + @database + ' database(s)' END + ' will be defragged; 554 | ' + CASE WHEN @tableName IS NULL THEN 'ALL tables' ELSE 'The ' + @tableName + ' TABLE' END + ' will be defragged; 555 | We' + CASE WHEN EXISTS(SELECT Top 1 * FROM dbo.dba_indexDefragStatus WHERE defragDate IS NULL) 556 | AND @forceRescan <> 1 THEN ' WILL NOT' ELSE ' WILL' END + ' be rescanning indexes; 557 | The scan will be performed in ' + @scanMode + ' mode; 558 | You want to limit defrags to indexes with' + CASE WHEN @maxPageCount IS NULL THEN ' more than ' 559 | + CAST(@minPageCount AS VARCHAR(10)) ELSE 560 | ' BETWEEN ' + CAST(@minPageCount AS VARCHAR(10)) 561 | + ' AND ' + CAST(@maxPageCount AS VARCHAR(10)) END + ' pages; 562 | Indexes will be defragged' + CASE WHEN @editionCheck = 0 OR @onlineRebuild = 0 THEN ' OFFLINE;' ELSE ' ONLINE;' END + ' 563 | Indexes will be sorted in' + CASE WHEN @sortInTempDB = 0 THEN ' the DATABASE' ELSE ' TEMPDB;' END + ' 564 | Defrag operations will utilize ' + CASE WHEN @editionCheck = 0 OR @maxDopRestriction IS NULL 565 | THEN 'system defaults for processors;' 566 | ELSE CAST(@maxDopRestriction AS VARCHAR(2)) + ' processors;' END + ' 567 | You' + CASE WHEN @printCommands = 1 THEN ' DO' ELSE ' DO NOT' END + ' want to PRINT the ALTER INDEX commands; 568 | You' + CASE WHEN @printFragmentation = 1 THEN ' DO' ELSE ' DO NOT' END + ' want to OUTPUT fragmentation levels; 569 | You want to wait ' + @defragDelay + ' (hh:mm:ss) BETWEEN defragging indexes; 570 | You want to run in' + CASE WHEN @debugMode = 1 THEN ' DEBUG' ELSE ' SILENT' END + ' mode.'; 571 | 572 | RAISERROR(@debugMessage, 0, 42) WITH NOWAIT; 573 | 574 | END; 575 | 576 | IF @debugMode = 1 RAISERROR('Grabbing a list of our databases...', 0, 42) WITH NOWAIT; 577 | 578 | /* Retrieve the list of databases to investigate */ 579 | /* If @database is NULL, it means we want to defrag *all* databases */ 580 | IF @database IS NULL 581 | BEGIN 582 | 583 | INSERT INTO #databaseList 584 | SELECT database_id 585 | , name 586 | , 0 -- not scanned yet for fragmentation 587 | FROM sys.databases 588 | WHERE [name] NOT IN ('master', 'tempdb')-- exclude system databases 589 | AND [state] = 0 -- state must be ONLINE 590 | AND is_read_only = 0; -- cannot be read_only 591 | 592 | END; 593 | ELSE 594 | /* Otherwise, we're going to just defrag our list of databases */ 595 | BEGIN 596 | 597 | INSERT INTO #databaseList 598 | SELECT database_id 599 | , name 600 | , 0 -- not scanned yet for fragmentation 601 | FROM sys.databases AS d 602 | JOIN dbo.dba_parseString_udf(@database, ',') AS x 603 | ON d.name COLLATE database_default = x.stringValue 604 | WHERE [name] NOT IN ('master', 'tempdb')-- exclude system databases 605 | AND [state] = 0 -- state must be ONLINE 606 | AND is_read_only = 0; -- cannot be read_only 607 | 608 | END; 609 | 610 | /* Check to see IF we have indexes in need of defrag; otherwise, re-scan the database(s) */ 611 | IF NOT EXISTS(SELECT Top 1 * FROM dbo.dba_indexDefragStatus WHERE defragDate IS NULL) 612 | OR @forceRescan = 1 613 | BEGIN 614 | 615 | /* Truncate our list of indexes to prepare for a new scan */ 616 | TRUNCATE TABLE dbo.dba_indexDefragStatus; 617 | 618 | IF @debugMode = 1 RAISERROR('Looping through our list of databases and checking for fragmentation...', 0, 42) WITH NOWAIT; 619 | 620 | /* Loop through our list of databases */ 621 | WHILE (SELECT COUNT(*) FROM #databaseList WHERE scanStatus = 0) > 0 622 | BEGIN 623 | 624 | SELECT Top 1 @databaseID = databaseID 625 | FROM #databaseList 626 | WHERE scanStatus = 0; 627 | 628 | SELECT @debugMessage = ' working on ' + DB_NAME(@databaseID) + '...'; 629 | 630 | IF @debugMode = 1 631 | RAISERROR(@debugMessage, 0, 42) WITH NOWAIT; 632 | 633 | /* Determine which indexes to defrag using our user-defined parameters */ 634 | INSERT INTO dbo.dba_indexDefragStatus 635 | ( 636 | databaseID 637 | , databaseName 638 | , objectID 639 | , indexID 640 | , partitionNumber 641 | , fragmentation 642 | , page_count 643 | , range_scan_count 644 | , scanDate 645 | ) 646 | SELECT 647 | ps.database_id AS 'databaseID' 648 | , QUOTENAME(DB_NAME(ps.database_id)) AS 'databaseName' 649 | , ps.[object_id] AS 'objectID' 650 | , ps.index_id AS 'indexID' 651 | , ps.partition_number AS 'partitionNumber' 652 | , SUM(ps.avg_fragmentation_in_percent) AS 'fragmentation' 653 | , SUM(ps.page_count) AS 'page_count' 654 | , os.range_scan_count 655 | , GETDATE() AS 'scanDate' 656 | FROM sys.dm_db_index_physical_stats(@databaseID, OBJECT_ID(@tableName), NULL , NULL, @scanMode) AS ps 657 | JOIN sys.dm_db_index_operational_stats(@databaseID, OBJECT_ID(@tableName), NULL , NULL) AS os 658 | ON ps.database_id = os.database_id 659 | AND ps.[object_id] = os.[object_id] 660 | AND ps.index_id = os.index_id 661 | AND ps.partition_number = os.partition_number 662 | WHERE avg_fragmentation_in_percent >= @minFragmentation 663 | AND ps.index_id > 0 -- ignore heaps 664 | AND ps.page_count > @minPageCount 665 | AND ps.index_level = 0 -- leaf-level nodes only, supports @scanMode 666 | GROUP BY ps.database_id 667 | , QUOTENAME(DB_NAME(ps.database_id)) 668 | , ps.[object_id] 669 | , ps.index_id 670 | , ps.partition_number 671 | , os.range_scan_count 672 | OPTION (MAXDOP 2); 673 | 674 | /* Do we want to exclude right-most populated partition of our partitioned indexes? */ 675 | IF @excludeMaxPartition = 1 676 | BEGIN 677 | 678 | SET @excludeMaxPartitionSQL = ' 679 | SELECT ' + CAST(@databaseID AS VARCHAR(10)) + ' AS [databaseID] 680 | , [object_id] 681 | , index_id 682 | , MAX(partition_number) AS [maxPartition] 683 | FROM [' + DB_NAME(@databaseID) + '].sys.partitions 684 | WHERE partition_number > 1 685 | AND [rows] > 0 686 | GROUP BY object_id 687 | , index_id;'; 688 | 689 | INSERT INTO #maxPartitionList 690 | EXECUTE sp_executesql @excludeMaxPartitionSQL; 691 | 692 | END; 693 | 694 | /* Keep track of which databases have already been scanned */ 695 | UPDATE #databaseList 696 | SET scanStatus = 1 697 | WHERE databaseID = @databaseID; 698 | 699 | END 700 | 701 | /* We don't want to defrag the right-most populated partition, so 702 | delete any records for partitioned indexes where partition = MAX(partition) */ 703 | IF @excludeMaxPartition = 1 704 | BEGIN 705 | 706 | DELETE ids 707 | FROM dbo.dba_indexDefragStatus AS ids 708 | JOIN #maxPartitionList AS mpl 709 | ON ids.databaseID = mpl.databaseID 710 | AND ids.objectID = mpl.objectID 711 | AND ids.indexID = mpl.indexID 712 | AND ids.partitionNumber = mpl.maxPartition; 713 | 714 | END; 715 | 716 | /* Update our exclusion mask for any index that has a restriction ON the days it can be defragged */ 717 | UPDATE ids 718 | SET ids.exclusionMask = ide.exclusionMask 719 | FROM dbo.dba_indexDefragStatus AS ids 720 | JOIN dbo.dba_indexDefragExclusion AS ide 721 | ON ids.databaseID = ide.databaseID 722 | AND ids.objectID = ide.objectID 723 | AND ids.indexID = ide.indexID; 724 | 725 | END 726 | 727 | SELECT @debugMessage = 'Looping through our list... there are ' + CAST(COUNT(*) AS VARCHAR(10)) + ' indexes to defrag!' 728 | FROM dbo.dba_indexDefragStatus 729 | WHERE defragDate IS NULL 730 | AND page_count BETWEEN @minPageCount AND ISNULL(@maxPageCount, page_count); 731 | 732 | IF @debugMode = 1 RAISERROR(@debugMessage, 0, 42) WITH NOWAIT; 733 | 734 | /* Begin our loop for defragging */ 735 | WHILE (SELECT COUNT(*) 736 | FROM dbo.dba_indexDefragStatus 737 | WHERE ( 738 | (@executeSQL = 1 AND defragDate IS NULL) 739 | OR (@executeSQL = 0 AND defragDate IS NULL AND printStatus = 0) 740 | ) 741 | AND exclusionMask & POWER(2, DATEPART(weekday, GETDATE())-1) = 0 742 | AND page_count BETWEEN @minPageCount AND ISNULL(@maxPageCount, page_count)) > 0 743 | BEGIN 744 | 745 | /* Check to see IF we need to exit our loop because of our time limit */ 746 | IF ISNULL(@enddatetime, GETDATE()) < GETDATE() 747 | BEGIN 748 | RAISERROR('Our time limit has been exceeded!', 11, 42) WITH NOWAIT; 749 | END; 750 | 751 | IF @debugMode = 1 RAISERROR(' Picking an index to beat into shape...', 0, 42) WITH NOWAIT; 752 | 753 | /* Grab the index with the highest priority, based on the values submitted; 754 | Look at the exclusion mask to ensure it can be defragged today */ 755 | SET @getIndexSQL = N' 756 | SELECT TOP 1 757 | @objectID_Out = objectID 758 | , @indexID_Out = indexID 759 | , @databaseID_Out = databaseID 760 | , @databaseName_Out = databaseName 761 | , @fragmentation_Out = fragmentation 762 | , @partitionNumber_Out = partitionNumber 763 | , @pageCount_Out = page_count 764 | FROM dbo.dba_indexDefragStatus 765 | WHERE defragDate IS NULL ' 766 | + CASE WHEN @executeSQL = 0 THEN 'AND printStatus = 0' ELSE '' END + ' 767 | AND exclusionMask & Power(2, DatePart(weekday, GETDATE())-1) = 0 768 | AND page_count BETWEEN @p_minPageCount AND ISNULL(@p_maxPageCount, page_count) 769 | ORDER BY + ' + @defragOrderColumn + ' ' + @defragSortOrder; 770 | 771 | SET @getIndexSQL_Param = N'@objectID_Out INT OUTPUT 772 | , @indexID_Out INT OUTPUT 773 | , @databaseID_Out INT OUTPUT 774 | , @databaseName_Out NVARCHAR(128) OUTPUT 775 | , @fragmentation_Out INT OUTPUT 776 | , @partitionNumber_Out INT OUTPUT 777 | , @pageCount_Out INT OUTPUT 778 | , @p_minPageCount INT 779 | , @p_maxPageCount INT'; 780 | 781 | EXECUTE sp_executesql @getIndexSQL 782 | , @getIndexSQL_Param 783 | , @p_minPageCount = @minPageCount 784 | , @p_maxPageCount = @maxPageCount 785 | , @objectID_Out = @objectID OUTPUT 786 | , @indexID_Out = @indexID OUTPUT 787 | , @databaseID_Out = @databaseID OUTPUT 788 | , @databaseName_Out = @databaseName OUTPUT 789 | , @fragmentation_Out = @fragmentation OUTPUT 790 | , @partitionNumber_Out = @partitionNumber OUTPUT 791 | , @pageCount_Out = @pageCount OUTPUT; 792 | 793 | IF @debugMode = 1 RAISERROR(' Looking up the specifics for our index...', 0, 42) WITH NOWAIT; 794 | 795 | /* Look up index information */ 796 | SELECT @updateSQL = N'UPDATE ids 797 | SET schemaName = QUOTENAME(s.name) 798 | , objectName = QUOTENAME(o.name) 799 | , indexName = QUOTENAME(i.name) 800 | FROM dbo.dba_indexDefragStatus AS ids 801 | INNER JOIN ' + @databaseName + '.sys.objects AS o 802 | ON ids.objectID = o.[object_id] 803 | INNER JOIN ' + @databaseName + '.sys.indexes AS i 804 | ON o.[object_id] = i.[object_id] 805 | AND ids.indexID = i.index_id 806 | INNER JOIN ' + @databaseName + '.sys.schemas AS s 807 | ON o.schema_id = s.schema_id 808 | WHERE o.[object_id] = ' + CAST(@objectID AS VARCHAR(10)) + ' 809 | AND i.index_id = ' + CAST(@indexID AS VARCHAR(10)) + ' 810 | AND i.type > 0 811 | AND ids.databaseID = ' + CAST(@databaseID AS VARCHAR(10)); 812 | 813 | EXECUTE sp_executesql @updateSQL; 814 | 815 | /* Grab our object names */ 816 | SELECT @objectName = objectName 817 | , @schemaName = schemaName 818 | , @indexName = indexName 819 | FROM dbo.dba_indexDefragStatus 820 | WHERE objectID = @objectID 821 | AND indexID = @indexID 822 | AND databaseID = @databaseID; 823 | 824 | IF @debugMode = 1 RAISERROR(' Grabbing the partition COUNT...', 0, 42) WITH NOWAIT; 825 | 826 | /* Determine if the index is partitioned */ 827 | SELECT @partitionSQL = 'SELECT @partitionCount_OUT = COUNT(*) 828 | FROM ' + @databaseName + '.sys.partitions 829 | WHERE object_id = ' + CAST(@objectID AS VARCHAR(10)) + ' 830 | AND index_id = ' + CAST(@indexID AS VARCHAR(10)) + ';' 831 | , @partitionSQL_Param = '@partitionCount_OUT INT OUTPUT'; 832 | 833 | EXECUTE sp_executesql @partitionSQL, @partitionSQL_Param, @partitionCount_OUT = @partitionCount OUTPUT; 834 | 835 | IF @debugMode = 1 RAISERROR(' Seeing IF there are any LOBs to be handled...', 0, 42) WITH NOWAIT; 836 | 837 | /* Determine if the table contains LOBs */ 838 | SELECT @LOB_SQL = ' SELECT @containsLOB_OUT = COUNT(*) 839 | FROM ' + @databaseName + '.sys.columns WITH (NoLock) 840 | WHERE [object_id] = ' + CAST(@objectID AS VARCHAR(10)) + ' 841 | AND (system_type_id IN (34, 35, 99) 842 | OR max_length = -1);' 843 | /* system_type_id --> 34 = IMAGE, 35 = TEXT, 99 = NTEXT 844 | max_length = -1 --> VARBINARY(MAX), VARCHAR(MAX), NVARCHAR(MAX), XML */ 845 | , @LOB_SQL_Param = '@containsLOB_OUT INT OUTPUT'; 846 | 847 | EXECUTE sp_executesql @LOB_SQL, @LOB_SQL_Param, @containsLOB_OUT = @containsLOB OUTPUT; 848 | 849 | IF @debugMode = 1 RAISERROR(' Checking for indexes that do NOT allow page locks...', 0, 42) WITH NOWAIT; 850 | 851 | /* Determine if page locks are allowed; for those indexes, we need to always REBUILD */ 852 | SELECT @allowPageLockSQL = 'SELECT @allowPageLocks_OUT = COUNT(*) 853 | FROM ' + @databaseName + '.sys.indexes 854 | WHERE object_id = ' + CAST(@objectID AS VARCHAR(10)) + ' 855 | AND index_id = ' + CAST(@indexID AS VARCHAR(10)) + ' 856 | AND Allow_Page_Locks = 0;' 857 | , @allowPageLockSQL_Param = '@allowPageLocks_OUT INT OUTPUT'; 858 | 859 | EXECUTE sp_executesql @allowPageLockSQL, @allowPageLockSQL_Param, @allowPageLocks_OUT = @allowPageLocks OUTPUT; 860 | 861 | IF @debugMode = 1 RAISERROR(' Building our SQL statements...', 0, 42) WITH NOWAIT; 862 | 863 | /* IF there's not a lot of fragmentation, or if we have a LOB, we should REORGANIZE */ 864 | IF (@fragmentation < @rebuildThreshold OR @containsLOB >= 1 OR @partitionCount > 1) 865 | AND @allowPageLocks = 0 866 | BEGIN 867 | 868 | SET @sqlCommand = N'ALTER INDEX ' + @indexName + N' ON ' + @databaseName + N'.' 869 | + @schemaName + N'.' + @objectName + N' REORGANIZE'; 870 | 871 | /* If our index is partitioned, we should always REORGANIZE */ 872 | IF @partitionCount > 1 873 | SET @sqlCommand = @sqlCommand + N' PARTITION = ' 874 | + CAST(@partitionNumber AS NVARCHAR(10)); 875 | 876 | END 877 | /* If the index is heavily fragmented and doesn't contain any partitions or LOB's, 878 | or if the index does not allow page locks, REBUILD it */ 879 | ELSE IF (@fragmentation >= @rebuildThreshold OR @allowPageLocks <> 0) 880 | AND ISNULL(@containsLOB, 0) != 1 AND @partitionCount <= 1 881 | BEGIN 882 | 883 | /* Set online REBUILD options; requires Enterprise Edition */ 884 | IF @onlineRebuild = 1 AND @editionCheck = 1 885 | SET @rebuildCommand = N' REBUILD WITH (ONLINE = ON'; 886 | ELSE 887 | SET @rebuildCommand = N' REBUILD WITH (ONLINE = Off'; 888 | 889 | /* Set sort operation preferences */ 890 | IF @sortInTempDB = 1 891 | SET @rebuildCommand = @rebuildCommand + N', SORT_IN_TEMPDB = ON'; 892 | ELSE 893 | SET @rebuildCommand = @rebuildCommand + N', SORT_IN_TEMPDB = Off'; 894 | 895 | /* Set processor restriction options; requires Enterprise Edition */ 896 | IF @maxDopRestriction IS NOT NULL AND @editionCheck = 1 897 | SET @rebuildCommand = @rebuildCommand + N', MAXDOP = ' + CAST(@maxDopRestriction AS VARCHAR(2)) + N')'; 898 | ELSE 899 | SET @rebuildCommand = @rebuildCommand + N')'; 900 | 901 | SET @sqlCommand = N'ALTER INDEX ' + @indexName + N' ON ' + @databaseName + N'.' 902 | + @schemaName + N'.' + @objectName + @rebuildCommand; 903 | 904 | END 905 | ELSE 906 | /* Print an error message if any indexes happen to not meet the criteria above */ 907 | IF @printCommands = 1 OR @debugMode = 1 908 | RAISERROR('We are unable to defrag this index.', 0, 42) WITH NOWAIT; 909 | 910 | /* Are we executing the SQL? IF so, do it */ 911 | IF @executeSQL = 1 912 | BEGIN 913 | 914 | SET @debugMessage = 'Executing: ' + @sqlCommand; 915 | 916 | /* Print the commands we're executing if specified to do so */ 917 | IF @printCommands = 1 OR @debugMode = 1 918 | RAISERROR(@debugMessage, 0, 42) WITH NOWAIT; 919 | 920 | /* Grab the time for logging purposes */ 921 | SET @datetimestart = GETDATE(); 922 | 923 | /* Log our actions */ 924 | INSERT INTO dbo.dba_indexDefragLog 925 | ( 926 | databaseID 927 | , databaseName 928 | , objectID 929 | , objectName 930 | , indexID 931 | , indexName 932 | , partitionNumber 933 | , fragmentation 934 | , page_count 935 | , dateTimeStart 936 | , sqlStatement 937 | ) 938 | SELECT 939 | @databaseID 940 | , @databaseName 941 | , @objectID 942 | , @objectName 943 | , @indexID 944 | , @indexName 945 | , @partitionNumber 946 | , @fragmentation 947 | , @pageCount 948 | , @datetimestart 949 | , @sqlCommand; 950 | 951 | SET @indexDefrag_id = SCOPE_IDENTITY(); 952 | 953 | /* Wrap our execution attempt in a TRY/CATCH and log any errors that occur */ 954 | BEGIN TRY 955 | 956 | /* Execute our defrag! */ 957 | EXECUTE sp_executesql @sqlCommand; 958 | SET @dateTimeEnd = GETDATE(); 959 | 960 | /* Update our log with our completion time */ 961 | UPDATE dbo.dba_indexDefragLog 962 | SET dateTimeEnd = @dateTimeEnd 963 | , durationSeconds = DATEDIFF(second, @datetimestart, @dateTimeEnd) 964 | WHERE indexDefrag_id = @indexDefrag_id; 965 | 966 | END TRY 967 | BEGIN CATCH 968 | 969 | /* Update our log with our error message */ 970 | UPDATE dbo.dba_indexDefragLog 971 | SET dateTimeEnd = GETDATE() 972 | , durationSeconds = -1 973 | , errorMessage = ERROR_MESSAGE() 974 | WHERE indexDefrag_id = @indexDefrag_id; 975 | 976 | IF @debugMode = 1 977 | RAISERROR(' An error has occurred executing this command! Please review the dba_indexDefragLog table for details.' 978 | , 0, 42) WITH NOWAIT; 979 | 980 | END CATCH 981 | 982 | /* Just a little breather for the server */ 983 | WAITFOR DELAY @defragDelay; 984 | 985 | UPDATE dbo.dba_indexDefragStatus 986 | SET defragDate = GETDATE() 987 | , printStatus = 1 988 | WHERE databaseID = @databaseID 989 | AND objectID = @objectID 990 | AND indexID = @indexID 991 | AND partitionNumber = @partitionNumber; 992 | 993 | END 994 | ELSE 995 | /* Looks like we're not executing, just printing the commands */ 996 | BEGIN 997 | IF @debugMode = 1 RAISERROR(' Printing SQL statements...', 0, 42) WITH NOWAIT; 998 | 999 | IF @printCommands = 1 OR @debugMode = 1 1000 | PRINT ISNULL(@sqlCommand, 'error!'); 1001 | 1002 | UPDATE dbo.dba_indexDefragStatus 1003 | SET printStatus = 1 1004 | WHERE databaseID = @databaseID 1005 | AND objectID = @objectID 1006 | AND indexID = @indexID 1007 | AND partitionNumber = @partitionNumber; 1008 | END 1009 | 1010 | END 1011 | 1012 | /* Do we want to output our fragmentation results? */ 1013 | IF @printFragmentation = 1 1014 | BEGIN 1015 | 1016 | IF @debugMode = 1 RAISERROR(' Displaying a summary of our action...', 0, 42) WITH NOWAIT; 1017 | 1018 | SELECT databaseID 1019 | , databaseName 1020 | , objectID 1021 | , objectName 1022 | , indexID 1023 | , indexName 1024 | , partitionNumber 1025 | , fragmentation 1026 | , page_count 1027 | , range_scan_count 1028 | FROM dbo.dba_indexDefragStatus 1029 | WHERE defragDate >= @startdatetime 1030 | ORDER BY defragDate; 1031 | 1032 | END; 1033 | 1034 | END TRY 1035 | BEGIN CATCH 1036 | 1037 | SET @debugMessage = ERROR_MESSAGE() + ' (Line Number: ' + CAST(ERROR_LINE() AS VARCHAR(10)) + ')'; 1038 | PRINT @debugMessage; 1039 | 1040 | END CATCH; 1041 | 1042 | /* When everything is said and done, make sure to get rid of our temp table */ 1043 | DROP TABLE #databaseList; 1044 | DROP TABLE #processor; 1045 | DROP TABLE #maxPartitionList; 1046 | 1047 | IF @debugMode = 1 RAISERROR('DONE! Thank you for taking care of your indexes! :)', 0, 42) WITH NOWAIT; 1048 | 1049 | SET NOCOUNT OFF; 1050 | RETURN 0; 1051 | END 1052 | -------------------------------------------------------------------------------- /indexes/dba_indexLookup_sp.sql: -------------------------------------------------------------------------------- 1 | If ObjectProperty(Object_ID('dbo.dba_indexLookup_sp'), N'IsProcedure') Is Null 2 | Begin 3 | Execute ('Create Procedure dbo.dba_indexLookup_sp As Print ''Hello World!''') 4 | RaisError('Procedure dbo.dba_indexLookup_sp created.', 10, 1); 5 | End; 6 | Go 7 | 8 | Set ANSI_Nulls On; 9 | Set Ansi_Padding On; 10 | Set Ansi_Warnings On; 11 | Set ArithAbort On; 12 | Set Concat_Null_Yields_Null On; 13 | Set NoCount On; 14 | Set Numeric_RoundAbort Off; 15 | Set Quoted_Identifier On; 16 | Go 17 | 18 | Alter Procedure dbo.dba_indexLookup_sp 19 | 20 | /* Declare Parameters */ 21 | @tableName varchar(128) = Null 22 | As 23 | /********************************************************************************************************** 24 | 25 | NAME: dba_indexLookup_sp 26 | 27 | SYNOPSIS: Retrieves index information for the specified table name. 28 | 29 | DEPENDENCIES: The following dependencies are required to execute this script: 30 | - SQL Server 2005 or newer 31 | 32 | NOTES: If the tableName is left null, it will return index information 33 | for all tables and indexes. 34 | 35 | AUTHOR: Michelle Ufford, http://sqlfool.com 36 | 37 | CREATED: 2008-10-28 38 | 39 | VERSION: 1.0 40 | 41 | LICENSE: Apache License v2 42 | 43 | ---------------------------------------------------------------------------- 44 | DISCLAIMER: 45 | This code and information are provided "AS IS" without warranty of any kind, 46 | either expressed or implied, including but not limited to the implied 47 | warranties or merchantability and/or fitness for a particular purpose. 48 | ---------------------------------------------------------------------------- 49 | 50 | --------------------------------------------------------------------------------------------------------- 51 | -- DATE VERSION AUTHOR DESCRIPTION -- 52 | --------------------------------------------------------------------------------------------------------- 53 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 54 | **********************************************************************************************************/ 55 | 56 | Set NoCount On; 57 | Set XACT_Abort On; 58 | 59 | Begin 60 | 61 | Declare @objectID int; 62 | 63 | If @tableName Is Not Null 64 | Set @objectID = Object_ID(@tableName); 65 | 66 | With indexCTE(partition_scheme_name 67 | , partition_function_name 68 | , data_space_id) 69 | As ( 70 | Select sps.name 71 | , spf.name 72 | , sps.data_space_id 73 | From sys.partition_schemes As sps 74 | Join sys.partition_functions As spf 75 | On sps.function_id = spf.function_id 76 | ) 77 | 78 | Select st.name As 'table_name' 79 | , IsNull(ix.name, '') As 'index_name' 80 | , ix.object_id 81 | , ix.index_id 82 | , Cast( 83 | Case When ix.index_id = 1 84 | Then 'clustered' 85 | When ix.index_id =0 86 | Then 'heap' 87 | Else 'nonclustered' End 88 | + Case When ix.ignore_dup_key <> 0 89 | Then ', ignore duplicate keys' 90 | Else '' End 91 | + Case When ix.is_unique <> 0 92 | Then ', unique' 93 | Else '' End 94 | + Case When ix.is_primary_key <> 0 95 | Then ', primary key' Else '' End As varchar(210) 96 | ) As 'index_description' 97 | , IsNull(Replace( Replace( Replace( 98 | ( 99 | Select c.name As 'columnName' 100 | From sys.index_columns As sic 101 | Join sys.columns As c 102 | On c.column_id = sic.column_id 103 | And c.object_id = sic.object_id 104 | Where sic.object_id = ix.object_id 105 | And sic.index_id = ix.index_id 106 | And is_included_column = 0 107 | Order By sic.index_column_id 108 | For XML Raw) 109 | , '"/>', ''), '') 112 | As 'indexed_columns' 113 | , IsNull(Replace( Replace( Replace( 114 | ( 115 | Select c.name As 'columnName' 116 | From sys.index_columns As sic 117 | Join sys.columns As c 118 | On c.column_id = sic.column_id 119 | And c.object_id = sic.object_id 120 | Where sic.object_id = ix.object_id 121 | And sic.index_id = ix.index_id 122 | And is_included_column = 1 123 | Order By sic.index_column_id 124 | For XML Raw) 125 | , '"/>', ''), '') 128 | As 'included_columns' 129 | , IsNull(cte.partition_scheme_name, '') As 'partition_scheme_name' 130 | , Count(partition_number) As 'partition_count' 131 | , Sum(rows) As 'row_count' 132 | From sys.indexes As ix 133 | Join sys.partitions As sp 134 | On ix.object_id = sp.object_id 135 | And ix.index_id = sp.index_id 136 | Join sys.tables As st 137 | On ix.object_id = st.object_id 138 | Left Join indexCTE As cte 139 | On ix.data_space_id = cte.data_space_id 140 | Where ix.object_id = IsNull(@objectID, ix.object_id) 141 | Group By st.name 142 | , IsNull(ix.name, '') 143 | , ix.object_id 144 | , ix.index_id 145 | , Cast( 146 | Case When ix.index_id = 1 147 | Then 'clustered' 148 | When ix.index_id =0 149 | Then 'heap' 150 | Else 'nonclustered' End 151 | + Case When ix.ignore_dup_key <> 0 152 | Then ', ignore duplicate keys' 153 | Else '' End 154 | + Case When ix.is_unique <> 0 155 | Then ', unique' 156 | Else '' End 157 | + Case When ix.is_primary_key <> 0 158 | Then ', primary key' Else '' End As varchar(210) 159 | ) 160 | , IsNull(cte.partition_scheme_name, '') 161 | , IsNull(cte.partition_function_name, '') 162 | Order By table_name 163 | , index_id; 164 | 165 | Set NoCount Off; 166 | Return 0; 167 | End 168 | Go 169 | 170 | Set Quoted_Identifier Off; 171 | Go 172 | -------------------------------------------------------------------------------- /indexes/dba_indexStats_sp.sql: -------------------------------------------------------------------------------- 1 | If ObjectProperty(Object_ID('dbo.dba_indexStats_sp'), N'IsProcedure') = 1 2 | Begin 3 | Drop Procedure dbo.dba_indexStats_sp; 4 | Print 'Procedure dba_indexStats_sp dropped'; 5 | End; 6 | Go 7 | 8 | Set Quoted_Identifier On 9 | Go 10 | Set ANSI_Nulls On 11 | Go 12 | 13 | Create Procedure dbo.dba_indexStats_sp 14 | 15 | /* Declare Parameters */ 16 | @databaseName varchar(256) = Null 17 | , @indexType varchar(256) = Null 18 | , @minRowCount int = Null 19 | , @maxRowCount int = Null 20 | , @minSeekScanLookup int = Null 21 | , @maxSeekScanLookup int = Null 22 | As 23 | /********************************************************************************************************** 24 | 25 | NAME: dba_indexStats_sp 26 | 27 | SYNOPSIS: Retrieves information regarding indexes; will return drop SQL 28 | statement for non-clustered indexes. 29 | 30 | DEPENDENCIES: The following dependencies are required to execute this script: 31 | - SQL Server 2005 or newer 32 | 33 | NOTES: @databaseName - optional, specify a specific database to interrogate; 34 | by default, all user databases will be returned 35 | 36 | @indexType - optional, valid options are: 37 | Clustered 38 | NonClustered 39 | Unique Clustered 40 | Unique NonClustered 41 | Heap 42 | 43 | @minRowCount - optional, specify a minimum number of rows an index 44 | must cover 45 | 46 | @maxRowCount - optional, specify a maximum number of rows an index 47 | must cover 48 | 49 | @minSeekScanLookup - optional, min sum aggregation of index scans, 50 | seeks, and look-ups. Useful for finding unused indexes 51 | 52 | @minSeekScanLookup - optional, max sum aggregation of index scans, 53 | seeks, and look-ups. Useful for finding unused indexes 54 | 55 | AUTHOR: Michelle Ufford, http://sqlfool.com 56 | 57 | CREATED: 2008-07-11 58 | 59 | VERSION: 1.0 60 | 61 | LICENSE: Apache License v2 62 | 63 | USAGE: EXEC dbo.dba_indexStats_sp 64 | @databaseName = 'your_db' 65 | , @indexType = 'NonClustered' 66 | , @minSeekScanLookup = 0 67 | , @maxSeekScanLookup = 1000 68 | , @minRowCount = 0 69 | , @maxRowCount = 10000000; 70 | 71 | ---------------------------------------------------------------------------- 72 | DISCLAIMER: 73 | This code and information are provided "AS IS" without warranty of any kind, 74 | either expressed or implied, including but not limited to the implied 75 | warranties or merchantability and/or fitness for a particular purpose. 76 | ---------------------------------------------------------------------------- 77 | 78 | --------------------------------------------------------------------------------------------------------- 79 | -- DATE VERSION AUTHOR DESCRIPTION -- 80 | --------------------------------------------------------------------------------------------------------- 81 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 82 | **********************************************************************************************************/ 83 | 84 | Set NoCount On; 85 | Set XACT_Abort On; 86 | 87 | Begin 88 | 89 | /* Declare Variables */ 90 | Create Table #indexStats 91 | ( 92 | databaseName varchar(256) 93 | , objectName varchar(256) 94 | , indexName varchar(256) 95 | , indexType varchar(256) 96 | , user_seeks int 97 | , user_scans int 98 | , user_lookups int 99 | , user_updates int 100 | , total_seekScanLookup int 101 | , rowCounts int 102 | , SQL_DropStatement varchar(2000) 103 | ); 104 | 105 | /* Check for existing transactions; 106 | If one exists, exit with error. */ 107 | If @@TranCount > 0 108 | Begin 109 | 110 | /* Log the fact that there were open transactions */ 111 | Execute dbo.dba_logError_sp @errorType = 'app' 112 | , @app_errorProcedure = 'dba_indexStats_sp' 113 | , @app_errorMessage = 'Open transaction exists; dba_indexStats_sp proc will not execute.'; 114 | Print 'Open transactions exist!'; 115 | 116 | End 117 | Else 118 | Begin 119 | Begin Try 120 | 121 | Execute sp_MSForEachDB 'Use [?] 122 | 123 | Declare @dbid int 124 | , @dbName varchar(100); 125 | 126 | Select @dbid = DB_ID() 127 | , @dbName = DB_Name(); 128 | 129 | With indexSizeCTE (object_id, index_id, rowCounts) As 130 | ( 131 | Select [object_id] 132 | , index_id 133 | , Sum([rows]) As ''rowCounts'' 134 | From sys.partitions 135 | Group By [object_id] 136 | , index_id 137 | ) 138 | 139 | Insert Into #indexStats 140 | Select 141 | @dbName 142 | , Object_Name(ix.[object_id]) as objectName 143 | , ix.name As ''indexName'' 144 | , Case 145 | When ix.is_unique = 1 146 | Then ''UNIQUE '' 147 | Else '''' 148 | End + ix.type_desc As ''indexType'' 149 | , ddius.user_seeks 150 | , ddius.user_scans 151 | , ddius.user_lookups 152 | , ddius.user_updates 153 | , ddius.user_seeks + ddius.user_scans + ddius.user_lookups 154 | , isc.rowCounts 155 | , Case 156 | When ix.type = 2 And ix.is_unique = 0 157 | Then ''Drop Index '' + ix.name + '' On '' + @dbName + ''.dbo.'' + Object_Name(ddius.[object_id]) + '';'' 158 | When ix.type = 2 And ix.is_unique = 1 159 | Then ''Alter Table '' + @dbName + ''.dbo.'' + Object_Name(ddius.[object_ID]) + '' Drop Constraint '' + ix.name + '';'' 160 | Else '' '' 161 | End As ''SQL_DropStatement'' 162 | From sys.indexes As ix 163 | Left Outer Join sys.dm_db_index_usage_stats ddius 164 | On ix.object_id = ddius.object_id 165 | And ix.index_id = ddius.index_id 166 | Left Outer Join indexSizeCTE As isc 167 | On ix.object_id = isc.object_id 168 | And ix.index_id = isc.index_id 169 | Where ddius.database_id = @dbid 170 | And ObjectProperty(ix.[object_id], N''IsUserTable'') = 1 171 | Order By (ddius.user_seeks + ddius.user_scans + ddius.user_lookups) Asc; 172 | ' 173 | 174 | Select databaseName 175 | , objectName 176 | , indexName 177 | , indexType 178 | , user_seeks 179 | , user_scans 180 | , user_lookups 181 | , total_seekScanLookup 182 | , user_updates 183 | , rowCounts 184 | , SQL_DropStatement 185 | From #indexStats 186 | Where databaseName = IsNull(@databaseName, databaseName) 187 | And indexType = IsNull(@indexType, indexType) 188 | And rowCounts Between IsNull(@minRowCount, rowCounts) And IsNull(@maxRowCount, rowCounts) 189 | And total_seekScanLookup Between IsNull(@minSeekScanLookup, total_seekScanLookup) And IsNull(@maxSeekScanLookup, total_seekScanLookup) 190 | And databaseName Not In ('master', 'msdb', 'tempdb', 'model') 191 | Order By total_seekScanLookup; 192 | 193 | End Try 194 | Begin Catch 195 | 196 | /* Return an error message and log it */ 197 | Execute dbo.dba_logError_sp; 198 | Print 'An error has occurred!'; 199 | 200 | End Catch; 201 | End; 202 | 203 | /* Clean up! */ 204 | Drop Table #indexStats; 205 | 206 | Set NoCount Off; 207 | Return 0; 208 | End 209 | Go 210 | 211 | Set Quoted_Identifier Off; 212 | Go 213 | Set ANSI_Nulls On; 214 | Go 215 | 216 | If ObjectProperty(Object_ID('dbo.dba_indexStats_sp'), N'IsProcedure') = 1 217 | RaisError('Procedure dba_indexStats_sp was successfully created.', 10, 1); 218 | Else 219 | RaisError('Procedure dba_indexStats_sp FAILED to create!', 16, 1); 220 | Go -------------------------------------------------------------------------------- /indexes/dba_missingIndexStoredProc_sp.sql: -------------------------------------------------------------------------------- 1 | Use dbaTools; 2 | Go 3 | 4 | /* Create a stored procedure skeleton */ 5 | If ObjectProperty(Object_ID('dbo.dba_missingIndexStoredProc_sp'), N'IsProcedure') Is Null 6 | Begin 7 | Execute ('Create Procedure dbo.dba_missingIndexStoredProc_sp As Print ''Hello World!''') 8 | RaisError('Procedure dba_missingIndexStoredProc_sp created.', 10, 1); 9 | End; 10 | Go 11 | 12 | /* Drop our table if it already exists */ 13 | If Exists(Select Object_ID From sys.tables Where [name] = N'dba_missingIndexStoredProc') 14 | Begin 15 | Drop Table dbo.dba_missingIndexStoredProc 16 | Print 'dba_missingIndexStoredProc table dropped!'; 17 | End 18 | 19 | /* Create our table */ 20 | Create Table dbo.dba_missingIndexStoredProc 21 | ( 22 | missingIndexSP_id int Identity(1,1) Not Null 23 | , databaseName varchar(128) Not Null 24 | , databaseID int Not Null 25 | , objectName varchar(128) Not Null 26 | , objectID int Not Null 27 | , query_plan xml Not Null 28 | , executionDate smalldatetime Not Null 29 | , statementExecutions int Not Null 30 | 31 | Constraint PK_missingIndexStoredProc 32 | Primary Key Clustered(missingIndexSP_id) 33 | ); 34 | 35 | Print 'dba_missingIndexStoredProc Table Created'; 36 | 37 | /* Configure our settings */ 38 | Set ANSI_Nulls On; 39 | Set Quoted_Identifier On; 40 | Go 41 | 42 | Alter Procedure dbo.dba_missingIndexStoredProc_sp 43 | 44 | /* Declare Parameters */ 45 | @lastExecuted_inDays int = 7 46 | , @minExecutionCount int = 1 47 | , @logResults bit = 1 48 | , @displayResults bit = 0 49 | 50 | As 51 | /********************************************************************************************************** 52 | 53 | NAME: dba_missingIndexStoredProc_sp 54 | 55 | SYNOPSIS: Retrieves stored procedures with missing indexes in their cached query plans. 56 | 57 | @lastExecuted_inDays = number of days old the cached query plan 58 | can be to still appear in the results; 59 | the HIGHER the number, the longer the 60 | execution time. 61 | 62 | @minExecutionCount = minimum number of executions the cached 63 | query plan can have to still appear 64 | in the results; the LOWER the number, 65 | the longer the execution time. 66 | 67 | @logResults = store results in dba_missingIndexStoredProc 68 | 69 | @displayResults = return results to the caller 70 | 71 | DEPENDENCIES: The following dependencies are required to execute this script: 72 | - SQL Server 2005 or newer 73 | 74 | NOTES: This is not 100% guaranteed to catch all missing indexes in 75 | a stored procedure. It will only catch it if the stored proc's 76 | query plan is still in cache. Run regularly to help minimize 77 | the chance of missing a proc. 78 | 79 | AUTHOR: Michelle Ufford, http://sqlfool.com 80 | 81 | CREATED: 2009-09-03 82 | 83 | VERSION: 1.0 84 | 85 | LICENSE: Apache License v2 86 | 87 | USAGE: Exec dbo.dba_missingIndexStoredProc_sp 88 | @lastExecuted_inDays = 30 89 | , @minExecutionCount = 5 90 | , @logResults = 1 91 | , @displayResults = 1; 92 | 93 | ---------------------------------------------------------------------------- 94 | DISCLAIMER: 95 | This code and information are provided "AS IS" without warranty of any kind, 96 | either expressed or implied, including but not limited to the implied 97 | warranties or merchantability and/or fitness for a particular purpose. 98 | ---------------------------------------------------------------------------- 99 | 100 | --------------------------------------------------------------------------------------------------------- 101 | -- DATE VERSION AUTHOR DESCRIPTION -- 102 | --------------------------------------------------------------------------------------------------------- 103 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 104 | **********************************************************************************************************/ 105 | 106 | Set NoCount On; 107 | Set XACT_Abort On; 108 | Set Ansi_Padding On; 109 | Set Ansi_Warnings On; 110 | Set ArithAbort On; 111 | Set Concat_Null_Yields_Null On; 112 | Set Numeric_RoundAbort Off; 113 | 114 | Begin 115 | 116 | /* Declare Variables */ 117 | Declare @currentDateTime smalldatetime; 118 | 119 | Set @currentDateTime = GetDate(); 120 | 121 | Declare @plan_handles Table 122 | ( 123 | plan_handle varbinary(64) Not Null 124 | , statementExecutions int Not Null 125 | ); 126 | 127 | Create Table #missingIndexes 128 | ( 129 | databaseID int Not Null 130 | , objectID int Not Null 131 | , query_plan xml Not Null 132 | , statementExecutions int Not Null 133 | ); 134 | 135 | Create Clustered Index CIX_temp_missingIndexes 136 | On #missingIndexes(databaseID, objectID); 137 | 138 | Begin Try 139 | 140 | /* Perform some data validation */ 141 | If @logResults = 0 And @displayResults = 0 142 | Begin 143 | 144 | /* Log the fact that there were open transactions */ 145 | Execute dbo.dba_logError_sp 146 | @errorType = 'app' 147 | , @app_errorProcedure = 'dba_missingIndexStoredProc_sp' 148 | , @app_errorMessage = '@logResults = 0 and @displayResults = 0; no action taken, exiting stored proc.' 149 | , @forceExit = 1 150 | , @returnError = 1; 151 | 152 | End; 153 | 154 | Begin Transaction; 155 | 156 | /* Retrieve distinct plan handles to minimize dm_exec_query_plan lookups */ 157 | Insert Into @plan_handles 158 | Select plan_handle, Sum(execution_count) As 'executions' 159 | From sys.dm_exec_query_stats 160 | Where last_execution_time > DateAdd(day, -@lastExecuted_inDays, @currentDateTime) 161 | Group By plan_handle 162 | Having Sum(execution_count) > @minExecutionCount; 163 | 164 | With xmlNameSpaces ( 165 | Default 'http://schemas.microsoft.com/sqlserver/2004/07/showplan' 166 | ) 167 | 168 | /* Retrieve our query plan's XML if there's a missing index */ 169 | Insert Into #missingIndexes 170 | Select deqp.[dbid] 171 | , deqp.objectid 172 | , deqp.query_plan 173 | , ph.statementExecutions 174 | From @plan_handles As ph 175 | Cross Apply sys.dm_exec_query_plan(ph.plan_handle) As deqp 176 | Where deqp.query_plan.exist('//MissingIndex/@Database') = 1 177 | And deqp.objectid Is Not Null; 178 | 179 | /* Do we want to store the results of our process? */ 180 | If @logResults = 1 181 | Begin 182 | Insert Into dbo.dba_missingIndexStoredProc 183 | Execute sp_msForEachDB 'Use ?; 184 | Select ''?'' 185 | , mi.databaseID 186 | , Object_Name(o.object_id) 187 | , o.object_id 188 | , mi.query_plan 189 | , GetDate() 190 | , mi.statementExecutions 191 | From sys.objects As o 192 | Join #missingIndexes As mi 193 | On o.object_id = mi.objectID 194 | Where databaseID = DB_ID();'; 195 | 196 | End 197 | /* We're not logging it, so let's display it */ 198 | Else 199 | Begin 200 | Execute sp_msForEachDB 'Use ?; 201 | Select ''?'' 202 | , mi.databaseID 203 | , Object_Name(o.object_id) 204 | , o.object_id 205 | , mi.query_plan 206 | , GetDate() 207 | , mi.statementExecutions 208 | From sys.objects As o 209 | Join #missingIndexes As mi 210 | On o.object_id = mi.objectID 211 | Where databaseID = DB_ID();'; 212 | End; 213 | 214 | /* See above; this part will only work if we've 215 | logged our data. */ 216 | If @displayResults = 1 And @logResults = 1 217 | Begin 218 | Select * 219 | From dbo.dba_missingIndexStoredProc 220 | Where executionDate >= @currentDateTime; 221 | End; 222 | 223 | /* If you have an open transaction, commit it */ 224 | If @@TranCount > 0 225 | Commit Transaction; 226 | 227 | End Try 228 | Begin Catch 229 | 230 | /* Whoops, there was an error... rollback! */ 231 | If @@TranCount > 0 232 | Rollback Transaction; 233 | 234 | /* Return an error message and log it */ 235 | Execute dbo.dba_logError_sp; 236 | 237 | End Catch; 238 | 239 | /* Clean-Up! */ 240 | Drop Table #missingIndexes; 241 | 242 | Set NoCount Off; 243 | Return 0; 244 | End 245 | Go 246 | 247 | Set Quoted_Identifier Off; 248 | Go -------------------------------------------------------------------------------- /indexes/index_definition.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: index_definition.sql 4 | 5 | SYNOPSIS: Displays the definition of indexes; useful to audit indexes across servers & environments 6 | 7 | DEPENDENCIES: The following dependencies are required to execute this script: 8 | - SQL Server 2005 or newer 9 | 10 | AUTHOR: Michelle Ufford, http://sqlfool.com 11 | 12 | CREATED: 2012-10-15 13 | 14 | VERSION: 1.0 15 | 16 | LICENSE: Apache License v2 17 | 18 | ---------------------------------------------------------------------------- 19 | DISCLAIMER: 20 | This code and information are provided "AS IS" without warranty of any kind, 21 | either expressed or implied, including but not limited to the implied 22 | warranties or merchantability and/or fitness for a particular purpose. 23 | ---------------------------------------------------------------------------- 24 | 25 | --------------------------------------------------------------------------------------------------------- 26 | -- DATE VERSION AUTHOR DESCRIPTION -- 27 | --------------------------------------------------------------------------------------------------------- 28 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 29 | **********************************************************************************************************/ 30 | 31 | -- Single database 32 | 33 | WITH indexCTE AS 34 | ( 35 | SELECT st.object_id AS objectID 36 | , st.name AS tableName 37 | , si.index_id AS indexID 38 | , si.name AS indexName 39 | , si.type_desc AS indexType 40 | , sc.column_id AS columnID 41 | , sc.name + CASE WHEN sic.is_descending_key = 1 THEN ' DESC' ELSE '' END AS columnName 42 | , sic.key_ordinal AS ordinalPosition 43 | , CASE WHEN sic.is_included_column = 0 AND key_ordinal > 0 THEN sc.name ELSE NULL END AS indexKeys 44 | , CASE WHEN sic.is_included_column = 1 THEN sc.name ELSE NULL END AS includedColumns 45 | , sic.partition_ordinal AS partitionOrdinal 46 | , CASE WHEN sic.partition_ordinal > 0 THEN sc.name ELSE NULL END AS partitionColumns 47 | , si.is_primary_key AS isPrimaryKey 48 | , si.is_unique AS isUnique 49 | , si.is_unique_constraint AS isUniqueConstraint 50 | , si.has_filter AS isFilteredIndex 51 | , COALESCE(si.filter_definition, '') AS filterDefinition 52 | FROM sys.tables AS st 53 | INNER JOIN sys.indexes AS si 54 | ON si.object_id = st.object_id 55 | INNER JOIN sys.index_columns AS sic 56 | ON sic.object_id=si.object_id 57 | AND sic.index_id=si.index_id 58 | INNER JOIN sys.columns AS sc 59 | ON sc.object_id = sic.object_id 60 | and sc.column_id = sic.column_id 61 | ) 62 | 63 | SELECT DISTINCT 64 | @@SERVERNAME AS ServerName 65 | , DB_NAME() AS DatabaseName 66 | , tableName 67 | , indexName 68 | , indexType 69 | , STUFF(( 70 | SELECT ', ' + indexKeys 71 | FROM indexCTE 72 | WHERE objectID = cte.objectID 73 | AND indexID = cte.indexID 74 | AND indexKeys IS NOT NULL 75 | ORDER BY ordinalPosition 76 | FOR XML PATH(''), 77 | TYPE).value('.','varchar(max)'),1,1,'') AS indexKeys 78 | , COALESCE(STUFF(( 79 | SELECT ', ' + includedColumns 80 | FROM indexCTE 81 | WHERE objectID = cte.objectID 82 | AND indexID = cte.indexID 83 | AND includedColumns IS NOT NULL 84 | ORDER BY columnID 85 | FOR XML PATH(''), 86 | TYPE).value('.','varchar(max)'),1,1,''), '') AS includedColumns 87 | , COALESCE(STUFF(( 88 | SELECT ', ' + partitionColumns 89 | FROM indexCTE 90 | WHERE objectID = cte.objectID 91 | AND indexID = cte.indexID 92 | AND partitionColumns IS NOT NULL 93 | ORDER BY partitionOrdinal 94 | FOR XML PATH(''), 95 | TYPE).value('.','varchar(max)'),1,1,''), '') AS partitionKeys 96 | , isPrimaryKey 97 | , isUnique 98 | , isUniqueConstraint 99 | , isFilteredIndex 100 | , FilterDefinition 101 | FROM indexCTE AS cte 102 | WHERE tableName = 'your_example' 103 | ORDER BY tableName 104 | , indexName; 105 | 106 | /*********************************************************************************************************/ 107 | 108 | -- All databases 109 | IF OBJECT_ID('tempdb..#IndexAudit') IS NOT NULL 110 | DROP TABLE #IndexAudit; 111 | 112 | CREATE TABLE #IndexAudit 113 | ( 114 | serverName SYSNAME 115 | , databaseName SYSNAME 116 | , tableName VARCHAR(128) 117 | , indexName VARCHAR(128) 118 | , indexType NVARCHAR(60) 119 | , indexKeys VARCHAR(8000) 120 | , includedColumns VARCHAR(8000) 121 | , partitionColumns VARCHAR(8000) 122 | , isPrimaryKey BIT 123 | , isUnique BIT 124 | , isUniqueConstraint BIT 125 | , isFilteredIndex BIT 126 | , FilterDefinition VARCHAR(8000) 127 | ); 128 | 129 | EXECUTE sp_foreachdb 'USE ?; 130 | WITH indexCTE AS 131 | ( 132 | SELECT st.object_id AS objectID 133 | , st.name AS tableName 134 | , si.index_id AS indexID 135 | , si.type_desc AS indexType 136 | , si.name AS indexName 137 | , sc.column_id AS columnID 138 | , sc.name + CASE WHEN sic.is_descending_key = 1 THEN '' DESC'' ELSE '''' END AS columnName 139 | , sic.key_ordinal AS ordinalPosition 140 | , CASE WHEN sic.is_included_column = 0 AND key_ordinal > 0 THEN sc.name ELSE NULL END AS indexKeys 141 | , CASE WHEN sic.is_included_column = 1 THEN sc.name ELSE NULL END AS includedColumns 142 | , sic.partition_ordinal AS partitionOrdinal 143 | , CASE WHEN sic.partition_ordinal > 0 THEN sc.name ELSE NULL END AS partitionColumns 144 | , si.is_primary_key AS isPrimaryKey 145 | , si.is_unique AS isUnique 146 | , si.is_unique_constraint AS isUniqueConstraint 147 | , si.has_filter AS isFilteredIndex 148 | , COALESCE(si.filter_definition, '''') AS filterDefinition 149 | FROM sys.tables AS st 150 | INNER JOIN sys.indexes AS si 151 | ON si.object_id = st.object_id 152 | INNER JOIN sys.index_columns AS sic 153 | ON sic.object_id=si.object_id 154 | AND sic.index_id=si.index_id 155 | INNER JOIN sys.columns AS sc 156 | ON sc.object_id = sic.object_id 157 | and sc.column_id = sic.column_id 158 | ) 159 | 160 | INSERT INTO #IndexAudit 161 | SELECT DISTINCT 162 | @@SERVERNAME AS ServerName 163 | , DB_NAME() AS DatabaseName 164 | , tableName 165 | , indexName 166 | , indexType 167 | , STUFF(( 168 | SELECT '', '' + indexKeys 169 | FROM indexCTE 170 | WHERE objectID = cte.objectID 171 | AND indexID = cte.indexID 172 | AND indexKeys IS NOT NULL 173 | ORDER BY ordinalPosition 174 | FOR XML PATH(''''), 175 | TYPE).value(''.'',''varchar(max)''),1,1,'''') AS indexKeys 176 | , COALESCE(STUFF(( 177 | SELECT '', '' + includedColumns 178 | FROM indexCTE 179 | WHERE objectID = cte.objectID 180 | AND indexID = cte.indexID 181 | AND includedColumns IS NOT NULL 182 | ORDER BY columnID 183 | FOR XML PATH(''''), 184 | TYPE).value(''.'',''varchar(max)''),1,1,''''), '''') AS includedColumns 185 | , COALESCE(STUFF(( 186 | SELECT '', '' + partitionColumns 187 | FROM indexCTE 188 | WHERE objectID = cte.objectID 189 | AND indexID = cte.indexID 190 | AND partitionColumns IS NOT NULL 191 | ORDER BY partitionOrdinal 192 | FOR XML PATH(''''), 193 | TYPE).value(''.'',''varchar(max)''),1,1,''''), '''') AS partitionKeys 194 | , isPrimaryKey 195 | , isUnique 196 | , isUniqueConstraint 197 | , isFilteredIndex 198 | , FilterDefinition 199 | FROM indexCTE AS cte 200 | ORDER BY tableName 201 | , indexName; 202 | '; 203 | 204 | -- For multi-server testing, dump results to a temp table and compare tables 205 | SELECT * 206 | FROM #IndexAudit 207 | WHERE databaseName NOT IN ('tempdb', 'master', 'msdb', 'model') 208 | ORDER BY serverName 209 | , databaseName 210 | , tableName 211 | , indexName; -------------------------------------------------------------------------------- /indexes/missing.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: missing.sql 4 | 5 | SYNOPSIS: Displays potential missing indexes for a given database. Adding the indexes via the 6 | provided CREATE scripts may improve server performance. 7 | 8 | DEPENDENCIES: The following dependencies are required to execute this script: 9 | - SQL Server 2005 or newer 10 | 11 | AUTHOR: Michelle Ufford, http://sqlfool.com 12 | 13 | CREATED: 2014-04-08 14 | 15 | VERSION: 1.0 16 | 17 | LICENSE: Apache License v2 18 | 19 | ---------------------------------------------------------------------------- 20 | DISCLAIMER: 21 | This code and information are provided "AS IS" without warranty of any kind, 22 | either expressed or implied, including but not limited to the implied 23 | warranties or merchantability and/or fitness for a particular purpose. 24 | ---------------------------------------------------------------------------- 25 | 26 | --------------------------------------------------------------------------------------------------------- 27 | -- DATE VERSION AUTHOR DESCRIPTION -- 28 | --------------------------------------------------------------------------------------------------------- 29 | 20140408 1.0 Michelle Ufford Open Sourced on GitHub 30 | **********************************************************************************************************/ 31 | 32 | SELECT 33 | t.name AS 'affected_table' 34 | , 'CREATE NONCLUSTERED INDEX IX_' + t.name + '_missing_' 35 | + CONVERT(CHAR(8), GETDATE(), 112) + '_' 36 | + CAST(ROW_NUMBER() OVER (PARTITION BY t.name 37 | ORDER BY CAST((ddmigs.user_seeks + ddmigs.user_scans) 38 | * ddmigs.avg_user_impact AS BIGINT) DESC) AS VARCHAR(3)) 39 | + ' ON ' + ddmid.statement 40 | + ' (' + ISNULL(ddmid.equality_columns,'') 41 | + CASE WHEN ddmid.equality_columns IS NOT NULL 42 | AND ddmid.inequality_columns IS NOT NULL THEN ',' 43 | ELSE '' END 44 | + ISNULL(ddmid.inequality_columns, '') 45 | + ')' 46 | + ISNULL(' INCLUDE (' + ddmid.included_columns + ');', ';' 47 | ) AS sql_statement 48 | , ddmigs.user_seeks 49 | , ddmigs.user_scans 50 | , CAST((ddmigs.user_seeks + ddmigs.user_scans) 51 | * ddmigs.avg_user_impact AS BIGINT) AS 'est_impact' 52 | , ddmigs.last_user_seek 53 | FROM sys.dm_db_missing_index_groups AS ddmig 54 | INNER JOIN sys.dm_db_missing_index_group_stats AS ddmigs 55 | ON ddmigs.group_handle = ddmig.index_group_handle 56 | INNER JOIN sys.dm_db_missing_index_details AS ddmid 57 | ON ddmig.index_handle = ddmid.index_handle 58 | INNER JOIN sys.tables AS t 59 | ON ddmid.[object_id] = t.[object_id] 60 | WHERE ddmid.database_id = DB_ID() ----> by default, only examines the current database 61 | AND CAST((ddmigs.user_seeks + ddmigs.user_scans) * ddmigs.avg_user_impact AS BIGINT) > 100 ----> 100 is a starting point; update value as appropriate 62 | ORDER BY CAST((ddmigs.user_seeks + ddmigs.user_scans) * ddmigs.avg_user_impact AS BIGINT) DESC; -------------------------------------------------------------------------------- /indexes/unused.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************************** 2 | 3 | NAME: unused.sql 4 | 5 | SYNOPSIS: Displays potential unused indexes for the current database. Dropping these indexes 6 | may improve database performance. These statistics are reset each time the server 7 | is rebooted, so make sure to review the [sqlserver_start_time] value to ensure the 8 | statistics are captured for a meaningful time period. 9 | 10 | DEPENDENCIES: The following dependencies are required to execute this script: 11 | - SQL Server 2005 or newer 12 | 13 | AUTHOR: Michelle Ufford, http://sqlfool.com 14 | 15 | CREATED: 2014-04-08 16 | 17 | VERSION: 1.0 18 | 19 | LICENSE: Apache License v2 20 | 21 | ---------------------------------------------------------------------------- 22 | DISCLAIMER: 23 | This code and information are provided "AS IS" without warranty of any kind, 24 | either expressed or implied, including but not limited to the implied 25 | warranties or merchantability and/or fitness for a particular purpose. 26 | ---------------------------------------------------------------------------- 27 | 28 | --------------------------------------------------------------------------------------------------------- 29 | -- DATE VERSION AUTHOR DESCRIPTION -- 30 | --------------------------------------------------------------------------------------------------------- 31 | 20140408 1.0 Michelle Ufford Open Sourced on GitHub 32 | **********************************************************************************************************/ 33 | 34 | 35 | SELECT sqlserver_start_time FROM sys.dm_os_sys_info; 36 | 37 | DECLARE @dbid INT 38 | , @dbName VARCHAR(100); 39 | 40 | SELECT @dbid = DB_ID() 41 | , @dbName = DB_NAME(); 42 | 43 | WITH partitionCTE (object_id, index_id, row_count, partition_count) 44 | AS 45 | ( 46 | SELECT [object_id] 47 | , index_id 48 | , SUM([rows]) AS 'row_count' 49 | , COUNT(partition_id) AS 'partition_count' 50 | FROM sys.partitions 51 | GROUP BY [object_id] 52 | , index_id 53 | ) 54 | 55 | SELECT OBJECT_NAME(i.[object_id]) AS objectName 56 | , i.name 57 | , CASE 58 | WHEN i.is_unique = 1 59 | THEN 'UNIQUE ' 60 | ELSE '' 61 | END + i.type_desc AS 'indexType' 62 | , ddius.user_seeks 63 | , ddius.user_scans 64 | , ddius.user_lookups 65 | , ddius.user_updates 66 | , cte.row_count 67 | , CASE WHEN partition_count > 1 THEN 'yes' 68 | ELSE 'no' END AS 'partitioned?' 69 | , CASE 70 | WHEN i.type = 2 AND i.is_unique = 0 71 | THEN 'Drop Index ' + i.name 72 | + ' On ' + @dbName 73 | + '.dbo.' + OBJECT_NAME(ddius.[object_id]) + ';' 74 | WHEN i.type = 2 AND i.is_unique = 1 75 | THEN 'Alter Table ' + @dbName 76 | + '.dbo.' + OBJECT_NAME(ddius.[object_ID]) 77 | + ' Drop Constraint ' + i.name + ';' 78 | ELSE '' 79 | END AS 'SQL_DropStatement' 80 | FROM sys.indexes AS i 81 | INNER JOIN sys.dm_db_index_usage_stats AS ddius 82 | ON i.object_id = ddius.object_id 83 | AND i.index_id = ddius.index_id 84 | INNER JOIN partitionCTE AS cte 85 | ON i.object_id = cte.object_id 86 | AND i.index_id = cte.index_id 87 | WHERE ddius.database_id = @dbid 88 | AND i.type = 2 ----> retrieve nonclustered indexes only 89 | AND i.is_unique = 0 ----> ignore unique indexes, we'll assume they're serving a necessary business use 90 | AND (ddius.user_seeks + ddius.user_scans + ddius.user_lookups) = 0 ----> starting point, update this value as needed; 0 retrieves completely unused indexes 91 | ORDER BY user_updates DESC; 92 | 93 | -------------------------------------------------------------------------------- /misc/dba_viewPageData_sp.sql: -------------------------------------------------------------------------------- 1 | If ObjectProperty(Object_ID('dbo.dba_viewPageData_sp'), N'IsProcedure') Is Null 2 | Begin 3 | Execute ('Create Procedure dbo.dba_viewPageData_sp As Print ''Hello World!''') 4 | RaisError('Procedure dba_viewPageData_sp created.', 10, 1); 5 | End; 6 | Go 7 | 8 | Set ANSI_Nulls On; 9 | Set Quoted_Identifier On; 10 | Go 11 | 12 | Alter Procedure dbo.dba_viewPageData_sp 13 | 14 | /* Declare Parameters */ 15 | @databaseName varchar(128) 16 | , @tableName varchar(128) = Null -- database.schema.tableName 17 | , @indexName varchar(128) = Null 18 | , @fileNumber int = Null 19 | , @pageNumber int = Null 20 | , @printOption int = 3 -- 0, 1, 2, or 3 21 | , @pageType char(4) = 'Leaf' -- Leaf, Root, or IAM 22 | 23 | As 24 | /********************************************************************************************************** 25 | 26 | NAME: dba_viewPageData_sp 27 | 28 | SYNOPSIS: Retrieves page data for the specified table/page. 29 | 30 | DEPENDENCIES: The following dependencies are required to execute this script: 31 | - SQL Server 2005 or newer 32 | 33 | NOTES: Can pass either the table name or the pageID, but must pass one, or 34 | you'll end up with no results. 35 | If the table name is passed, it will return the first page. 36 | 37 | @tableName must be '..' in order to 38 | function correctly. When called within the same database, the database 39 | prefix may be omitted. 40 | 41 | @printOption can be one of following values: 42 | 0 - print just the page header 43 | 1 - page header plus per-row hex dumps and a dump of the page slot array 44 | 2 - page header plus whole page hex dump 45 | 3 - page header plus detailed per-row interpretation 46 | 47 | Page Options borrowed from: 48 | https://blogs.msdn.com/sqlserverstorageengine/archive/2006/06/10/625659.aspx 49 | 50 | @pageType must be one of the following values: 51 | Leaf - returns the first page of the leaf level of your index or heap 52 | Root - returns the root page of your index 53 | IAM - returns the index allocation map chain for your index or heap 54 | 55 | Conversions borrowed from: 56 | http://sqlskills.com/blogs/paul/post/Inside-The-Storage-Engine- 57 | sp_AllocationMetadata-putting-undocumented-system-catalog-views-to-work.aspx 58 | 59 | AUTHOR: Michelle Ufford, http://sqlfool.com 60 | 61 | CREATED: 2009-05-06 62 | 63 | VERSION: 1.0 64 | 65 | LICENSE: Apache License v2 66 | 67 | USAGE: EXEC dbo.dba_viewPageData_sp 68 | @databaseName = 'AdventureWorks' 69 | , @tableName = 'AdventureWorks.Sales.SalesOrderDetail' 70 | , @indexName = 'IX_SalesOrderDetail_ProductID' 71 | --, @fileNumber = 1 72 | --, @pageNumber = 38208 73 | , @printOption = 3 74 | , @pageType = 'Root'; 75 | 76 | ---------------------------------------------------------------------------- 77 | DISCLAIMER: 78 | This code and information are provided "AS IS" without warranty of any kind, 79 | either expressed or implied, including but not limited to the implied 80 | warranties or merchantability and/or fitness for a particular purpose. 81 | ---------------------------------------------------------------------------- 82 | 83 | --------------------------------------------------------------------------------------------------------- 84 | -- DATE VERSION AUTHOR DESCRIPTION -- 85 | --------------------------------------------------------------------------------------------------------- 86 | 20150619 1.0 Michelle Ufford Open Sourced on GitHub 87 | **********************************************************************************************************/ 88 | 89 | Set NoCount On; 90 | Set XACT_Abort On; 91 | Set Ansi_Padding On; 92 | Set Ansi_Warnings On; 93 | Set ArithAbort On; 94 | Set Concat_Null_Yields_Null On; 95 | Set Numeric_RoundAbort Off; 96 | 97 | Begin 98 | 99 | Declare @fileID int 100 | , @pageID int 101 | , @sqlStatement nvarchar(1200) 102 | , @sqlParameters nvarchar(255) 103 | , @errorMessage varchar(100); 104 | 105 | Begin Try 106 | 107 | If @fileNumber Is Null And @pageNumber Is Null And @tableName Is Null 108 | Begin 109 | Set @errorMessage = 'You must provide either a file/page number, or a table name!'; 110 | RaisError(@errorMessage, 16, 1); 111 | End; 112 | 113 | If @pageType Not In ('Leaf', 'Root', 'IAM') 114 | Begin 115 | Set @errorMessage = 'You have entered an invalid page type; valid options are "Leaf", "Root", or "IAM"'; 116 | RaisError(@errorMessage, 16, 1); 117 | End; 118 | 119 | If @fileNumber Is Null Or @pageNumber Is Null 120 | Begin 121 | 122 | Set @sqlStatement = 123 | Case When @pageType = 'Leaf' Then 124 | 'Select Top 1 @p_fileID = Convert (varchar(6), Convert (int, 125 | SubString (au.first_page, 6, 1) + 126 | SubString (au.first_page, 5, 1))) 127 | , @p_pageID = Convert (varchar(20), Convert (int, 128 | SubString (au.first_page, 4, 1) + 129 | SubString (au.first_page, 3, 1) + 130 | SubString (au.first_page, 2, 1) + 131 | SubString (au.first_page, 1, 1)))' 132 | When @pageType = 'Root' Then 133 | 'Select Top 1 @p_fileID = Convert (varchar(6), Convert (int, 134 | SubString (au.root_page, 6, 1) + 135 | SubString (au.root_page, 5, 1))) 136 | , @p_pageID = Convert (varchar(20), Convert (int, 137 | SubString (au.root_page, 4, 1) + 138 | SubString (au.root_page, 3, 1) + 139 | SubString (au.root_page, 2, 1) + 140 | SubString (au.root_page, 1, 1)))' 141 | When @pageType = 'IAM' Then 142 | 'Select Top 1 @p_fileID = Convert (varchar(6), Convert (int, 143 | SubString (au.first_iam_page, 6, 1) + 144 | SubString (au.first_iam_page, 5, 1))) 145 | , @p_pageID = Convert (varchar(20), Convert (int, 146 | SubString (au.first_iam_page, 4, 1) + 147 | SubString (au.first_iam_page, 3, 1) + 148 | SubString (au.first_iam_page, 2, 1) + 149 | SubString (au.first_iam_page, 1, 1)))' 150 | End + 151 | 'From ' + QuoteName(ParseName(@databaseName, 1)) + '.sys.indexes AS i 152 | Join ' + QuoteName(ParseName(@databaseName, 1)) + '.sys.partitions AS p 153 | On i.[object_id] = p.[object_id] 154 | And i.index_id = p.index_id 155 | Join ' + QuoteName(ParseName(@databaseName, 1)) + '.sys.system_internals_allocation_units AS au 156 | On p.hobt_id = au.container_id 157 | Where p.[object_id] = Object_ID(@p_tableName) 158 | And au.first_page > 0x000000000000 ' 159 | + Case When @indexName Is Null 160 | Then ';' 161 | Else 'And i.name = @p_indexName;' End; 162 | 163 | Set @sqlParameters = '@p_tableName varchar(128) 164 | , @p_indexName varchar(128) 165 | , @p_fileID int OUTPUT 166 | , @p_pageID int OUTPUT'; 167 | 168 | Execute sp_executeSQL @sqlStatement 169 | , @sqlParameters 170 | , @p_tableName = @tableName 171 | , @p_indexName = @indexName 172 | , @p_fileID = @fileID OUTPUT 173 | , @p_pageID = @pageID OUTPUT; 174 | 175 | End 176 | Else 177 | Begin 178 | Select @fileID = @fileNumber 179 | , @pageID = @pageNumber; 180 | End; 181 | 182 | DBCC TraceOn (3604); 183 | DBCC Page (@databaseName, @fileID, @pageID, @printOption); 184 | DBCC TraceOff (3604); 185 | 186 | End Try 187 | Begin Catch 188 | 189 | Print @errorMessage; 190 | 191 | End Catch; 192 | 193 | Set NoCount Off; 194 | Return 0; 195 | End 196 | Go 197 | 198 | Set Quoted_Identifier Off; 199 | Go --------------------------------------------------------------------------------