├── .gitattributes
├── .gitignore
├── LICENSE.txt
├── README.md
└── TSQLCodeLibrary
├── Scripts
└── ScriptsIgnoredOnImport.sql
├── TSQLCodeLibrary.sln
├── TSQLCodeLibrary.sqlproj
├── conchango.sql
├── conchango
└── Stored Procedures
│ ├── csp_ToolIDAssign.sql
│ └── csp_ToolRenameObjects2005.sql
├── jt.sql
└── jt
├── Functions
└── cdf_TitleCase.sql
├── Stored Procedures
├── AllPermissions.sql
├── AutoGrowAutoShrinkEvents.sql
├── CurrentlyExecutingSQLAgentJobs.sql
├── DeadlockGraphShredder.sql
├── GetIoVirtualFileStatsDeltas.sql
├── GetPartitionRowTallies.sql
├── GetTableRowTallies.sql
├── TableStats.sql
├── WaitStatsAnalysis.sql
└── tempdbStats.sql
└── Views
├── StatsLastUpdatedTime.sql
├── vwAllSessions.sql
├── vwBufferusagePerDB.sql
├── vwCacheUsagePerTable.sql
├── vwCodeLibraryDescriptions.sql
├── vwFastRowCounts.sql
└── vwdiskfileLatency.sql
/.gitattributes:
--------------------------------------------------------------------------------
1 | ###############################################################################
2 | # Set default behavior to automatically normalize line endings.
3 | ###############################################################################
4 | * text=auto
5 |
6 | ###############################################################################
7 | # Set default behavior for command prompt diff.
8 | #
9 | # This is need for earlier builds of msysgit that does not have it on by
10 | # default for csharp files.
11 | # Note: This is only used by command line
12 | ###############################################################################
13 | #*.cs diff=csharp
14 |
15 | ###############################################################################
16 | # Set the merge driver for project and solution files
17 | #
18 | # Merging from the command prompt will add diff markers to the files if there
19 | # are conflicts (Merging from VS is not affected by the settings below, in VS
20 | # the diff markers are never inserted). Diff markers may cause the following
21 | # file extensions to fail to load in VS. An alternative would be to treat
22 | # these files as binary and thus will always conflict and require user
23 | # intervention with every merge. To do so, just uncomment the entries below
24 | ###############################################################################
25 | #*.sln merge=binary
26 | #*.csproj merge=binary
27 | #*.vbproj merge=binary
28 | #*.vcxproj merge=binary
29 | #*.vcproj merge=binary
30 | #*.dbproj merge=binary
31 | #*.fsproj merge=binary
32 | #*.lsproj merge=binary
33 | #*.wixproj merge=binary
34 | #*.modelproj merge=binary
35 | #*.sqlproj merge=binary
36 | #*.wwaproj merge=binary
37 |
38 | ###############################################################################
39 | # behavior for image files
40 | #
41 | # image files are treated as binary by default.
42 | ###############################################################################
43 | #*.jpg binary
44 | #*.png binary
45 | #*.gif binary
46 |
47 | ###############################################################################
48 | # diff behavior for common document formats
49 | #
50 | # Convert binary document formats to text before diffing them. This feature
51 | # is only available from the command line. Turn it on by uncommenting the
52 | # entries below.
53 | ###############################################################################
54 | #*.doc diff=astextplain
55 | #*.DOC diff=astextplain
56 | #*.docx diff=astextplain
57 | #*.DOCX diff=astextplain
58 | #*.dot diff=astextplain
59 | #*.DOT diff=astextplain
60 | #*.pdf diff=astextplain
61 | #*.PDF diff=astextplain
62 | #*.rtf diff=astextplain
63 | #*.RTF diff=astextplain
64 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | ## Ignore Visual Studio temporary files, build results, and
2 | ## files generated by popular Visual Studio add-ons.
3 |
4 | # User-specific files
5 | *.suo
6 | *.user
7 | *.sln.docstates
8 |
9 | # Build results
10 |
11 | [Dd]ebug/
12 | [Rr]elease/
13 | x64/
14 | build/
15 | [Bb]in/
16 | [Oo]bj/
17 |
18 | # Enable "build/" folder in the NuGet Packages folder since NuGet packages use it for MSBuild targets
19 | !packages/*/build/
20 |
21 | # MSTest test Results
22 | [Tt]est[Rr]esult*/
23 | [Bb]uild[Ll]og.*
24 |
25 | *_i.c
26 | *_p.c
27 | *.ilk
28 | *.meta
29 | *.obj
30 | *.pch
31 | *.pdb
32 | *.pgc
33 | *.pgd
34 | *.rsp
35 | *.sbr
36 | *.tlb
37 | *.tli
38 | *.tlh
39 | *.tmp
40 | *.tmp_proj
41 | *.log
42 | *.vspscc
43 | *.vssscc
44 | .builds
45 | *.pidb
46 | *.log
47 | *.scc
48 |
49 | # Visual C++ cache files
50 | ipch/
51 | *.aps
52 | *.ncb
53 | *.opensdf
54 | *.sdf
55 | *.cachefile
56 |
57 | # Visual Studio profiler
58 | *.psess
59 | *.vsp
60 | *.vspx
61 |
62 | # Guidance Automation Toolkit
63 | *.gpState
64 |
65 | # ReSharper is a .NET coding add-in
66 | _ReSharper*/
67 | *.[Rr]e[Ss]harper
68 |
69 | # TeamCity is a build add-in
70 | _TeamCity*
71 |
72 | # DotCover is a Code Coverage Tool
73 | *.dotCover
74 |
75 | # NCrunch
76 | *.ncrunch*
77 | .*crunch*.local.xml
78 |
79 | # Installshield output folder
80 | [Ee]xpress/
81 |
82 | # DocProject is a documentation generator add-in
83 | DocProject/buildhelp/
84 | DocProject/Help/*.HxT
85 | DocProject/Help/*.HxC
86 | DocProject/Help/*.hhc
87 | DocProject/Help/*.hhk
88 | DocProject/Help/*.hhp
89 | DocProject/Help/Html2
90 | DocProject/Help/html
91 |
92 | # Click-Once directory
93 | publish/
94 |
95 | # Publish Web Output
96 | *.Publish.xml
97 | *.pubxml
98 |
99 | # NuGet Packages Directory
100 | ## TODO: If you have NuGet Package Restore enabled, uncomment the next line
101 | #packages/
102 |
103 | # Windows Azure Build Output
104 | csx
105 | *.build.csdef
106 |
107 | # Windows Store app package directory
108 | AppPackages/
109 |
110 | # Others
111 | sql/
112 | *.Cache
113 | ClientBin/
114 | [Ss]tyle[Cc]op.*
115 | ~$*
116 | *~
117 | *.dbmdl
118 | *.[Pp]ublish.xml
119 | *.pfx
120 | *.publishsettings
121 |
122 | # RIA/Silverlight projects
123 | Generated_Code/
124 |
125 | # Backup & report files from converting an old project file to a newer
126 | # Visual Studio version. Backup files are not needed, because we have git ;-)
127 | _UpgradeReport_Files/
128 | Backup*/
129 | UpgradeLog*.XML
130 | UpgradeLog*.htm
131 |
132 | # SQL Server files
133 | App_Data/*.mdf
134 | App_Data/*.ldf
135 |
136 | # =========================
137 | # Windows detritus
138 | # =========================
139 |
140 | # Windows image file caches
141 | Thumbs.db
142 | ehthumbs.db
143 |
144 | # Folder config file
145 | Desktop.ini
146 |
147 | # Recycle Bin used on file shares
148 | $RECYCLE.BIN/
149 |
150 | # Mac crap
151 | .DS_Store
152 |
--------------------------------------------------------------------------------
/LICENSE.txt:
--------------------------------------------------------------------------------
1 | The MIT License (MIT)
2 |
3 | Copyright (c) 2014 Jamie Thomson
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | TSQLCodeLibrary
2 | ===============
3 |
4 | My personal T-SQL code library
5 |
6 | Licensed under the MIT license, see LICENSE.txt.
--------------------------------------------------------------------------------
/TSQLCodeLibrary/Scripts/ScriptsIgnoredOnImport.sql:
--------------------------------------------------------------------------------
1 |
2 | create view jt.vwdiskfileLatency
3 | AS
4 | /*
5 | Show disk file latency
6 |
7 | http://www.sqlskills.com/BLOGS/PAUL/category/IO-Subsystems.aspx
8 | */
9 |
10 |
11 | SELECT
12 | --virtual file latency
13 | ReadLatency = CASE WHEN num_of_reads = 0
14 | THEN 0 ELSE (io_stall_read_ms / num_of_reads) END,
15 | WriteLatency = CASE WHEN num_of_writes = 0
16 | THEN 0 ELSE (io_stall_write_ms / num_of_writes) END,
17 | Latency = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0)
18 | THEN 0 ELSE (io_stall / (num_of_reads + num_of_writes)) END,
19 | --avg bytes per IOP
20 | AvgBPerRead = CASE WHEN num_of_reads = 0
21 | THEN 0 ELSE (num_of_bytes_read / num_of_reads) END,
22 | AvgBPerWrite = CASE WHEN io_stall_write_ms = 0
23 | THEN 0 ELSE (num_of_bytes_written / num_of_writes) END,
24 | AvgBPerTransfer = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0)
25 | THEN 0 ELSE ((num_of_bytes_read + num_of_bytes_written) /
26 | (num_of_reads + num_of_writes)) END,
27 | LEFT (mf.physical_name, 2) AS Drive,
28 | DB_NAME (vfs.database_id) AS DB,
29 | --vfs.*,
30 | mf.physical_name
31 | FROM sys.dm_io_virtual_file_stats (NULL,NULL) AS vfs
32 | JOIN sys.master_files AS mf
33 | ON vfs.database_id = mf.database_id
34 | AND vfs.file_id = mf.file_id
35 | --WHERE vfs.file_id = 2 -- log files
36 | -- ORDER BY Latency DESC
37 | -- ORDER BY ReadLatency DESC
38 | ORDER BY WriteLatency DESC;
39 |
40 | GO
41 |
42 | --Syntax Error: The ORDER BY clause is not valid in views, inline functions, derived tables, sub-queries, and common table expressions, unless TOP or FOR XML or OFFSET is also specified.
43 | --create view jt.vwdiskfileLatency
44 | --AS
45 | --/*
46 | -- Show disk file latency
47 | --
48 | -- http://www.sqlskills.com/BLOGS/PAUL/category/IO-Subsystems.aspx
49 | --*/
50 | --
51 | --
52 | --SELECT
53 | -- --virtual file latency
54 | -- ReadLatency = CASE WHEN num_of_reads = 0
55 | -- THEN 0 ELSE (io_stall_read_ms / num_of_reads) END,
56 | -- WriteLatency = CASE WHEN num_of_writes = 0
57 | -- THEN 0 ELSE (io_stall_write_ms / num_of_writes) END,
58 | -- Latency = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0)
59 | -- THEN 0 ELSE (io_stall / (num_of_reads + num_of_writes)) END,
60 | -- --avg bytes per IOP
61 | -- AvgBPerRead = CASE WHEN num_of_reads = 0
62 | -- THEN 0 ELSE (num_of_bytes_read / num_of_reads) END,
63 | -- AvgBPerWrite = CASE WHEN io_stall_write_ms = 0
64 | -- THEN 0 ELSE (num_of_bytes_written / num_of_writes) END,
65 | -- AvgBPerTransfer = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0)
66 | -- THEN 0 ELSE ((num_of_bytes_read + num_of_bytes_written) /
67 | -- (num_of_reads + num_of_writes)) END,
68 | -- LEFT (mf.physical_name, 2) AS Drive,
69 | -- DB_NAME (vfs.database_id) AS DB,
70 | -- --vfs.*,
71 | -- mf.physical_name
72 | --FROM sys.dm_io_virtual_file_stats (NULL,NULL) AS vfs
73 | --JOIN sys.master_files AS mf
74 | -- ON vfs.database_id = mf.database_id
75 | -- AND vfs.file_id = mf.file_id
76 | ----WHERE vfs.file_id = 2 -- log files
77 | ---- ORDER BY Latency DESC
78 | ---- ORDER BY ReadLatency DESC
79 | --ORDER BY WriteLatency DESC;
80 |
81 |
82 |
83 | GO
84 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/TSQLCodeLibrary.sln:
--------------------------------------------------------------------------------
1 |
2 | Microsoft Visual Studio Solution File, Format Version 12.00
3 | # Visual Studio 2013
4 | VisualStudioVersion = 12.0.21005.1
5 | MinimumVisualStudioVersion = 10.0.40219.1
6 | Project("{00D1A9C2-B5F0-4AF3-8072-F6C62B433612}") = "TSQLCodeLibrary", "TSQLCodeLibrary.sqlproj", "{58D06B8E-2DB4-4262-92C7-1944B63C5133}"
7 | EndProject
8 | Global
9 | GlobalSection(SolutionConfigurationPlatforms) = preSolution
10 | Debug|Any CPU = Debug|Any CPU
11 | Release|Any CPU = Release|Any CPU
12 | EndGlobalSection
13 | GlobalSection(ProjectConfigurationPlatforms) = postSolution
14 | {58D06B8E-2DB4-4262-92C7-1944B63C5133}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
15 | {58D06B8E-2DB4-4262-92C7-1944B63C5133}.Debug|Any CPU.Build.0 = Debug|Any CPU
16 | {58D06B8E-2DB4-4262-92C7-1944B63C5133}.Debug|Any CPU.Deploy.0 = Debug|Any CPU
17 | {58D06B8E-2DB4-4262-92C7-1944B63C5133}.Release|Any CPU.ActiveCfg = Release|Any CPU
18 | {58D06B8E-2DB4-4262-92C7-1944B63C5133}.Release|Any CPU.Build.0 = Release|Any CPU
19 | {58D06B8E-2DB4-4262-92C7-1944B63C5133}.Release|Any CPU.Deploy.0 = Release|Any CPU
20 | EndGlobalSection
21 | GlobalSection(SolutionProperties) = preSolution
22 | HideSolutionNode = FALSE
23 | EndGlobalSection
24 | EndGlobal
25 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/TSQLCodeLibrary.sqlproj:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 | Debug
6 | AnyCPU
7 | TSQLCodeLibrary
8 | 2.0
9 | 4.1
10 | {58d06b8e-2db4-4262-92c7-1944b63c5133}
11 | Microsoft.Data.Tools.Schema.Sql.Sql110DatabaseSchemaProvider
12 | Database
13 |
14 |
15 | TSQLCodeLibrary
16 | TSQLCodeLibrary
17 | 1033, CI
18 | BySchemaAndSchemaType
19 | True
20 | v4.5
21 | CS
22 | Properties
23 | False
24 | True
25 | True
26 |
27 |
28 | bin\Release\
29 | $(MSBuildProjectName).sql
30 | False
31 | pdbonly
32 | true
33 | false
34 | true
35 | prompt
36 | 4
37 |
38 |
39 | bin\Debug\
40 | $(MSBuildProjectName).sql
41 | false
42 | true
43 | full
44 | false
45 | true
46 | true
47 | prompt
48 | 4
49 |
50 |
51 |
52 | 10.0
53 |
54 | True
55 | 10.0
56 |
57 |
58 |
59 |
60 |
61 |
62 |
63 |
64 |
65 |
66 |
67 |
68 |
69 |
70 |
71 |
72 |
73 |
74 |
75 |
76 |
77 |
78 |
79 |
80 |
81 |
82 |
83 |
84 |
85 |
86 |
87 |
88 |
89 |
90 |
91 |
92 |
93 |
94 |
95 | $(DacPacRootPath)\Extensions\Microsoft\SQLDB\Extensions\SqlServer\110\SqlSchemas\master.dacpac
96 | False
97 | master
98 |
99 |
100 | $(DacPacRootPath)\Extensions\Microsoft\SQLDB\Extensions\SqlServer\110\SqlSchemas\msdb.dacpac
101 | False
102 | msdb
103 |
104 |
105 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/conchango.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [conchango]
2 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/conchango/Stored Procedures/csp_ToolIDAssign.sql:
--------------------------------------------------------------------------------
1 | /*
2 | csp_ToolIDAssign
3 |
4 | Assigns unqiue surrogate key
5 |
6 |
7 | Table Name
8 | Surrogate Column Name
9 | Source Table of last value
10 | Additional Constraint
11 | Whether or not to print the SQL
12 | Whether or not to execute the SQL
13 | The SQL used to generate the surrogate keys
14 |
15 |
16 |
17 |
18 | */
19 | CREATE PROC [conchango].[csp_ToolIDAssign]
20 | (
21 | @pTableName SYSNAME,
22 | @pColumnName SYSNAME,
23 | @pSourceTableName SYSNAME = NULL, --Optional Source Table Name (ie Presentation table)
24 | @pConstraint VARCHAR(1000) = NULL, --Optional Constraint
25 | @pPrintSQL TINYINT = 0,
26 | @pExecuteSQL TINYINT = 1,
27 | @pSQL VARCHAR(1000) = '' OUTPUT
28 | ) AS
29 |
30 | SET NOCOUNT ON
31 | SET ANSI_WARNINGS ON
32 | SET DATEFORMAT DMY
33 |
34 | --Declare Variables
35 | DECLARE @vError INT,
36 | @vSQL VARCHAR(1000),
37 | @vTableSchema SYSNAME,
38 | @vTableNameWithoutSchema SYSNAME,
39 | @vTargetColumnDataType SYSNAME
40 |
41 | BEGIN TRY
42 |
43 | --Source Table = Table if not supplied
44 | SET @pSourceTableName = ISNULL(@pSourceTableName, @pTableName)
45 | SET @pConstraint = ISNULL(@pConstraint, '')
46 |
47 | IF CHARINDEX('.', @pTableName) <> 0 --i.e. schema name is included in table name
48 | BEGIN
49 | SET @vTableSchema = LEFT(@pTableName, CHARINDEX('.', @pTableName) - 1)
50 | SET @vTableNameWithoutSchema = SUBSTRING(@pTableName, CHARINDEX('.', @pTableName) + 1, 255)
51 | END
52 | ELSE
53 | BEGIN
54 | SET @vTableSchema = 'dbo'
55 | SET @vTableNameWithoutSchema = @pTableName
56 | END
57 |
58 | --establish if target column is bigint or not (bigint columns must be handled separately)
59 | SELECT @vTargetColumnDataType = DATA_TYPE
60 | FROM INFORMATION_SCHEMA.COLUMNS
61 | WHERE TABLE_NAME = @vTableNameWithoutSchema
62 | AND TABLE_SCHEMA = @vTableSchema
63 | AND COLUMN_NAME = @pColumnName
64 |
65 | SET @vSQL = REPLACE(' DECLARE @vKeyCounter @pDataType', '@pDataType', @vTargetColumnDataType)
66 |
67 | SET @vSQL = @vSQL + '
68 |
69 | SET @vKeyCounter = (SELECT ISNULL(MIN(@pColumnName), -1) FROM @pSourceTableName)
70 |
71 | UPDATE @pTableName
72 | SET @vKeyCounter = @pColumnName = @vKeyCounter - 1
73 | WHERE @pColumnName IS NULL
74 | @pConstraint
75 | OPTION (MAXDOP 1)
76 |
77 | '
78 | SET @vSQL = REPLACE(@vSQL, '@pColumnName', @pColumnName)
79 | SET @vSQL = REPLACE(@vSQL, '@pTableName', @pTableName)
80 | SET @vSQL = REPLACE(@vSQL, '@pSourceTableName', @pSourceTableName)
81 | SET @vSQL = REPLACE(@vSQL, '@pConstraint', @pConstraint)
82 |
83 | --Return SQL
84 | SET @pSQL = @vSQL
85 | EXEC dbo.csp_ToolSQLExecute @vSQL, @pPrintSQL, @pExecuteSQL
86 |
87 |
88 | END TRY
89 | BEGIN CATCH
90 |
91 | EXEC @vError = csp_LogAndRethrowError
92 | RETURN @vError
93 |
94 | END CATCH
--------------------------------------------------------------------------------
/TSQLCodeLibrary/conchango/Stored Procedures/csp_ToolRenameObjects2005.sql:
--------------------------------------------------------------------------------
1 | CREATE PROC [conchango].[csp_ToolRenameObjects2005]
2 | (
3 | @pTableName SYSNAME = '%',
4 | @pFK BIT = 1,
5 | @pCheck BIT = 1,
6 | @pIndexes BIT = 1,
7 | @pPrintSQL BIT = 1,
8 | @pExecuteSQL BIT = 0
9 | ) as
10 |
11 | SET NOCOUNT ON
12 |
13 | DECLARE @vTableName SYSNAME,
14 | @vObjectCount TINYINT,
15 | @vCurObjectCount CHAR(2),
16 | @i VARCHAR(2),
17 | @vCurObjectName SYSNAME,
18 | @vNewObjectName SYSNAME,
19 | @vFKTableName SYSNAME,
20 | @vPKTableName SYSNAME,
21 | @vPrimary BIT,
22 | @vClustered BIT
23 |
24 | IF @pTableName IS NULL OR @pTableName = ''
25 | SET @pTableName = '%'
26 |
27 | DECLARE cur_tables cursor LOCAL FAST_FORWARD FOR
28 | SELECT TABLE_NAME
29 | FROM INFORMATION_SCHEMA.TABLES
30 | WHERE OBJECTPROPERTY(OBJECT_ID(TABLE_NAME), 'ISMSSHIPPED') = 0 AND
31 | TABLE_NAME LIKE @pTableName
32 | ORDER BY 1
33 |
34 | OPEN cur_tables
35 |
36 | FETCH NEXT FROM cur_tables INTO @vTableName
37 |
38 | WHILE @@FETCH_STATUS = 0
39 | BEGIN
40 | /*
41 | ** FK Constraints
42 | */
43 |
44 | IF @pFK = 1
45 | BEGIN
46 | IF OBJECT_ID('TEMPDB..#FKs') IS NOT NULL
47 | DROP TABLE #FKs
48 |
49 | SELECT DISTINCT
50 | object_name(constid) as CurObjectName,
51 | object_name(fkeyid) as FKTableName,
52 | --Following line changed from csp_ToolRenameObjects
53 | --object_name(rkeyid) as PKTableName,*
54 | object_name(rkeyid) as PKTableName
55 | INTO #FKs
56 | FROM sysforeignkeys sc
57 | WHERE fkeyid = OBJECT_ID(@vTableName)
58 | ORDER BY object_name(fkeyid), object_name(rkeyid)
59 |
60 | SELECT @vObjectCount = @@ROWCOUNT,
61 | @i = '1'
62 |
63 | DECLARE cur_FKs CURSOR LOCAL FAST_FORWARD FOR
64 | SELECT CurObjectName, FKTableName, PKTableName
65 | FROM #FKs
66 |
67 | OPEN cur_FKs
68 |
69 | FETCH NEXT FROM cur_FKs INTO @vCurObjectName, @vFKTableName, @vPKTableName
70 |
71 | WHILE @@FETCH_STATUS = 0
72 | BEGIN
73 | SET @vCurObjectCount = REPLICATE('0', 2 - LEN(@i)) + @i
74 |
75 | SELECT @vNewObjectName = 'FK_' + @vFKTableName + '_' + @vPKTableName + '_' + @vCurObjectCount
76 |
77 | IF @pExecuteSQL = 1
78 | EXEC sp_rename @vCurObjectName, @vNewObjectName, 'OBJECT'
79 |
80 | IF @pPrintSQL = 1
81 | SELECT @vNewObjectName, @vCurObjectName
82 |
83 | SET @i = @i + 1
84 | FETCH NEXT FROM cur_FKs INTO @vCurObjectName, @vFKTableName, @vPKTableName
85 | END
86 |
87 | CLOSE cur_FKs
88 | DEALLOCATE cur_FKs
89 | END
90 |
91 | /*
92 | ** Check Constraints
93 | */
94 |
95 | IF @pCheck = 1
96 | BEGIN
97 | IF OBJECT_ID('TEMPDB..#CHKs') IS NOT NULL
98 | DROP TABLE #CHKs
99 |
100 | SELECT DISTINCT
101 | CONSTRAINT_NAME AS CurObjectName
102 | INTO #CHKs
103 | FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS
104 | WHERE TABLE_NAME = @vTableName AND
105 | CONSTRAINT_TYPE = 'CHECK'
106 | ORDER BY CONSTRAINT_NAME
107 |
108 | SELECT @vObjectCount = @@ROWCOUNT,
109 | @i = '1'
110 |
111 | DECLARE cur_CHKs CURSOR LOCAL FAST_FORWARD FOR
112 | SELECT CurObjectName
113 | FROM #CHKs
114 |
115 | OPEN cur_CHKs
116 |
117 | FETCH NEXT FROM cur_CHKs INTO @vCurObjectName
118 |
119 | WHILE @@FETCH_STATUS = 0
120 | BEGIN
121 | SET @vCurObjectCount = REPLICATE('0', 2 - LEN(@i)) + @i
122 |
123 | SELECT @vNewObjectName = 'CK_' + @vTableName + '_' + @vCurObjectCount
124 |
125 | IF @pExecuteSQL = 1
126 | EXEC sp_rename @vCurObjectName, @vNewObjectName, 'OBJECT'
127 |
128 | IF @pPrintSQL = 1
129 | SELECT @vNewObjectName, @vCurObjectName
130 |
131 | SET @i = @i + 1
132 | FETCH NEXT FROM cur_CHKs INTO @vCurObjectName
133 | END
134 |
135 | CLOSE cur_CHKs
136 | DEALLOCATE cur_CHKs
137 | END
138 |
139 | /*
140 | ** Indexes
141 | */
142 | IF @pIndexes = 1
143 | BEGIN
144 |
145 | IF OBJECT_ID('TEMPDB..#Indexes') IS NOT NULL
146 | DROP TABLE #Indexes
147 |
148 | SELECT OBJECT_NAME(si.id) as TableName,
149 | si.name as IndexName,
150 | (CASE WHEN OBJECTPROPERTY(scon.constid, 'IsPrimaryKey') = 1 THEN 1 ELSE 0 END) as bPrimary,
151 | (CASE WHEN INDEXPROPERTY(si.id, si.name, 'IsClustered') = 1 THEN 1 ELSE 0 END) as bClustered,
152 | max(sk.keyno) as NumCols
153 | INTO #Indexes
154 | FROM sysindexes si
155 | INNER JOIN
156 | sysindexkeys sk
157 | ON
158 | si.id = sk.id and
159 | si.indid = sk.indid
160 | INNER JOIN
161 | syscolumns sc
162 | ON
163 | sk.id = sc.id and
164 | sk.colid = sc.colid
165 | LEFT OUTER JOIN sysconstraints scon
166 | ON
167 | si.id = scon.id and
168 | si.name = object_name(scon.constid)
169 | WHERE INDEXPROPERTY(si.id, si.name, 'IsStatistics') = 0 AND
170 | OBJECT_NAME(si.id) = @vTableName
171 | GROUP BY OBJECT_NAME(si.id),
172 | si.name,
173 | (CASE WHEN OBJECTPROPERTY(scon.constid, 'IsPrimaryKey') = 1 THEN 1 ELSE 0 END),
174 | (CASE WHEN INDEXPROPERTY(si.id, si.name, 'IsClustered') = 1 THEN 1 ELSE 0 END)
175 | ORDER BY
176 | OBJECT_NAME(si.id),
177 | (CASE WHEN INDEXPROPERTY(si.id, si.name, 'IsClustered') = 1 THEN 1 ELSE 0 END) DESC,
178 | si.name
179 |
180 | SELECT @vObjectCount = @@ROWCOUNT,
181 | @i = '1'
182 |
183 | DECLARE cur_Indexes CURSOR LOCAL FAST_FORWARD FOR
184 | SELECT IndexName, bPrimary, bClustered
185 | FROM #Indexes
186 |
187 | OPEN cur_Indexes
188 |
189 | FETCH NEXT FROM cur_Indexes INTO @vCurObjectName, @vPrimary, @vClustered
190 |
191 | WHILE @@FETCH_STATUS = 0
192 | BEGIN
193 | SET @vCurObjectCount = REPLICATE('0', 2 - LEN(@i)) + @i
194 |
195 | SELECT @vNewObjectName = @vTableName + '_' + (CASE WHEN @vPrimary = 1 THEN 'PK'
196 | WHEN @vClustered = 1 THEN 'idx'
197 | ELSE 'ndx' + @vCurObjectCount END),
198 | @vCurObjectName = @vTableName + '.' + @vCurObjectName
199 |
200 | IF @pExecuteSQL = 1
201 | EXEC sp_rename @vCurObjectName, @vNewObjectName, 'INDEX'
202 |
203 | IF @pPrintSQL = 1
204 | SELECT @vNewObjectName, @vCurObjectName
205 |
206 | IF @vClustered <> 1 AND @vPrimary <> 1
207 | SET @i = @i + 1
208 |
209 | FETCH NEXT FROM cur_Indexes INTO @vCurObjectName, @vPrimary, @vClustered
210 | END
211 |
212 | CLOSE cur_Indexes
213 | DEALLOCATE cur_Indexes
214 |
215 |
216 | IF OBJECT_ID('TEMPDB..#Indexes') IS NOT NULL
217 | DROP TABLE #Indexes
218 | END
219 |
220 | -- Next Table
221 | FETCH NEXT FROM cur_tables INTO @vTableName
222 | END
223 |
224 | CLOSE cur_tables
225 | DEALLOCATE cur_tables
226 |
227 | /*
228 |
229 | select top 100 *
230 | from sysforeignkeys
231 | from information_schema.referential_constraints
232 | where Constraint_type = 'FOREIGN KEY'
233 |
234 | */
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [jt]
2 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Functions/cdf_TitleCase.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [jt].[cdf_TitleCase]
2 | ( @pStr AS NVARCHAR(100)
3 | ) RETURNS NVARCHAR(100) AS
4 | BEGIN
5 | /*
6 | cdf_TitleCase
7 |
8 | Returns Title Case Formatted String
9 |
10 |
11 | Input String
12 |
13 |
14 |
15 |
16 |
17 |
18 | SELECT dbo.cdf_TitleCase('mr.bean')
19 |
20 | */
21 |
22 | DECLARE @vReturnValue AS NVARCHAR(100),
23 | @vPos AS TINYINT,
24 | @vPos1 AS TINYINT,
25 | @vLen AS TINYINT
26 |
27 | SELECT @vReturnValue = ' ' + LOWER(@pStr),
28 | @vPos = 1,
29 | @vLen = LEN(@pStr) + 1
30 |
31 | WHILE @vPos > 0 AND @vPos <= @vLen
32 | BEGIN
33 | SET @vReturnValue = STUFF(@vReturnValue,
34 | @vPos + 1,
35 | 1,
36 | UPPER(SUBSTRING(@vReturnValue,@vPos + 1, 1)))
37 |
38 | SET @vPos1 = PATINDEX('%[ _/().-]%',SUBSTRING(@vReturnValue, @vPos + 1,100))
39 | SET @vPos = @vPos1 + SIGN(@vPos1) * @vPos
40 |
41 | END
42 |
43 | RETURN COALESCE(RIGHT(@vReturnValue, @vLen - 1),'')
44 |
45 | END
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/AllPermissions.sql:
--------------------------------------------------------------------------------
1 | CREATE PROC jt.AllPermissions
2 | @dbName sysname
3 | AS
4 | /*
5 | Originally published here: http://blogs.conchango.com/jamiethomson/archive/2007/02/09/SQL-Server-2005_3A00_-View-all-permissions--_2800_2_2900_.aspx
6 |
7 | This script will show all permissions that a user has in the current database, including those inherited from role memberships
8 |
9 | Might be a good idea to create this as a view
10 |
11 | This only works on SQL Server 2005 and later (because it uses a common table expression)
12 |
13 | -Jamie Thomson
14 | 2008-11-08
15 | */
16 | DECLARE @SQL nvarchar(max) = '
17 | WITH perms_cte as
18 | (
19 | select USER_NAME(p.grantee_principal_id) AS principal_name,
20 | dp.principal_id,
21 | dp.type_desc AS principal_type_desc,
22 | p.class_desc,
23 | OBJECT_NAME(p.major_id) AS object_name,
24 | p.permission_name,
25 | p.state_desc AS permission_state_desc
26 | from [@dbName].sys.database_permissions p
27 | inner JOIN [@dbName].sys.database_principals dp
28 | on p.grantee_principal_id = dp.principal_id
29 | )
30 | --users
31 | SELECT p.principal_name, p.principal_type_desc, p.class_desc, p.[object_name], p.permission_name, p.permission_state_desc, cast(NULL as sysname) as role_name
32 | FROM perms_cte p
33 | WHERE principal_type_desc <> ''DATABASE_ROLE''
34 | UNION
35 | --role members
36 | SELECT rm.member_principal_name, rm.principal_type_desc, p.class_desc, p.object_name, p.permission_name, p.permission_state_desc,rm.role_name
37 | FROM perms_cte p
38 | right outer JOIN (
39 | select role_principal_id, dp.type_desc as principal_type_desc, member_principal_id,user_name(member_principal_id) as member_principal_name,user_name(role_principal_id) as role_name--,*
40 | from [@dbName].sys.database_role_members rm
41 | INNER JOIN [@dbName].sys.database_principals dp
42 | ON rm.member_principal_id = dp.principal_id
43 | ) rm
44 | ON rm.role_principal_id = p.principal_id
45 | order by 1';
46 | SET @SQL = rePLACE(@SQL,'@dbName',@dbName)
47 | EXEC (@SQL)
48 |
49 | GO
50 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='AllPermissions',@level1type='PROCEDURE',@name='CodeLibraryDescription',@value='All permissions granted to any user, either directly or via role membership. Associated blog post here: http://blogs.conchango.com/jamiethomson/archive/2007/02/09/SQL-Server-2005_3A00_-View-all-permissions--_2800_2_2900_.aspx';
51 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/AutoGrowAutoShrinkEvents.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [jt].[AutoGrowAutoShrinkEvents]
2 | @dbname SYSNAME = NULL
3 | AS
4 | BEGIN
5 | IF (@dbname IS NULL) SET @dbname = DB_NAME()
6 | BEGIN TRY
7 | IF (
8 | SELECT CONVERT(INT, value_in_use)
9 | FROM sys.configurations
10 | WHERE name = 'default trace enabled'
11 | ) = 1
12 | BEGIN
13 | DECLARE @curr_tracefilename VARCHAR(500);
14 | DECLARE @base_tracefilename VARCHAR(500);
15 | DECLARE @indx INT;
16 |
17 | SELECT @curr_tracefilename = path
18 | FROM sys.traces
19 | WHERE is_default = 1;
20 | SET @curr_tracefilename = REVERSE(@curr_tracefilename);
21 | SELECT @indx = PATINDEX('%\%', @curr_tracefilename);
22 | SET @curr_tracefilename = REVERSE(@curr_tracefilename);
23 | SET @base_tracefilename = LEFT(@curr_tracefilename, LEN(@curr_tracefilename) - @indx) + '\log.trc';
24 |
25 | SELECT ( DENSE_RANK() OVER ( ORDER BY StartTime DESC ) ) % 2 AS l1
26 | , CONVERT(INT, EventClass) AS EventClass
27 | , DatabaseName
28 | , FileName
29 | , ( Duration / 1000 ) AS DurationMS
30 | , StartTime
31 | , EndTime
32 | , ( IntegerData * 8.0 / 1024 ) AS ChangeInSize
33 | INTO #events
34 | FROM ::
35 | fn_trace_gettable(@base_tracefilename, DEFAULT)
36 | WHERE EventClass >= 92
37 | AND EventClass <= 95
38 | AND ServerName = @@servername
39 | AND DatabaseName = @dbname;
40 | SELECT *
41 | FROM #events
42 | ORDER BY StartTime DESC;
43 | SELECT TotalDuration = 'Total Autogrow/AutoShrink duration = ' + CONVERT(NVARCHAR(20), SUM(DurationMS)) + 'milliseconds'
44 | FROM #events
45 | END
46 | ELSE
47 | PRINT 'default trace not enabled';
48 | --SELECT -1 AS l1
49 | --, 0 AS EventClass
50 | --, 0 DatabaseName
51 | --, 0 AS Filename
52 | --, 0 AS Duration
53 | --, 0 AS StartTime
54 | --, 0 AS EndTime
55 | --, 0 AS ChangeInSize
56 | END TRY
57 | BEGIN CATCH
58 | SELECT -100 AS l1
59 | , ERROR_NUMBER() AS EventClass
60 | , ERROR_SEVERITY() DatabaseName
61 | , ERROR_STATE() AS Filename
62 | , ERROR_MESSAGE() AS Duration
63 | , 1 AS StartTime
64 | , 1 AS EndTime
65 | , 1 AS ChangeInSize
66 | END CATCH
67 | END
68 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/CurrentlyExecutingSQLAgentJobs.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Taken from this post: http://sqlconcept.com/2011/06/25/how-to-query-currently-running-sql-server-agent-jobs/
3 | I'm afraid I don't know whoo wrote it.
4 | */
5 | CREATE PROCEDURE [jt].[CurrentlyExecutingSQLAgentJobs]
6 | AS
7 | BEGIN
8 | DECLARE @t TABLE-- [tempdb].[dbo].[Temp1]
9 | (
10 | job_id UNIQUEIDENTIFIER NOT NULL
11 | ,last_run_date NVARCHAR(20) NOT NULL
12 | ,last_run_time NVARCHAR(20) NOT NULL
13 | ,next_run_date NVARCHAR(20) NOT NULL
14 | ,next_run_time NVARCHAR(20) NOT NULL
15 | ,next_run_schedule_id INT NOT NULL
16 | ,requested_to_run INT NOT NULL
17 | ,request_source INT NOT NULL
18 | ,request_source_id SYSNAME COLLATE database_default
19 | NULL
20 | ,running INT NOT NULL
21 | ,current_step INT NOT NULL
22 | ,current_retry_attempt INT NOT NULL
23 | ,job_state INT NOT NULL
24 | )
25 | DECLARE @job_owner SYSNAME
26 | DECLARE @is_sysadmin INT
27 | SET @is_sysadmin = ISNULL(IS_SRVROLEMEMBER('sysadmin'), 0)
28 | SET @job_owner = SUSER_SNAME()
29 | INSERT INTO @t
30 |
31 | --EXECUTE sys.xp_sqlagent_enum_jobs @is_sysadmin, @job_owner
32 | EXECUTE master.dbo.xp_sqlagent_enum_jobs @is_sysadmin, @job_owner
33 | UPDATE @t
34 | SET last_run_time = RIGHT('000000' + last_run_time, 6)
35 | , next_run_time = RIGHT('000000' + next_run_time, 6);
36 | -----
37 | SELECT j.name AS JobName
38 | , j.enabled AS Enabled
39 | , CASE x.running
40 | WHEN 1 THEN 'Running'
41 | ELSE CASE h.run_status
42 | WHEN 2 THEN 'Inactive'
43 | WHEN 4 THEN 'Inactive'
44 | ELSE 'Completed'
45 | END
46 | END AS CurrentStatus
47 | , COALESCE(x.current_step, 0) AS CurrentStepNbr
48 | , CASE WHEN x.last_run_date > 0 THEN CONVERT (DATETIME, SUBSTRING(x.last_run_date, 1, 4) + '-' + SUBSTRING(x.last_run_date, 5, 2) + '-' + SUBSTRING(x.last_run_date, 7, 2) + ' ' + SUBSTRING(x.last_run_time, 1, 2) + ':' + SUBSTRING(x.last_run_time, 3, 2) + ':' + SUBSTRING(x.last_run_time, 5, 2) + '.000', 121)
49 | ELSE NULL
50 | END AS LastRunTime
51 | , CASE h.run_status
52 | WHEN 0 THEN 'Fail'
53 | WHEN 1 THEN 'Success'
54 | WHEN 2 THEN 'Retry'
55 | WHEN 3 THEN 'Cancel'
56 | WHEN 4 THEN 'In progress'
57 | END AS LastRunOutcome
58 | , CASE WHEN h.run_duration > 0 THEN ( h.run_duration / 1000000 ) * ( 3600 * 24 ) + ( h.run_duration / 10000 % 100 ) * 3600 + ( h.run_duration / 100 % 100 ) * 60 + ( h.run_duration % 100 )
59 | ELSE NULL
60 | END AS LastRunDuration
61 | FROM @t x
62 | LEFT JOIN msdb.dbo.sysjobs j
63 | ON x.job_id = j.job_id
64 | LEFT OUTER JOIN msdb.dbo.syscategories c
65 | ON j.category_id = c.category_id
66 | LEFT OUTER JOIN msdb.dbo.sysjobhistory h
67 | ON x.job_id = h.job_id
68 | AND x.last_run_date = h.run_date
69 | AND x.last_run_time = h.run_time
70 | AND h.step_id = 0
71 | WHERE x.running = 1
72 | END
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/DeadlockGraphShredder.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [jt].[DeadlockGraphShredder]
2 | AS
3 | BEGIN
4 | IF OBJECT_ID('tempdb..#rawDeadlockGraph') IS NOT NULL
5 | DROP TABLE #rawDeadlockGraph;
6 | SELECT CAST (XEventData.XEvent.value('(data/value)[1]', 'varchar(max)') AS XML) AS DeadlockGraph
7 | INTO #rawDeadlockGraph
8 | FROM (
9 | SELECT CAST (target_data AS XML) AS TargetData
10 | , *
11 | FROM sys.dm_xe_session_targets st
12 | JOIN sys.dm_xe_sessions s
13 | ON s.address = st.event_session_address
14 | WHERE s.[name] = 'system_health'
15 | ) AS Data
16 | CROSS APPLY TargetData.nodes('//RingBufferTarget/event') AS XEventData ( XEvent )
17 | WHERE XEventData.XEvent.value('@name', 'varchar(4000)') = 'xml_deadlock_report';
18 | IF OBJECT_ID('tempdb..#deadlockgraphCTE') IS NOT NULL
19 | DROP TABLE #deadlockgraphCTE;
20 | SELECT q.DeadlockGraph
21 | , q.[starttime]
22 | , [DeadLockID] = ROW_NUMBER() OVER ( ORDER BY q.[starttime] ASC )
23 | INTO #deadlockgraphCTE
24 | FROM (
25 | SELECT q.DeadlockGraph
26 | , [starttime] = q.DeadlockGraph.value('/deadlock[1]/process-list[1]/process[1]/@lasttranstarted[1]', 'varchar(max)')
27 | FROM #rawDeadlockGraph q
28 | ) q;
29 | IF OBJECT_ID('tempdb..#victimListCTE') IS NOT NULL
30 | DROP TABLE #victimListCTE;
31 | SELECT [victimProcessid] = q.DeadlockGraph.value('/deadlock[1]/victim-list[1]/victimProcess[1]/@id[1]', 'varchar(max)')
32 | , [DeadLockID]
33 | INTO #victimListCTE
34 | FROM #deadlockgraphCTE q;
35 | IF OBJECT_ID('tempdb..#processesCTE') IS NOT NULL
36 | DROP TABLE #processesCTE;
37 | SELECT [DeadLockID]
38 | , [starttime]
39 | , [processA_processid] = XEventData.XEvent.value('process-list[1]/process[1]/@id', 'varchar(max)')
40 | , [processB_processid] = XEventData.XEvent.value('process-list[1]/process[2]/@id', 'varchar(max)')
41 | INTO #processesCTE
42 | FROM #deadlockgraphCTE
43 | CROSS APPLY DeadLockGraph.nodes('/deadlock') AS XEventData ( XEvent );
44 | IF OBJECT_ID('tempdb..#resourceList') IS NOT NULL
45 | DROP TABLE #resourceList;
46 | SELECT [resource-list] = c.Deadlockgraph.query('//resource-list')
47 | , DeadLockID
48 | INTO #resourceList
49 | FROM #deadlockgraphCTE c
50 | SELECT q.[DeadLockID]
51 | , [IsVictim] = CASE WHEN vlCTE.[victimProcessid] IS NOT NULL THEN ' *'
52 | END
53 | , [processid]
54 | , [inputbuf] = CONVERT(XML, [inputbuf])
55 | , [statementtext(all execution stack)] = CONVERT(XML, [statementtext])
56 | --, [querytext(if still in cache)] = CONVERT(XML, [querytext])
57 | , [querytext(if still in cache)] = [querytext]
58 | , [query_plan(if still in cache)] = [query_plan]
59 | , logused
60 | , [lockmode]
61 | , [currentdbname]
62 | , [isolationlevel]
63 | , [spid]
64 | , [lasttranstarted]
65 | , [lastbatchstarted]
66 | , [lastbatchcompleted]
67 | , [waitresource]
68 | , [waitobject] = CASE WHEN LEFT([waitresource], 6) = 'OBJECT' THEN ISNULL((
69 | SELECT OBJECT_NAME(SUBSTRING(DBandOBJ, CHARINDEX(':', DBandOBJ) + 1, LEN(DBandOBJ)), SUBSTRING(DBandOBJ, 1, CHARINDEX(':', DBandOBJ) - 1))
70 | FROM (
71 | SELECT DBandOBJ = REVERSE(SUBSTRING(REVERSE(REPLACE(RTRIM(LTRIM(waitresource)), 'OBJECT: ', '')), 3, LEN(RTRIM(LTRIM(waitresource)))))
72 | ) q
73 | ), '')
74 | WHEN LEFT([waitresource], 3) = 'KEY' THEN (
75 | SELECT ISNULL(OBJECT_NAME([object_id], [currentdb]), '')
76 | FROM sys.partitions p
77 | INNER JOIN (
78 | SELECT hobt_id = SUBSTRING(DBandOBJ, CHARINDEX(':', DBandOBJ) + 1, CHARINDEX(' ', DBandOBJ) - CHARINDEX(':', DBandOBJ))
79 | FROM (
80 | SELECT DBandOBJ = REPLACE(RTRIM(LTRIM(waitresource)), 'KEY: ', '')
81 | ) q
82 | ) hobt
83 | ON p.hobt_id = hobt.hobt_id
84 | )
85 | WHEN LEFT([waitresource], 8) = 'METADATA'
86 | AND CHARINDEX('PARTITION_FUNCTION', [waitresource]) > 0 THEN ( ISNULL((
87 | SELECT ISNULL(pf.[name], '')
88 | FROM sys.partition_functions pf
89 | INNER JOIN (
90 | SELECT function_id = SUBSTRING(DBandOBJ, CHARINDEX('=', DBandOBJ, CHARINDEX('=', DBandOBJ) + 1) + 2, 5)
91 | FROM (
92 | SELECT DBandOBJ = REPLACE(RTRIM(LTRIM(waitresource)), 'METADATA: ', '')
93 | ) q
94 | ) q
95 | ON pf.[function_id] = q.[function_id]
96 | ), '') )
97 | WHEN LEFT([waitresource], 8) = 'METADATA'
98 | AND CHARINDEX('DATA_SPACE', [waitresource]) > 0 THEN ( ISNULL((
99 | SELECT ds.[name]
100 | FROM sys.data_spaces ds
101 | INNER JOIN (
102 | SELECT [data_space_id] = SUBSTRING(DBandOBJ, CHARINDEX('=', DBandOBJ, CHARINDEX('=', DBandOBJ) + 1) + 2, 5)
103 | FROM (
104 | SELECT DBandOBJ = REPLACE(RTRIM(LTRIM(waitresource)), 'METADATA: ', '')
105 | ) q
106 | ) q
107 | ON ds.[data_space_id] = q.[data_space_id]
108 | ), '') )
109 | END
110 | FROM (
111 | SELECT processAexecutionStack.[DeadLockID]
112 | , [ProcessID] = processAexecutionStack.[processid]
113 | , [inputbuf] = processAexecutionStack.[inputbuf]
114 | , [statementtext] = processAexecutionStack.[statementtext]
115 | , [querytext] = processAexecutionStack.[querytext]
116 | , [query_plan] = processAexecutionStack.[query_plan]
117 | , logused
118 | , [lockmode]
119 | , [currentdb]
120 | , [currentdbname]
121 | , [isolationlevel]
122 | , [spid]
123 | , [waitresource]
124 | , [lasttranstarted]
125 | , [lastbatchstarted]
126 | , [lastbatchcompleted]
127 | FROM #processesCTE processes
128 | INNER JOIN (
129 | SELECT executionStack.DeadLockID
130 | , [statementtext] = SUBSTRING(est.text, ( [stmtstart] / 2 ) + 1, ( ( CASE [stmtend]
131 | WHEN -1 THEN DATALENGTH(est.text)
132 | ELSE [stmtend]
133 | END - [stmtstart] ) / 2 ) + 1)
134 | , [querytext] = est.text
135 | , ecp.[query_plan]
136 | , executionStack.[processid]
137 | , executionStack.[inputbuf]
138 | , executionStack.[logused]
139 | , [lockmode]
140 | , [currentdb]
141 | , [currentdbname]
142 | , [isolationlevel]
143 | , [spid]
144 | , [waitresource]
145 | , [lasttranstarted]
146 | , [lastbatchstarted]
147 | , [lastbatchcompleted]
148 | FROM (
149 | SELECT deadlockgraphCTE.[DeadLockID]
150 | , [line] = XEventData.XEvent.value('@line[1]', 'int')
151 | , [stmtstart] = XEventData.XEvent.value('@stmtstart[1]', 'int')
152 | , [stmtend] = XEventData.XEvent.value('@stmtend[1]', 'int')
153 | , [sqlhandle] = CONVERT(VARBINARY(64), XEventData.XEvent.value('@sqlhandle[1]', 'nvarchar(max)'), 1)
154 | , [processid] = XEventData2.XEvent.value('process-list[1]/process[1]/@id', 'nvarchar(max)')
155 | , [inputbuf] = XEventData2.XEvent.value('process-list[1]/process[1]/inputbuf[1]', 'nvarchar(max)')
156 | , [logused] = XEventData2.XEvent.value('process-list[1]/process[1]/@logused[1]', 'int')
157 | , [lockmode] = XEventData2.XEvent.value('process-list[1]/process[1]/@lockMode[1]', 'nvarchar(max)')
158 | , [currentdb] = XEventData2.XEvent.value('process-list[1]/process[1]/@currentdb[1]', 'int')
159 | , [currentdbname] = DB_NAME(XEventData2.XEvent.value('process-list[1]/process[1]/@currentdb[1]', 'int'))
160 | , [isolationlevel] = XEventData2.XEvent.value('process-list[1]/process[1]/@isolationlevel[1]', 'nvarchar(max)')
161 | , [spid] = XEventData2.XEvent.value('process-list[1]/process[1]/@spid[1]', 'int')
162 | , [waitresource] = XEventData2.XEvent.value('process-list[1]/process[1]/@waitresource[1]', 'nvarchar(max)')
163 | , [lasttranstarted] = XEventData2.XEvent.value('process-list[1]/process[1]/@lasttranstarted[1]', 'nvarchar(max)')
164 | , [lastbatchstarted] = XEventData2.XEvent.value('process-list[1]/process[1]/@lastbatchstarted[1]', 'nvarchar(max)')
165 | , [lastbatchcompleted] = XEventData2.XEvent.value('process-list[1]/process[1]/@lastbatchcompleted[1]', 'nvarchar(max)')
166 | FROM #deadlockgraphCTE deadlockgraphCTE
167 | CROSS APPLY DeadLockGraph.nodes('/deadlock/process-list[1]/process[1]/executionStack/frame') AS XEventData ( XEvent )
168 | CROSS APPLY DeadLockGraph.nodes('/deadlock') AS XEventData2 ( XEvent )
169 | ) executionStack
170 | LEFT OUTER JOIN sys.dm_exec_query_stats eqs
171 | ON executionStack.[sqlhandle] = eqs.[sql_handle]
172 | OUTER APPLY sys.dm_exec_sql_text(executionStack.[sqlhandle]) est
173 | OUTER APPLY sys.dm_exec_query_plan(eqs.[plan_handle]) ecp
174 | ) processAexecutionStack
175 | ON processes.[DeadLockID] = processAexecutionStack.[DeadLockID]
176 | UNION ALL
177 | SELECT processBexecutionStack.[DeadLockID]
178 | , [ProcessID] = processBexecutionStack.[processid]
179 | , [inputbuf] = processBexecutionStack.[inputbuf]
180 | , [statementtext] = processBexecutionStack.[statementtext]
181 | , [querytext] = processBexecutionStack.[querytext]
182 | , [query_plan] = processBexecutionStack.[query_plan]
183 | , logused
184 | , [lockmode]
185 | , [currentdb]
186 | , [currentdbname]
187 | , [isolationlevel]
188 | , [spid]
189 | , [waitresource]
190 | , [lasttranstarted]
191 | , [lastbatchstarted]
192 | , [lastbatchcompleted]
193 | FROM #processesCTE processes
194 | INNER JOIN (
195 | SELECT executionStack.DeadLockID
196 | , [statementtext] = SUBSTRING(est.text, ( [stmtstart] / 2 ) + 1, ( ( CASE [stmtend]
197 | WHEN -1 THEN DATALENGTH(est.text)
198 | ELSE [stmtend]
199 | END - [stmtstart] ) / 2 ) + 1)
200 | , [querytext] = est.text
201 | , ecp.[query_plan]
202 | , executionStack.[processid]
203 | , executionStack.[inputbuf]
204 | , executionStack.[logused]
205 | , [lockmode]
206 | , [currentdb]
207 | , [currentdbname]
208 | , [isolationlevel]
209 | , [spid]
210 | , [waitresource]
211 | , [lasttranstarted]
212 | , [lastbatchstarted]
213 | , [lastbatchcompleted]
214 | FROM (
215 | SELECT deadlockgraphCTE.[DeadLockID]
216 | , [line] = XEventData.XEvent.value('@line[1]', 'int')
217 | , [stmtstart] = XEventData.XEvent.value('@stmtstart[1]', 'int')
218 | , [stmtend] = XEventData.XEvent.value('@stmtend[1]', 'int')
219 | , [sqlhandle] = CONVERT(VARBINARY(64), XEventData.XEvent.value('@sqlhandle[1]', 'nvarchar(max)'), 1)
220 | , [processid] = XEventData2.XEvent.value('process-list[1]/process[2]/@id', 'nvarchar(max)')
221 | , [inputbuf] = XEventData2.XEvent.value('process-list[1]/process[2]/inputbuf[1]', 'nvarchar(max)')
222 | , [logused] = XEventData2.XEvent.value('process-list[1]/process[2]/@logused[1]', 'int')
223 | , [lockmode] = XEventData2.XEvent.value('process-list[1]/process[2]/@lockMode[1]', 'nvarchar(max)')
224 | , [currentdb] = XEventData2.XEvent.value('process-list[1]/process[2]/@currentdb[1]', 'int')
225 | , [currentdbname] = DB_NAME(XEventData2.XEvent.value('process-list[1]/process[2]/@currentdb[1]', 'int'))
226 | , [isolationlevel] = XEventData2.XEvent.value('process-list[1]/process[2]/@isolationlevel[1]', 'nvarchar(max)')
227 | , [spid] = XEventData2.XEvent.value('process-list[1]/process[2]/@spid[1]', 'int')
228 | , [waitresource] = XEventData2.XEvent.value('process-list[1]/process[2]/@waitresource[1]', 'nvarchar(max)')
229 | , [lasttranstarted] = XEventData2.XEvent.value('process-list[1]/process[2]/@lasttranstarted[1]', 'nvarchar(max)')
230 | , [lastbatchstarted] = XEventData2.XEvent.value('process-list[1]/process[2]/@lastbatchstarted[1]', 'nvarchar(max)')
231 | , [lastbatchcompleted] = XEventData2.XEvent.value('process-list[1]/process[2]/@lastbatchcompleted[1]', 'nvarchar(max)')
232 | FROM #deadlockgraphCTE deadlockgraphCTE
233 | CROSS APPLY DeadLockGraph.nodes('/deadlock/process-list[1]/process[2]/executionStack/frame') AS XEventData ( XEvent )
234 | CROSS APPLY DeadLockGraph.nodes('/deadlock') AS XEventData2 ( XEvent )
235 | ) executionStack
236 | LEFT OUTER JOIN sys.dm_exec_query_stats eqs
237 | ON executionStack.[sqlhandle] = eqs.[sql_handle]
238 | OUTER APPLY sys.dm_exec_sql_text(executionStack.[sqlhandle]) est
239 | OUTER APPLY sys.dm_exec_query_plan(eqs.[plan_handle]) ecp
240 | ) processBexecutionStack
241 | ON processes.[DeadLockID] = processBexecutionStack.[DeadLockID]
242 | ) q
243 | LEFT OUTER JOIN #victimListCTE vlCTE
244 | ON q.[ProcessID] = vlCTE.[victimProcessid]
245 | AND q.[DeadLockID] = vlCTE.[DeadLockID]
246 | ORDER BY q.[DeadLockID] ASC
247 | , [IsVictim] DESC
248 | , [processid] ASC;
249 |
250 | SELECT q.[DeadLockID]
251 | , [lockobject] = CASE WHEN q.[locksubresource] = 'FULL' THEN ISNULL(OBJECT_NAME(q.[lockassociatedObjectId], q.[lockdbid]), '')
252 | WHEN q.[locksubresource] = 'PARTITION_FUNCTION' THEN ISNULL((
253 | SELECT ISNULL(pf.[name], '')
254 | FROM sys.partition_functions pf
255 | WHERE [function_id] = SUBSTRING(q.[lockclassid], CHARINDEX('=', q.[lockclassid]) + 2, LEN(q.[lockclassid]))
256 | ), '')
257 | WHEN q.[locksubresource] = 'DATA_SPACE' THEN ISNULL((
258 | SELECT ds.[name]
259 | FROM sys.data_spaces ds
260 | WHERE [data_space_id] = SUBSTRING(q.[lockclassid], CHARINDEX('=', q.[lockclassid]) + 2, LEN(q.[lockclassid]))
261 | ), '')
262 | END
263 | , q.[lockType]
264 | , q.[lockmode]
265 | --, q.[lockid]
266 | --, q.[lockobjectname]
267 | --, q.[lockassociatedObjectId]
268 | --, q.[lockPartition]
269 | , q.[locksubresource]
270 | --, q.[lockclassid]
271 | , q.[lockdbname]
272 | , q.[ownerid]
273 | , q.[ownermode]
274 | , q.[waiterid]
275 | , q.[waitermode]
276 | , q.[waiterrequestType]
277 | FROM (
278 | SELECT deadlockgraphCTE.[DeadLockID]
279 | , [data] = Resources._Resource.query('.')
280 | , [lockType] = Resources._Resource.value('local-name(.)', 'nvarchar(max)')
281 | , [lockmode] = Resources._Resource.value('@mode', 'nvarchar(max)')
282 | , [lockid] = Resources._Resource.value('@id', 'nvarchar(max)')
283 | , [lockobjectname] = Resources._Resource.value('@objectname', 'nvarchar(max)')
284 | , [lockassociatedObjectId] = Resources._Resource.value('@associatedObjectId', 'nvarchar(max)')
285 | , [lockPartition] = Resources._Resource.value('@lockPartition', 'nvarchar(max)')
286 | , [locksubresource] = Resources._Resource.value('@subresource', 'nvarchar(max)')
287 | , [lockclassid] = Resources._Resource.value('@classid', 'nvarchar(max)')
288 | , [lockdbid] = Resources._Resource.value('@dbid', 'int')
289 | , [lockdbname] = DB_NAME(Resources._Resource.value('@dbid', 'int'))
290 | , [ownerid] = OwnerList._Owner.value('@id', 'nvarchar(max)')
291 | , [ownermode] = OwnerList._Owner.value('@mode', 'nvarchar(max)')
292 | , [waiterid] = WaiterList._Waiter.value('@id', 'nvarchar(max)')
293 | , [waitermode] = WaiterList._Waiter.value('@mode', 'nvarchar(max)')
294 | , [waiterrequestType] = WaiterList._Waiter.value('@requestType', 'nvarchar(max)')
295 | FROM #deadlockgraphCTE deadlockgraphCTE
296 | CROSS APPLY DeadLockGraph.nodes('//resource-list/*') AS Resources ( _Resource )
297 | CROSS APPLY Resources._Resource.nodes('owner-list/owner') AS OwnerList ( _Owner )
298 | CROSS APPLY Resources._Resource.nodes('waiter-list/waiter') AS WaiterList ( _Waiter )
299 | ) q
300 |
301 | /*
302 | understanding waitresource
303 | http://support.microsoft.com/kb/224453/en-gb
304 | OBJECT: 7:34099162:0
305 | KEY: 7:281474978938880 (f986588b1ade)
306 | */
307 | END
308 |
309 | GO
310 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='DeadlockGraphShredder',@level1type='PROCEDURE',@name='CodeLibraryDescription',@value='Shreds all deadlock XML graphs found in the XEvents ring buffer';
311 |
312 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/GetIoVirtualFileStatsDeltas.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE jt.GetIoVirtualFileStatsDeltas
2 | @dbname SYSNAME = NULL
3 | , @filename SYSNAME = NULL
4 | , @inMostRecentXms INT = NULL
5 | AS
6 | BEGIN
7 | DECLARE @MaxSamplems INT;
8 | IF NOT EXISTS ( SELECT *
9 | FROM tempdb.sys.tables
10 | WHERE name = 'VirtualFileStats' )
11 | CREATE TABLE tempdb..[VirtualFileStats]
12 | (
13 | [database_id] [smallint] NOT NULL
14 | ,[file_id] [smallint] NOT NULL
15 | ,[sample_ms] [int] NOT NULL
16 | ,[num_of_reads] [bigint] NOT NULL
17 | ,[num_of_bytes_read] [bigint] NOT NULL
18 | ,[io_stall_read_ms] [bigint] NOT NULL
19 | ,[num_of_writes] [bigint] NOT NULL
20 | ,[num_of_bytes_written] [bigint] NOT NULL
21 | ,[io_stall_write_ms] [bigint] NOT NULL
22 | ,[io_stall] [bigint] NOT NULL
23 | ,[size_on_disk_bytes] [bigint] NOT NULL
24 | ,[file_handle] [varbinary](8) NOT NULL
25 | ,CaptureTimestamp DATETIME
26 | )
27 | INSERT tempdb.dbo.VirtualFileStats
28 | (
29 | database_id
30 | ,file_id
31 | ,sample_ms
32 | ,num_of_reads
33 | ,num_of_bytes_read
34 | ,io_stall_read_ms
35 | ,num_of_writes
36 | ,num_of_bytes_written
37 | ,io_stall_write_ms
38 | ,io_stall
39 | ,size_on_disk_bytes
40 | ,file_handle
41 | ,CaptureTimestamp
42 | )
43 | SELECT database_id
44 | , file_id
45 | , sample_ms
46 | , num_of_reads
47 | , num_of_bytes_read
48 | , io_stall_read_ms
49 | , num_of_writes
50 | , num_of_bytes_written
51 | , io_stall_write_ms
52 | , io_stall
53 | , size_on_disk_bytes
54 | , file_handle
55 | , SYSDATETIME()
56 | FROM sys.dm_io_virtual_file_stats(DEFAULT, DEFAULT)
57 | SET @MaxSamplems = (
58 | SELECT MAX(sample_ms)
59 | FROM tempdb.dbo.VirtualFileStats
60 | );
61 | SELECT vfs1.database_id
62 | , vfs1.file_id
63 | , vfs1.sample_ms
64 | , sample_ms_delta = vfs1.[sample_ms] - vfs2.[sample_ms]
65 | , [num_of_reads] = vfs1.[num_of_reads] - vfs2.[num_of_reads]
66 | , [num_of_bytes_read] = vfs1.[num_of_bytes_read] - vfs2.[num_of_bytes_read]
67 | , [io_stall_read_ms] = vfs1.[io_stall_read_ms] - vfs2.[io_stall_read_ms]
68 | , [num_of_writes] = vfs1.[num_of_writes] - vfs2.[num_of_writes]
69 | , [num_of_bytes_written] = vfs1.[num_of_bytes_written] - vfs2.[num_of_bytes_written]
70 | , [io_stall_write_ms] = vfs1.[io_stall_write_ms] - vfs2.[io_stall_write_ms]
71 | , [size_on_disk_bytes] = vfs1.[size_on_disk_bytes] - vfs2.[size_on_disk_bytes]
72 | INTO #deltas
73 | FROM (
74 | SELECT vfs1.database_id
75 | , vfs1.file_id
76 | , vfs1.sample_ms
77 | , vfs1.num_of_reads
78 | , vfs1.num_of_bytes_read
79 | , vfs1.io_stall_read_ms
80 | , vfs1.num_of_writes
81 | , vfs1.num_of_bytes_written
82 | , vfs1.io_stall_write_ms
83 | , vfs1.io_stall
84 | , vfs1.size_on_disk_bytes
85 | , vfs1.file_handle
86 | , vfs1.CaptureTimestamp
87 | , MAXsample_ms = MAX(vfs2.[sample_ms])
88 | FROM tempdb.dbo.VirtualFileStats vfs1
89 | INNER JOIN sys.master_files mf
90 | ON vfs1.database_id = mf.[database_id]
91 | AND vfs1.[file_id] = mf.[file_id]
92 | INNER JOIN tempdb.dbo.VirtualFileStats vfs2
93 | ON vfs1.database_id = vfs2.database_id
94 | AND vfs1.file_id = vfs2.file_id
95 | AND vfs1.[sample_ms] > vfs2.[sample_ms]
96 | WHERE (
97 | @dbname IS NULL
98 | OR CHARINDEX(DB_NAME(vfs1.[database_id]), @dbname) > 0
99 | )
100 | AND (
101 | @filename IS NULL
102 | OR CHARINDEX(mf.name, @filename) > 0
103 | )
104 | AND (
105 | @inMostRecentXms IS NULL
106 | OR @MaxSamplems - vfs1.[sample_ms] <= @inMostRecentXms
107 | )
108 | GROUP BY vfs1.database_id
109 | , vfs1.file_id
110 | , vfs1.sample_ms
111 | , vfs1.num_of_reads
112 | , vfs1.num_of_bytes_read
113 | , vfs1.io_stall_read_ms
114 | , vfs1.num_of_writes
115 | , vfs1.num_of_bytes_written
116 | , vfs1.io_stall_write_ms
117 | , vfs1.io_stall
118 | , vfs1.size_on_disk_bytes
119 | , vfs1.file_handle
120 | , vfs1.CaptureTimestamp
121 | ) vfs1
122 | INNER JOIN tempdb.dbo.VirtualFileStats vfs2
123 | ON vfs1.[database_id] = vfs2.[database_id]
124 | AND vfs1.[file_id] = vfs2.[file_id]
125 | AND vfs1.[MAXsample_ms] = vfs2.[sample_ms];
126 |
127 |
128 |
129 |
130 | --SELECT DatabaseName=DB_NAME(d.database_id),filename=mf.name,*
131 | --FROM #deltas d
132 | --INNER JOIN sys.master_files mf
133 | -- ON d.[database_id] = mf.[database_id]
134 | -- AND d.[file_id] = mf.[file_id]
135 | --ORDER BY d.database_id,d.file_id,sample_ms ASC;
136 |
137 | SELECT DatabaseName = DB_NAME(d.database_id)
138 | , filename = mf.name
139 | , sample_ms_delta
140 | , AverageWaitTimePerRead_ms = io_stall_read_ms / NULLIF(num_of_reads, 0)
141 | , AverageWaitTimePerWrite_ms = io_stall_write_ms / NULLIF(num_of_writes, 0)
142 | FROM #deltas d
143 | INNER JOIN sys.master_files mf
144 | ON d.[database_id] = mf.[database_id]
145 | AND d.[file_id] = mf.[file_id]
146 | ORDER BY d.database_id
147 | , d.file_id
148 | , sample_ms ASC;
149 |
150 | END
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/GetPartitionRowTallies.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE jt.GetPartitionRowTallies
2 | @dbName SYSNAME = 'master'
3 | AS
4 | BEGIN
5 | DECLARE @sql NVARCHAR(MAX) = '
6 | SELECT t.name
7 | ,s.partition_number
8 | ,s.row_count
9 | FROM [@dbname].sys.dm_db_partition_stats AS s
10 | INNER JOIN [@dbname].sys.tables AS t ON t.[object_id] = s.[object_id]
11 | GROUP BY t.name
12 | ,s.partition_number
13 | ,s.row_count;
14 | ';
15 | SET @sql = REPLACE(@sql,'@dbName',@dbName)
16 | EXEC (@sql)
17 | END
18 |
19 | GO
20 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='GetPartitionRowTallies',@level1type='PROCEDURE',@name='CodeLibraryDescription',@value='Tally of rows per partition in a given database.';
21 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/GetTableRowTallies.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE jt.GetTableRowTallies
2 | @dbName SYSNAME = 'master'
3 | AS
4 | BEGIN
5 | CREATE TABLE #t (
6 | name sysname
7 | , partition_number int
8 | , row_count int
9 | );
10 | INSERT #t
11 | EXEC jt.GetPartitionRowTallies @dbName = @dbName;
12 | SELECT name,row_count = SUM(row_count)
13 | FROM #t
14 | GROUP BY name;
15 | END
16 |
17 | GO
18 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='GetTableRowTallies',@level1type='PROCEDURE',@name='CodeLibraryDescription',@value='Tally of rows per table in a given database.';
19 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/TableStats.sql:
--------------------------------------------------------------------------------
1 | CREATE PROC jt.TableStats
2 | @db_name sysname
3 | AS
4 | /*
5 | I wanted a way to return the number of rows for all tables in a database. The following did the job:
6 | exec sp_MSforeachtable 'select COUNT(*) from ?'
7 | but then I figured why not get lots more info while I'm at it. Hence, sp_tablestats.
8 | For every table in the database it returns:
9 | Table Name
10 | Rowcount
11 | Does it have a clustered index?
12 | Is the primary key clustered?
13 | Number of columns
14 | Number of unique, none-primary keys
15 | Number of none unique columns
16 |
17 | Use like so:
18 | exec sp_tablestats 'AdventureWorks'
19 |
20 | -Jamie Thomson
21 | jamie@jamie-thomson.net
22 | 2008-08-18
23 | */
24 |
25 | --DECLARE @db_name sysname;
26 | --SET @db_name = 'DeadlockDemo';
27 |
28 |
29 | SET NOCOUNT ON
30 | DECLARE @tables TABLE
31 | (
32 | tablename sysname
33 | , schemaname sysname
34 | )
35 | DECLARE @tableName sysname
36 | , @schemaname sysname
37 | , @hasCI BIT
38 | , @UK_none_PK TINYINT
39 | , @IsPKClustered BIT
40 | , @NoOfCols INT
41 | , @NoOfCompCols INT
42 | , @NumberOfNoneUniqueIndexes INT
43 | , @NoOfChecks INT;
44 | DECLARE @SQLString nvarchar(500);
45 | DECLARE @table_metrics TABLE
46 | (
47 | SchemaName sysname
48 | , TableName sysname
49 | , [RowCount] int
50 | , HasClusteredIndex bit
51 | , IsPKClustered bit
52 | , NumberOfUniqueNonePrimaryIndexes tinyint
53 | , NumberOfNoneUniqueIndexes tinyint
54 | , NumberOfColumns INT
55 | , NumberOfComputedColumns INT
56 | , NumberOfCheckConstraints INT
57 | )
58 |
59 | --Check valid DB
60 | IF NOT EXISTS (SELECT * FROM sys.databases where name = @db_name)
61 | BEGIN
62 | PRINT 'Database ' + @db_name + ' does not exist!';
63 | RETURN;
64 | END
65 |
66 | --Build list of tables to process
67 | DECLARE @tablesSQL NVARCHAR(500);
68 | SET @tablesSQL = '
69 | SELECT t.name as tablename, s.name as schemaname
70 | FROM ' + @db_name + '.sys.tables t
71 | INNER JOIN ' + @db_name + '.sys.schemas s
72 | ON t.schema_id = s.schema_id
73 | WHERE t.type = ''U''
74 | AND t.name <> ''sysdiagrams''
75 | ORDER BY 2,1';
76 | INSERT @tables
77 | EXEC sp_executesql @tablesSQL;
78 |
79 | DECLARE tables_curs CURSOR
80 | FOR SELECT tablename,schemaname
81 | FROM @tables
82 |
83 | OPEN tables_curs;
84 |
85 | FETCH NEXT FROM tables_curs INTO @tableName, @schemaname
86 |
87 | WHILE @@FETCH_STATUS = 0
88 | BEGIN
89 | DECLARE @ParmDefinition nvarchar(500);
90 | DECLARE @rowcount varchar(30);
91 | SET @rowcount = 0
92 |
93 | --How many rows?
94 | SET @SQLString = N'select @rowcountOUT = COUNT(*) from ' + @db_name + '.' + @schemaname + '.' + @tableName;
95 | SET @ParmDefinition = N'@rowcountOUT int OUTPUT';
96 | EXECUTE sp_executesql @SQLString, @ParmDefinition, @rowcountOUT = @rowcount OUTPUT;
97 |
98 | --Has Clustered index?
99 | SET @SQLString = N'
100 | select @hasCI_OUT = CASE WHEN COUNT(*) > 0 THEN 0 ELSE 1 END
101 | from ' + @db_name + '.sys.indexes i
102 | inner join ' + @db_name + '.sys.objects o
103 | on i.object_id = o.object_id
104 | inner join ' + @db_name + '.sys.schemas s
105 | on o.schema_id = s.schema_id
106 | where i.type = 0
107 | and o.Name = ''' + @tableName + '''
108 | and s.Name = ''' + @schemaname + '''';
109 | SET @ParmDefinition = N'@hasCI_OUT BIT OUTPUT';
110 | EXEC sp_executesql @SQLString, @ParmDefinition, @hasCI_OUT = @hasCI OUTPUT;
111 |
112 | --How many unique, none-primary indexes?
113 | SET @SQLString = N'
114 | select @UK_none_PK_OUT = COUNT(*)
115 | from ' + @db_name + '.sys.indexes i
116 | inner join ' + @db_name + '.sys.objects o
117 | on i.object_id = o.object_id
118 | inner join ' + @db_name + '.sys.schemas s
119 | on o.schema_id = s.schema_id
120 | where i.is_unique_constraint = 1
121 | and o.Name = ''' + @tableName + '''
122 | and s.Name = ''' + @schemaname + '''';
123 | SET @ParmDefinition = N'@UK_none_PK_OUT TINYINT OUTPUT';
124 | EXEC sp_executesql @SQLString, @ParmDefinition, @UK_none_PK_OUT = @UK_none_PK OUTPUT;
125 |
126 | --How many none unique indexes?
127 | SET @SQLString = N'
128 | select @none_UK_OUT = COUNT(*)
129 | from ' + @db_name + '.sys.indexes i
130 | inner join ' + @db_name + '.sys.objects o
131 | on i.object_id = o.object_id
132 | inner join ' + @db_name + '.sys.schemas s
133 | on o.schema_id = s.schema_id
134 | where i.is_unique_constraint = 0
135 | and i.is_primary_key = 0
136 | and o.Name = ''' + @tableName + '''
137 | and s.Name = ''' + @schemaname + '''';
138 | SET @ParmDefinition = N'@none_UK_OUT TINYINT OUTPUT';
139 | EXEC sp_executesql @SQLString, @ParmDefinition, @none_UK_OUT = @NumberOfNoneUniqueIndexes OUTPUT;
140 |
141 | --Is PK clustered?
142 | SET @SQLString = N'
143 | SELECT @IsPKClustered_OUT = CASE WHEN COUNT(*) = 1 THEN 1 ELSE 0 END
144 | FROM ' + @db_name + '.sys.indexes i
145 | inner join ' + @db_name + '.sys.objects o
146 | on i.object_id = o.object_id
147 | inner join ' + @db_name + '.sys.schemas s
148 | on o.schema_id = s.schema_id
149 | WHERE i.is_primary_key = 1
150 | AND i.type = 1
151 | AND o.Name = ''' + @tableName + '''
152 | and s.Name = ''' + @schemaname + '''';
153 | SET @ParmDefinition = N'@IsPKClustered_OUT BIT OUTPUT';
154 | EXEC sp_executesql @SQLString, @ParmDefinition, @IsPKClustered_OUT = @IsPKClustered OUTPUT;
155 |
156 |
157 | --Number of columns
158 | SET @SQLString = N'
159 | SELECT @NoOfColsOUT = COUNT(*)
160 | FROM ' + @db_name + '.sys.columns c
161 | inner join ' + @db_name + '.sys.objects o
162 | on c.object_id = o.object_id
163 | inner join ' + @db_name + '.sys.schemas s
164 | on o.schema_id = s.schema_id
165 | WHERE o.Name = ''' + @tableName + '''
166 | and s.Name = ''' + @schemaname + '''';
167 | SET @ParmDefinition = N'@NoOfColsOUT INT OUTPUT';
168 | EXEC sp_executesql @SQLString, @ParmDefinition, @NoOfColsOUT = @NoOfCols OUTPUT;
169 |
170 | --Number of computed columns
171 | SET @SQLString = N'
172 | SELECT @NoOfCompCols_OUT = COUNT(*)
173 | FROM ' + @db_name + '.sys.computed_columns c
174 | inner join ' + @db_name + '.sys.objects o
175 | on c.object_id = o.object_id
176 | inner join ' + @db_name + '.sys.schemas s
177 | on o.schema_id = s.schema_id
178 | WHERE o.Name = ''' + @tableName + '''
179 | and s.Name = ''' + @schemaname + '''';
180 | SET @ParmDefinition = N'@NoOfCompCols_OUT INT OUTPUT';
181 | EXEC sp_executesql @SQLString, @ParmDefinition, @NoOfCompCols_OUT = @NoOfCompCols OUTPUT;
182 |
183 | --Number of check constraints
184 | SET @SQLString = N'
185 | SELECT @NoOfChecks_OUT = COUNT(*)
186 | FROM ' + @db_name + '.sys.check_constraints c
187 | inner join ' + @db_name + '.sys.objects o
188 | on c.parent_object_id = o.object_id
189 | inner join ' + @db_name + '.sys.schemas s
190 | on o.schema_id = s.schema_id
191 | WHERE o.Name = ''' + @tableName + '''
192 | and s.Name = ''' + @schemaname + '''';
193 | SET @ParmDefinition = N'@NoOfChecks_OUT INT OUTPUT';
194 | EXEC sp_executesql @SQLString, @ParmDefinition, @NoOfChecks_OUT = @NoOfChecks OUTPUT;
195 |
196 | INSERT @table_metrics (SchemaName, TableName,[RowCount],HasClusteredIndex,NumberOfUniqueNonePrimaryIndexes,IsPKClustered, NumberOfColumns, NumberOfComputedColumns, NumberOfNoneUniqueIndexes, NumberOfCheckConstraints)
197 | VALUES (@schemaname, @tableName, @rowcount, @hasCI, @UK_none_PK, @IsPKClustered, @NoOfCols, @NoOfCompCols, @NumberOfNoneUniqueIndexes, @NoOfChecks);
198 | FETCH NEXT FROM tables_curs INTO @tableName, @schemaname;
199 | END
200 |
201 | CLOSE tables_curs;
202 | DEALLOCATE tables_curs;
203 |
204 | SELECT *
205 | FROM @table_metrics;
206 |
207 | ;
208 | GO
209 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='TableStats',@level1type='PROCEDURE',@name='CodeLibraryDescription',@value='Stats per table. Provides Rowcount, Does it have a clustered index?, Is the primary key clustered?, Number of columns, Number of unique, none-primary keys, Number of none unique columns';
210 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/WaitStatsAnalysis.sql:
--------------------------------------------------------------------------------
1 | CREATE PROCEDURE [jt].[WaitStatsAnalysis]
2 | @ResetWaitStats BIT = 0
3 | AS
4 | BEGIN
5 | PRINT 'Requires VIEW SERVER STATE';
6 | PRINT 'From Wait statistics, or please tell me where it hurts by Paul Randal http://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/';
7 | PRINT ' and';
8 | PRINT 'when were wait stats last cleared? by Erin Stellato http://www.sqlskills.com/blogs/erin/figuring-out-when-wait-stats-were-last-cleared';
9 | IF @ResetWaitStats = 1
10 | DBCC SQLPERF(N'sys.dm_os_wait_stats', CLEAR);
11 |
12 | /*Wait statistics, or please tell me where it hurts
13 | http://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/
14 | */
15 | WITH [Waits] AS
16 | (SELECT
17 | [wait_type],
18 | [wait_time_ms] / 1000.0 AS [WaitS],
19 | ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS],
20 | [signal_wait_time_ms] / 1000.0 AS [SignalS],
21 | [waiting_tasks_count] AS [WaitCount],
22 | 100.0 * [wait_time_ms] / SUM (NULLIF([wait_time_ms],0)) OVER() AS [Percentage],
23 | ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum]
24 | FROM sys.dm_os_wait_stats
25 | WHERE [wait_type] NOT IN (
26 | N'CLR_SEMAPHORE', N'LAZYWRITER_SLEEP',
27 | N'RESOURCE_QUEUE', N'SQLTRACE_BUFFER_FLUSH',
28 | N'SLEEP_TASK', N'SLEEP_SYSTEMTASK',
29 | N'WAITFOR', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION',
30 | N'CHECKPOINT_QUEUE', N'REQUEST_FOR_DEADLOCK_SEARCH',
31 | N'XE_TIMER_EVENT', N'XE_DISPATCHER_JOIN',
32 | N'LOGMGR_QUEUE', N'FT_IFTS_SCHEDULER_IDLE_WAIT',
33 | N'BROKER_TASK_STOP', N'CLR_MANUAL_EVENT',
34 | N'CLR_AUTO_EVENT', N'DISPATCHER_QUEUE_SEMAPHORE',
35 | N'TRACEWRITE', N'XE_DISPATCHER_WAIT',
36 | N'BROKER_TO_FLUSH', N'BROKER_EVENTHANDLER',
37 | N'FT_IFTSHC_MUTEX', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
38 | N'DIRTY_PAGE_POLL', N'SP_SERVER_DIAGNOSTICS_SLEEP')
39 | )
40 | SELECT
41 | [W1].[wait_type] AS [WaitType],
42 | CAST ([W1].[WaitS] AS DECIMAL(14, 2)) AS [Wait_S],
43 | CAST ([W1].[ResourceS] AS DECIMAL(14, 2)) AS [Resource_S],
44 | CAST ([W1].[SignalS] AS DECIMAL(14, 2)) AS [Signal_S],
45 | [W1].[WaitCount] AS [WaitCount],
46 | CAST ([W1].[Percentage] AS DECIMAL(4, 2)) AS [Percentage],
47 | CAST (([W1].[WaitS] / NULLIF([W1].[WaitCount],0)) AS DECIMAL (14, 4)) AS [AvgWait_S],
48 | CAST (([W1].[ResourceS] / NULLIF([W1].[WaitCount],0)) AS DECIMAL (14, 4)) AS [AvgRes_S],
49 | CAST (([W1].[SignalS] / NULLIF([W1].[WaitCount],0)) AS DECIMAL (14, 4)) AS [AvgSig_S]
50 | FROM [Waits] AS [W1]
51 | INNER JOIN [Waits] AS [W2]
52 | ON [W2].[RowNum] <= [W1].[RowNum]
53 | GROUP BY [W1].[RowNum], [W1].[wait_type], [W1].[WaitS],
54 | [W1].[ResourceS], [W1].[SignalS], [W1].[WaitCount], [W1].[Percentage]
55 | HAVING SUM ([W2].[Percentage]) - [W1].[Percentage] < 95; -- percentage threshold
56 |
57 |
58 | /* when were wait stats last cleared? from Erin Stellato http://www.sqlskills.com/blogs/erin/figuring-out-when-wait-stats-were-last-cleared/ */
59 | SELECT [wait_type],
60 | [wait_time_ms],
61 | DATEADD(ms,-[wait_time_ms],getdate()) AS [Date/TimeCleared],
62 | CASE
63 | WHEN [wait_time_ms] < 1000 THEN CAST([wait_time_ms] AS VARCHAR(15)) + ' ms'
64 | WHEN [wait_time_ms] between 1000 and 60000 THEN CAST(([wait_time_ms]/1000) AS VARCHAR(15)) + ' seconds'
65 | WHEN [wait_time_ms] between 60001 and 3600000 THEN CAST(([wait_time_ms]/60000) AS VARCHAR(15)) + ' minutes'
66 | WHEN [wait_time_ms] between 3600001 and 86400000 THEN CAST(([wait_time_ms]/3600000) AS VARCHAR(15)) + ' hours'
67 | WHEN [wait_time_ms] > 86400000 THEN CAST(([wait_time_ms]/86400000) AS VARCHAR(15)) + ' days'
68 | END [TimeSinceCleared]
69 | FROM [sys].[dm_os_wait_stats]
70 | WHERE [wait_type] = 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP';
71 |
72 | /* check SQL Server start time - 2008 and higher */
73 | SELECT [sqlserver_start_time]
74 | FROM [sys].[dm_os_sys_info];
75 | END
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Stored Procedures/tempdbStats.sql:
--------------------------------------------------------------------------------
1 | create proc jt.tempdbStats
2 | AS
3 | --from http://msdn.microsoft.com/en-us/library/ms176029.aspx
4 | --Determining the Amount of Free Space in tempdb
5 | SELECT SUM(unallocated_extent_page_count) AS [free pages],
6 | (SUM(unallocated_extent_page_count)*1.0/128) AS [free space in MB]
7 | FROM tempdb.sys.dm_db_file_space_usage;
8 | --Determining the Longest Running Transaction
9 | SELECT transaction_id as longest_running_transction_id
10 | FROM tempdb.sys.dm_tran_active_snapshot_database_transactions
11 | ORDER BY elapsed_time_seconds DESC;
12 | --Determining the Amount Space Used by the Version Store
13 | SELECT SUM(version_store_reserved_page_count) AS [version store pages used],
14 | (SUM(version_store_reserved_page_count)*1.0/128) AS [version store space in MB]
15 | FROM tempdb.sys.dm_db_file_space_usage;
16 | --Determining the Amount of Space Used by Internal Objects
17 | SELECT SUM(internal_object_reserved_page_count) AS [internal object pages used],
18 | (SUM(internal_object_reserved_page_count)*1.0/128) AS [internal object space in MB]
19 | FROM tempdb.sys.dm_db_file_space_usage;
20 | --Determining the Amount of Space Used by User Objects
21 | SELECT SUM(user_object_reserved_page_count) AS [user object pages used],
22 | (SUM(user_object_reserved_page_count)*1.0/128) AS [user object space in MB]
23 | FROM tempdb.sys.dm_db_file_space_usage;
24 | --Determining the Total Amount of Space (Free and Used)
25 | SELECT SUM(size)*1.0/128 AS [size in MB]
26 | FROM tempdb.sys.database_files
27 |
28 | GO
29 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='tempdbStats',@level1type='PROCEDURE',@name='CodeLibraryDescription',@value='Loads of useful information about tempdb.';
30 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/StatsLastUpdatedTime.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [jt].[StatsLastUpdatedTime]
2 | AS
3 | select OBJECT_NAME(s.object_id ) object
4 | ,s.name
5 | ,STATS_DATE(s.object_id ,s.stats_id) StatsDate
6 |
7 | ,s.auto_created
8 | ,s.filter_definition
9 | ,s.has_filter
10 | ,s.no_recompute
11 | ,s.user_created
12 | ,stuff((select ','+col.name
13 | from sys.stats_columns sc
14 | join sys.columns col on sc.column_id = col.column_id
15 | and sc.object_id = col.object_id
16 | where sc.stats_id = s.stats_id
17 | and sc.object_id = s.object_id
18 | for xml path ('')),1,1,'') cols
19 | from sys.stats s
20 | inner join sys.tables t
21 | on s.object_id = t.object_id
22 | where t.type = 'U'
23 | GO
24 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='StatsLastUpdatedTime',@level1type='VIEW',@name='CodeLibraryDescription',@value='When were stats last updated, per object.';
25 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/vwAllSessions.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW jt.vwAllSessions
2 | AS
3 | select s.session_id
4 | , s.login_time
5 | , s.host_name
6 | , s.login_name
7 | , s.status as session_status
8 | , r.status as request_status
9 | , s.cpu_time as session_cpu_time
10 | , s.reads as session_reads
11 | , s.writes as session_writes
12 | , s.logical_reads as session_logical_reads
13 | , c.num_reads as connection_num_reads
14 | , c.num_writes as connection_num_writes
15 | , c.last_read as connection_last_read
16 | , c.last_write as connection_last_write
17 | , r.request_id
18 | , r.command as request_command
19 | , r.open_transaction_count as request_open_transaction_count
20 | , r.open_resultset_count as request_open_resultset_count
21 | , r.total_elapsed_time as request_total_elapsed_time
22 | , r.row_count as request_row_count
23 | from sys.dm_exec_sessions s
24 | left outer join sys.dm_exec_connections c
25 | on c.session_id = s.session_id
26 | left outer join sys.dm_exec_requests r
27 | on r.session_id = s.session_id
28 | GO
29 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='vwAllSessions',@level1type='VIEW',@name='CodeLibraryDescription',@value='All current sessions, plus info from sys.dm_exec_requests';
30 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/vwBufferusagePerDB.sql:
--------------------------------------------------------------------------------
1 | create view jt.vwBufferUsagePerDB
2 | AS
3 | SELECT top 100 percent
4 | [DatabaseName],
5 | ISNULL([Dirty],'0') AS [Dirty],
6 | ISNULL([Clean],'0') AS [Clean],
7 | ISNULL([Total],'0') AS [Total]
8 | FROM(
9 | SELECT
10 | (CASE WHEN ([database_id] = 32767) THEN 'Resource Database'
11 | ELSE ISNULL(DB_NAME (database_id),'Total')
12 | END) AS 'DatabaseName',
13 | (CASE WHEN ([is_modified] = 1) THEN 'Dirty'
14 | WHEN ([is_modified] = 0) THEN 'Clean'
15 | ELSE 'Total'
16 | END) AS 'State',
17 | COUNT (*)/128 AS 'SizeInMB'
18 | FROM sys.dm_os_buffer_descriptors
19 | GROUP BY [database_id], [is_modified] WITH CUBE
20 | ) AS SourceTable
21 | PIVOT(SUM([SizeInMB]) FOR [State] IN (Clean, Dirty, Total)) AS PivotTable
22 | ORDER BY [DatabaseName]
23 | GO
24 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='vwBufferUsagePerDB',@level1type='VIEW',@name='CodeLibraryDescription',@value='Show buffer usage per database.';
25 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/vwCacheUsagePerTable.sql:
--------------------------------------------------------------------------------
1 | create view jt.vwCacheUsagePerTable
2 | AS
3 | /*
4 | Taken from a blog by Steve Hindmarsh at http://sqlblogcasts.com/blogs/steveh/archive/2010/04/02/dbcc-memusage-in-2008.aspx
5 |
6 | */
7 | WITH memusage_CTE AS (
8 | SELECT bd.database_id, bd.file_id, bd.page_id, bd.page_type
9 | , COALESCE(p1.object_id, p2.object_id) AS object_id
10 | , COALESCE(p1.index_id, p2.index_id) AS index_id
11 | , bd.row_count
12 | , bd.free_space_in_bytes
13 | , CONVERT(TINYINT,bd.is_modified) AS 'DirtyPage'
14 | FROM sys.dm_os_buffer_descriptors AS bd
15 | JOIN sys.allocation_units AS au
16 | ON au.allocation_unit_id = bd.allocation_unit_id
17 | OUTER APPLY (
18 | SELECT TOP(1) p.object_id, p.index_id
19 | FROM sys.partitions AS p
20 | WHERE p.hobt_id = au.container_id AND au.type IN (1, 3)
21 | ) AS p1
22 | OUTER APPLY (
23 | SELECT TOP(1) p.object_id, p.index_id
24 | FROM sys.partitions AS p
25 | WHERE p.partition_id = au.container_id AND au.type = 2
26 | ) AS p2
27 | WHERE bd.database_id = DB_ID()
28 | AND bd.page_type IN ('DATA_PAGE', 'INDEX_PAGE')
29 | )
30 | SELECT TOP 20 DB_NAME(database_id) AS 'Database'
31 | , OBJECT_NAME(object_id,database_id) AS 'Table Name'
32 | , index_id,COUNT(*) AS 'Pages in Cache'
33 | , SUM(DirtyPage) AS 'Dirty Pages'
34 | FROM memusage_CTE
35 | GROUP BY database_id, object_id, index_id
36 | ORDER BY COUNT(*) DESC
37 | GO
38 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='vwCacheUsagePerTable',@level1type='VIEW',@name='CodeLibraryDescription',@value='Show cache usage per table. Taken from a blog by Steve Hindmarsh at http://sqlblogcasts.com/blogs/steveh/archive/2010/04/02/dbcc-memusage-in-2008.aspx';
39 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/vwCodeLibraryDescriptions.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [jt].[vwCodeLibraryDescriptions]
2 | AS
3 | SELECT schema_name=object_schema_name(major_id)
4 | , object_name=object_name(major_id)
5 | , CodeLibraryDescription=value
6 | , object_type=o.type_desc
7 | FROM sys.extended_properties ep
8 | INNER JOIN sys.objects o
9 | ON ep.major_id = o.object_id
10 | WHERE ep.name = N'CodeLibraryDescription'
11 |
12 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/vwFastRowCounts.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW dbo.vwFastRowCounts
2 | AS
3 | SELECT schm.name+'.'+objt.name Reference
4 | ,SUM(row_count) [RowCount]
5 | FROM sys.dm_db_partition_stats stat
6 | JOIN sys.objects objt ON stat.object_id = objt.object_id
7 | JOIN sys.schemas schm ON objt.schema_id = schm.schema_id
8 | WHERE stat.index_id < 2 AND schm.name <> 'sys'
9 | GROUP BY schm.name+'.'+objt.name
10 | ;
11 |
--------------------------------------------------------------------------------
/TSQLCodeLibrary/jt/Views/vwdiskfileLatency.sql:
--------------------------------------------------------------------------------
1 | create view jt.vwdiskfileLatency
2 | AS
3 | /*
4 | Show disk file latency
5 |
6 | http://www.sqlskills.com/BLOGS/PAUL/category/IO-Subsystems.aspx
7 | */
8 |
9 |
10 | SELECT top 100 percent
11 | --virtual file latency
12 | ReadLatency = CASE WHEN num_of_reads = 0
13 | THEN 0 ELSE (io_stall_read_ms / num_of_reads) END,
14 | WriteLatency = CASE WHEN num_of_writes = 0
15 | THEN 0 ELSE (io_stall_write_ms / num_of_writes) END,
16 | Latency = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0)
17 | THEN 0 ELSE (io_stall / (num_of_reads + num_of_writes)) END,
18 | --avg bytes per IOP
19 | AvgBPerRead = CASE WHEN num_of_reads = 0
20 | THEN 0 ELSE (num_of_bytes_read / num_of_reads) END,
21 | AvgBPerWrite = CASE WHEN io_stall_write_ms = 0
22 | THEN 0 ELSE (num_of_bytes_written / num_of_writes) END,
23 | AvgBPerTransfer = CASE WHEN (num_of_reads = 0 AND num_of_writes = 0)
24 | THEN 0 ELSE ((num_of_bytes_read + num_of_bytes_written) /
25 | (num_of_reads + num_of_writes)) END,
26 | LEFT (mf.physical_name, 2) AS Drive,
27 | DB_NAME (vfs.database_id) AS DB,
28 | --vfs.*,
29 | mf.physical_name
30 | FROM sys.dm_io_virtual_file_stats (NULL,NULL) AS vfs
31 | JOIN sys.master_files AS mf
32 | ON vfs.database_id = mf.database_id
33 | AND vfs.file_id = mf.file_id
34 | --WHERE vfs.file_id = 2 -- log files
35 | -- ORDER BY Latency DESC
36 | -- ORDER BY ReadLatency DESC
37 | ORDER BY WriteLatency DESC;
38 |
39 | GO
40 | EXEC sp_addextendedproperty @level0name='jt',@level0type='SCHEMA',@level1name='vwdiskfileLatency',@level1type='VIEW',@name='CodeLibraryDescription',@value='Show disk file latency. Gotten from Paul Randal at http://www.sqlskills.com/BLOGS/PAUL/category/IO-Subsystems.aspx';
41 |
42 |
43 |
--------------------------------------------------------------------------------