├── .gitattributes
├── .gitignore
├── CODEOWNERS
├── CODE_OF_CONDUCT.md
├── Get-OpenSourceScripts.ps1
├── Install-LatestDbaDatabase.ps1
├── LICENSE
├── README.md
├── Types
├── dbo.ObjectNameList.sql
└── dbo.ObjectNameListWithDb.sql
├── create-database.sql
├── functions-scalar
├── dbo.AGDbRole_Get.sql
├── dbo.EmailCss_Get.sql
└── dbo.EmailServerInfo_Get.sql
├── functions-tvfs
├── dbo.AgentJobHistory_TimeConvert.sql
├── dbo.AgentJob_Status.sql
├── dbo.Convert_LSNFromHexToDecimal.sql
├── dbo.ParseFilePath.sql
├── dbo.ParseStatementByOffset.sql
└── dbo.fn_split.sql
├── stored-procedures
├── dbo.Alert_Blocking.sql
├── dbo.Check_AgLatency.sql
├── dbo.Check_Blocking.sql
├── dbo.Check_DriveSpace.sql
├── dbo.Check_FileSize.sql
├── dbo.Check_LogVLF.sql
├── dbo.Check_OpenTransactions.sql
├── dbo.Check_QueryStoreRegressedQueries.sql
├── dbo.Check_SessionLocking.sql
├── dbo.Check_TableUsage.sql
├── dbo.Cleanup_BackupHistory.sql
├── dbo.Cleanup_CommandLog.sql
├── dbo.Cleanup_Msdb.sql
├── dbo.Cleanup_TableByID.sql
├── dbo.Find_StringInModules.sql
├── dbo.Get_DetachAttachSql.sql
├── dbo.PlanGuide_SetHintForProcedureStatement.sql
├── dbo.Repl_AddAllTables.sql
├── dbo.Repl_AddArticle.sql
├── dbo.Repl_CreatePublication.sql
├── dbo.Repl_CreateSubscription.sql
├── dbo.Set_AGReadOnlyRouting.sql
├── dbo.Set_StatisticsNorecomputeByTable.sql
├── dbo.Views_RecompileAll.sql
└── dbo.sp_Get_BaseTableList.sql
├── tables
├── dbo.CommandLog.Indexes.sql
├── dbo.Config.sql
├── dbo.Monitor_Blocking.sql
├── dbo.Numbers.sql
└── dbo.TimeZones.sql
└── views
├── dbo.CmsGroups.sql
├── dbo.CmsServers.sql
├── dbo.DatabaseProperties.sql
├── dbo.ServerLoginPermissions.sql
├── dbo.ServerLogins.sql
├── dbo.ServerProperties.sql
└── dbo.TimeZoneDetailed.sql
/.gitattributes:
--------------------------------------------------------------------------------
1 | # linguist overrides
2 | *.cs linguist-language=C#
3 | *.ps1 linguist-language=Powershell
4 | *.psd1 linguist-language=Powershell
5 | *.psm1 linguist-language=Powershell
6 | *.R linguist-language=R
7 | *.sql linguist-language=TSQL
8 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | # Ignore open source stuff. I'm not redistributing this stuff, so you'll need to grab it yourself.
2 | oss/
3 | *.json
4 |
--------------------------------------------------------------------------------
/CODEOWNERS:
--------------------------------------------------------------------------------
1 | # Andy is the code owner for everything in the repo. ¯\_(ツ)_/¯
2 | # Maybe we'll get a contributor that can join the team eventually. (☞゚ヮ゚)☞
3 | * @amtwo
4 |
--------------------------------------------------------------------------------
/CODE_OF_CONDUCT.md:
--------------------------------------------------------------------------------
1 | # Contributor Covenant Code of Conduct
2 |
3 | ## Our Pledge
4 |
5 | In the interest of fostering an open and welcoming environment, we as contributors and maintainers pledge to making participation in our project and our community a harassment-free experience for everyone, regardless of age, body size, disability, ethnicity, gender identity and expression, level of experience, nationality, personal appearance, race, religion, or sexual identity and orientation.
6 |
7 | ## Our Standards
8 |
9 | Examples of behavior that contributes to creating a positive environment include:
10 |
11 | * Using welcoming and inclusive language
12 | * Being respectful of differing viewpoints and experiences
13 | * Gracefully accepting constructive criticism
14 | * Focusing on what is best for the community
15 | * Showing empathy towards other community members
16 |
17 | Examples of unacceptable behavior by participants include:
18 |
19 | * The use of sexualized language or imagery and unwelcome sexual attention or advances
20 | * Trolling, insulting/derogatory comments, and personal or political attacks
21 | * Public or private harassment
22 | * Publishing others' private information, such as a physical or electronic address, without explicit permission
23 | * Other conduct which could reasonably be considered inappropriate in a professional setting
24 |
25 | ## Our Responsibilities
26 |
27 | Project maintainers are responsible for clarifying the standards of acceptable behavior and are expected to take appropriate and fair corrective action in response to any instances of unacceptable behavior.
28 |
29 | Project maintainers have the right and responsibility to remove, edit, or reject comments, commits, code, wiki edits, issues, and other contributions that are not aligned to this Code of Conduct, or to ban temporarily or permanently any contributor for other behaviors that they deem inappropriate, threatening, offensive, or harmful.
30 |
31 | ## Scope
32 |
33 | This Code of Conduct applies both within project spaces and in public spaces when an individual is representing the project or its community. Examples of representing a project or community include using an official project e-mail address, posting via an official social media account, or acting as an appointed representative at an online or offline event. Representation of a project may be further defined and clarified by project maintainers.
34 |
35 | ## Enforcement
36 |
37 | Instances of abusive, harassing, or otherwise unacceptable behavior may be reported by contacting the project team at andy@am2.co. The project team will review and investigate all complaints, and will respond in a way that it deems appropriate to the circumstances. The project team is obligated to maintain confidentiality with regard to the reporter of an incident. Further details of specific enforcement policies may be posted separately.
38 |
39 | Project maintainers who do not follow or enforce the Code of Conduct in good faith may face temporary or permanent repercussions as determined by other members of the project's leadership.
40 |
41 | ## Attribution
42 |
43 | This Code of Conduct is adapted from the [Contributor Covenant][homepage], version 1.4, available at [http://contributor-covenant.org/version/1/4][version]
44 |
45 | [homepage]: http://contributor-covenant.org
46 | [version]: http://contributor-covenant.org/version/1/4/
47 |
--------------------------------------------------------------------------------
/Get-OpenSourceScripts.ps1:
--------------------------------------------------------------------------------
1 | # Output directory
2 | $dir = Get-Location
3 |
4 | # Ola Hallengren's maintenance scripts
5 | New-Item -Path "$($dir)\oss\olahallengren" -ItemType Directory -Force |Out-Null
6 | $url = "https://raw.githubusercontent.com/olahallengren/sql-server-maintenance-solution/master"
7 | Invoke-WebRequest -Uri "$($url)/CommandExecute.sql" -OutFile "$($dir)\oss\olahallengren\CommandExecute.sql"
8 | Invoke-WebRequest -Uri "$($url)/CommandLog.sql" -OutFile "$($dir)\oss\olahallengren\CommandLog.sql"
9 | Invoke-WebRequest -Uri "$($url)/DatabaseBackup.sql" -OutFile "$($dir)\oss\olahallengren\DatabaseBackup.sql"
10 | Invoke-WebRequest -Uri "$($url)/DatabaseIntegrityCheck.sql" -OutFile "$($dir)\oss\olahallengren\DatabaseIntegrityCheck.sql"
11 | Invoke-WebRequest -Uri "$($url)/IndexOptimize.sql" -OutFile "$($dir)\oss\olahallengren\IndexOptimize.sql"
12 |
13 | # First Responder Kit
14 | New-Item -Path "$($dir)\oss\firstresponderkit" -ItemType Directory -Force |Out-Null
15 | $url = "https://raw.githubusercontent.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/master"
16 | Invoke-WebRequest -Uri "$($url)/sp_Blitz.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_Blitz.sql"
17 | Invoke-WebRequest -Uri "$($url)/sp_BlitzBackups.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzBackups.sql"
18 | Invoke-WebRequest -Uri "$($url)/sp_BlitzCache.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzCache.sql"
19 | Invoke-WebRequest -Uri "$($url)/sp_BlitzFirst.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzFirst.sql"
20 | Invoke-WebRequest -Uri "$($url)/sp_BlitzIndex.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzIndex.sql"
21 | Invoke-WebRequest -Uri "$($url)/sp_BlitzLock.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzLock.sql"
22 | #This throws errors when I try to deploy it to <2016 servers. Pulling it for now--will revisit later.
23 | #Invoke-WebRequest -Uri "$($url)/sp_BlitzQueryStore.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzQueryStore.sql"
24 | Invoke-WebRequest -Uri "$($url)/sp_BlitzWho.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_BlitzWho.sql"
25 | Invoke-WebRequest -Uri "$($url)/sp_ineachdb.sql" -OutFile "$($dir)\oss\firstresponderkit\sp_ineachdb.sql"
26 |
27 | # sp_WhoIsActive
28 | New-Item -Path "$($dir)\oss\whoisactive" -ItemType Directory -Force |Out-Null
29 | $url = "https://raw.githubusercontent.com/amachanic/sp_whoisactive/master"
30 | Invoke-WebRequest -Uri "$($url)/who_is_active.sql" -OutFile "$($dir)\oss\whoisactive\who_is_active.sql"
31 |
32 |
33 | # Darling Data Troubleshooting scripts
34 | New-Item -Path "$($dir)\oss\darlingdata" -ItemType Directory -Force |Out-Null
35 | $url = "https://raw.githubusercontent.com/erikdarlingdata/DarlingData/master"
36 | Invoke-WebRequest -Uri "$($url)/sp_PressureDetector/sp_PressureDetector.sql" -OutFile "$($dir)\oss\darlingdata\sp_PressureDetector.sql"
37 | Invoke-WebRequest -Uri "$($url)/sp_HumanEvents/sp_HumanEvents.sql" -OutFile "$($dir)\oss\darlingdata\sp_HumanEvents.sql"
38 |
39 |
--------------------------------------------------------------------------------
/Install-LatestDbaDatabase.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | .SYNOPSIS
3 | Installs or updates DBA database to the latest version
4 |
5 | .DESCRIPTION
6 | This function will create a DBA database if it does not already exist, and install the latest code.
7 |
8 | This depends on having the full, latest version of the full repo https://github.com/amtwo/dba-database
9 |
10 | All dependent .sql files are itempotent:
11 | * Table.sql scripts are written to create if not exists. Changes are maintained similarly as conditional ALTERs.
12 | * code.sql scripst are written to create a stub, then alter with actual code.
13 |
14 | .PARAMETER InstanceName
15 | An array of instance names
16 |
17 | .PARAMETER DatabaseName
18 | By default, this will be installed in a database called "DBA". If you want to install my DBA database with
19 | a different name, specify it here.
20 |
21 | .PARAMETER SkipOSS
22 | By default, this installer assumes that you've got the open source stuff in the right spot. If you don't
23 | want to install those packages, just pass in $true for this, and it'll skip all of them.
24 |
25 |
26 | .EXAMPLE
27 | Install-LatestDbaDatabase AM2Prod
28 |
29 |
30 | .NOTES
31 | AUTHOR: Andy Mallon
32 | DATE: 20170922
33 | COPYRIGHT: This code is licensed as part of Andy Mallon's DBA Database. https://github.com/amtwo/dba-database/blob/master/LICENSE
34 | ©2014-2020 ● Andy Mallon ● am2.co
35 | #>
36 |
37 | [CmdletBinding()]
38 | param (
39 | [Parameter(Position=0,mandatory=$true)]
40 | [string[]]$InstanceName,
41 | [Parameter(Position=1,mandatory=$false)]
42 | [string]$DatabaseName = 'DBA',
43 | [Parameter(Position=2,mandatory=$false)]
44 | [boolean]$SkipOSS = $false
45 | )
46 |
47 | #Get Time Zone info from the OS. We'll use this to populate a table later
48 | $TimeZoneInfo = Get-TimeZone -ListAvailable |
49 | Add-Member -MemberType AliasProperty -Name TimeZoneId -Value Id -PassThru | Select-Object TimeZoneId, DisplayName, StandardName, DaylightName, SupportsDaylightSavingTime
50 |
51 | # Process servers in a loop. I could do this parallel, but doing it this way is fast enough for me.
52 | foreach($instance in $InstanceName) {
53 | Write-Verbose "**************************************************************"
54 | Write-Verbose " $instance"
55 | Write-Verbose "**************************************************************"
56 | #Create the database - SQL Script contains logic to be conditional & not clobber existing database
57 | Write-Verbose "`n ***Creating Database if necessary `n"
58 | try{
59 | Invoke-Sqlcmd -ServerInstance $instance -Database master -InputFile .\create-database.sql -Variable "DbName=$($DatabaseName)"
60 | }
61 | catch{
62 | Write-Error -Message "Failed creating DBA Database" -ErrorAction Stop
63 | }
64 |
65 | #Create tables first
66 | Write-Verbose "`n ***Creating/Updating Tables `n"
67 | $fileList = Get-ChildItem -Path .\tables -Recurse
68 | Foreach ($file in $fileList){
69 | Write-Verbose $file.FullName
70 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName -QueryTimeout 300
71 | }
72 | # Populate the TimeZones table with the object we populated earlier, but only if the table is empty
73 | if((Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -Query 'SELECT RowCnt = COUNT(*) FROM dbo.TimeZones').RowCnt -eq 0){
74 | Write-Verbose "Populating dbo.TimeZones"
75 | Write-SqlTableData -ServerInstance $instance -Database $DatabaseName -SchemaName "dbo" -Table "TimeZones" -InputData $TimeZoneInfo
76 | }
77 |
78 |
79 | #Then types
80 | Write-Verbose "`n ***Creating/Updating Types `n"
81 | $fileList = Get-ChildItem -Path .\types -Recurse
82 | Foreach ($file in $fileList){
83 | Write-Verbose $file.FullName
84 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName -QueryTimeout 300
85 | }
86 | #Then views
87 | Write-Verbose "`n ***Creating/Updating Views `n"
88 | $fileList = Get-ChildItem -Path .\views -Recurse
89 | Foreach ($file in $fileList){
90 | Write-Verbose $file.FullName
91 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName -QueryTimeout 300
92 | }
93 | #Then scalar functions
94 | Write-Verbose "`n ***Creating/Updating Scalar Functions `n"
95 | $fileList = Get-ChildItem -Path .\functions-scalar -Recurse
96 | Foreach ($file in $fileList){
97 | Write-Verbose $file.FullName
98 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName
99 | }
100 | #Then TVFs
101 | Write-Verbose "`n ***Creating/Updating Table-Valued Functions `n"
102 | $fileList = Get-ChildItem -Path .\functions-tvfs -Recurse
103 | Foreach ($file in $fileList){
104 | Write-Verbose $file.FullName
105 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName
106 | }
107 | #Then Procedures
108 | Write-Verbose "`n ***Creating/Updating Stored Procedures `n"
109 | $fileList = Get-ChildItem -Path .\stored-procedures -Recurse -Filter *.sql
110 | Foreach ($file in $fileList){
111 | Write-Verbose $file.FullName
112 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName
113 | }
114 | #Skip Open Source procedures if asked
115 | If ($SkipOSS -eq $false){
116 | #Then First Responder Kit
117 | Write-Verbose "`n ***Creating/Updating First Responder Kit `n"
118 | $fileList = Get-ChildItem -Path .\oss\firstresponderkit -Recurse -Filter *.sql
119 | Foreach ($file in $fileList){
120 | Write-Verbose $file.FullName
121 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName
122 | }
123 | #Then sp_whoisactive
124 | Write-Verbose "`n ***Creating/Updating sp_WhoIsActive `n"
125 | $fileList = Get-ChildItem -Path .\oss\whoisactive -Recurse -Filter *.sql
126 | Foreach ($file in $fileList){
127 | Write-Verbose $file.FullName
128 | Invoke-Sqlcmd -ServerInstance $instance -Database master -InputFile $file.FullName
129 | }
130 | ## WOO HOO! Ola's code is idempotent now!
131 | Write-Verbose "`n ***Creating/Updating Ola Hallengren Maintenance Solution `n"
132 | $fileList = Get-ChildItem -Path .\oss\olahallengren -Recurse -Filter *.sql
133 | Foreach ($file in $fileList){
134 | Write-Verbose $file.FullName
135 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName
136 | }
137 | ## That Erik. He's such a Darling.
138 | Write-Verbose "`n ***Creating/Updating Darling's Dandy Data Troubleshooting scripts `n"
139 | $fileList = Get-ChildItem -Path .\oss\darlingdata -Recurse -Filter *.sql
140 | Foreach ($file in $fileList){
141 | Write-Verbose $file.FullName
142 | Invoke-Sqlcmd -ServerInstance $instance -Database $DatabaseName -InputFile $file.FullName
143 | }
144 | }
145 |
146 |
147 | #That's it!
148 | }
149 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | Copyright 2020 Andy Mallon
2 |
3 | Redistribution and use in source and binary forms, with or without modification,
4 | are permitted provided that the following conditions are met:
5 |
6 | 1. Redistributions of source code must retain the above copyright notice, this list of conditions and the following disclaimer.
7 |
8 | 2. Redistributions in binary form must reproduce the above copyright notice, this list of conditions and the following disclaimer
9 | in the documentation and/or other materials provided with the distribution.
10 |
11 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING,
12 | BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT
13 | SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
14 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS
15 | INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE
16 | OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
17 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # dba-database
2 |
3 | This is my DBA database that contains my utility scripts that I use to help manage my servers.
4 |
5 | Some of this code was never intended to be used by anyone else--it's primarily here for myself, but if you want to use it, make sure you know exactly what it's doing before using any of this code.
6 |
7 | Some of this code (including the installer!) assumes that the First Responder Kit (firstresponderkit.org) and Ola Hallengren's SQL Server Maintenance Solution (ola.hallengren.com) are installed in the same database as well. PowerShell script provided to pull that stuff from it's respective download location. Redistributing other people's code isn't my thing.
8 |
9 | ### To install
10 | By default, the installer will create a database named `DBA` (if it doesn't already exist), and install all objects in that `DBA` database. You can deploy to a database named something other than `DBA` by using the `-DatabaseName` parameter on the install script. This install script assumes that you have permission to create the database, or that it already exists.
11 |
12 | * Clone this repo.
13 | * Open a PowerShell prompt & navigate (ie `Set-Location`) to the `dba-database` folder you just cloned.
14 | * Run `Get-OpenSourceScripts.ps1` to grab the latest versions of the open source/third-party projects.
15 | * Also from dba-database folder, run `Install-LatestDbaDatabase.ps1 -InstanceName "MyInstance"`
16 | * By default, the installer will use `DBA` as the database name. To use a different database name, specify that using the `-DatabaseName` paramater.
17 | * The `-InstanceName` parameter will accept an array of server names, if you want to deploy to many servers.
18 |
19 | _If you experience issues with the install experience, please [create an issue in GitHub](https://github.com/amtwo/dba-database/issues/new/choose)._
20 |
21 | ### Open Source Projects License information:
22 | * The First Responders Kit is distributed under the [MIT License](https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/blob/master/LICENSE.md).
23 | * Ola Hallengren's SQL Server Maintenance Solution is distributed under the [MIT License](https://ola.hallengren.com/license.html).
24 | * sp_WhoIsActive is distributed under the [GNU GPL v3](https://github.com/amachanic/sp_whoisactive/blob/master/LICENSE).
25 | * The Darling Data SQL Server Troubleshooting Scripts are distributed under the [MIT License](https://github.com/erikdarlingdata/DarlingData/blob/master/LICENSE.md).
26 |
--------------------------------------------------------------------------------
/Types/dbo.ObjectNameList.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT 1 FROM sys.types WHERE user_type_id = type_id ('dbo.ObjectNameList'))
2 | BEGIN
3 | CREATE TYPE dbo.ObjectNameList
4 | AS TABLE(
5 | SchemaName sysname,
6 | ObjectName sysname
7 | );
8 | END;
9 | GO
10 |
--------------------------------------------------------------------------------
/Types/dbo.ObjectNameListWithDb.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT 1 FROM sys.types WHERE user_type_id = type_id ('dbo.ObjectNameListWithDb'))
2 | BEGIN
3 | CREATE TYPE dbo.ObjectNameListWithDb
4 | AS TABLE(
5 | DbName sysname,
6 | SchemaName sysname,
7 | ObjectName sysname
8 | );
9 | END;
10 | GO
11 |
--------------------------------------------------------------------------------
/create-database.sql:
--------------------------------------------------------------------------------
1 | --Create DB
2 | IF NOT EXISTS (SELECT 1 FROM sys.databases WHERE name = N'$(DbName)')
3 | BEGIN
4 | CREATE DATABASE [$(DbName)];
5 | ALTER DATABASE [$(DbName)] ADD FILEGROUP [DATA];
6 | --Need to use dynamic SQL to ensure we put this data file in the right spot dynamically
7 | DECLARE @sql nvarchar(max);
8 | SELECT @sql = N'ALTER DATABASE [$(DbName)] ADD FILE (NAME=N''$(DbName)_data'', FILENAME=N'''
9 | + LEFT(physical_name,LEN(physical_name)-CHARINDEX(N'\',REVERSE(physical_name))+1)
10 | + N'$(DbName)_data.ndf' + N''') TO FILEGROUP [DATA];'
11 | FROM sys.master_files
12 | WHERE database_id = db_id(N'$(DbName)')
13 | AND file_id = 1;
14 | EXEC sys.sp_executesql @statement = @sql;
15 | --And now finish up creating it
16 | ALTER DATABASE [$(DbName)] MODIFY FILEGROUP [DATA] DEFAULT;
17 | ALTER DATABASE [$(DbName)] SET READ_COMMITTED_SNAPSHOT ON;
18 | --set sa as owner
19 | ALTER AUTHORIZATION ON database::$(DbName) TO sa;
20 | --set to simple recovery on creation
21 | --if you change this after creation, we won't change it back.
22 | ALTER DATABASE $(DbName) SET RECOVERY SIMPLE;
23 | END
24 | GO
--------------------------------------------------------------------------------
/functions-scalar/dbo.AGDbRole_Get.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'FN' AND object_id = object_id('dbo.AGDbRole_Get'))
2 | EXEC ('CREATE FUNCTION dbo.AGDbRole_Get() RETURNS nvarchar(60) AS BEGIN RETURN ''This is a stub''; END')
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.AGDbRole_Get( @Name sysname)
7 | RETURNS nvarchar(60)
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20140101
11 | If a database is in an AG, returns either primary or secondary status.
12 | If database is not in an AG, returns the DB's state (ONLINE, etc)
13 | PARAMETERS:
14 | @Name - Name of a database or AG
15 | EXAMPLES:
16 | *
17 | **************************************************************************************************
18 | MODIFICATIONS:
19 | YYYYMMDD -
20 | **************************************************************************************************
21 | This code is licensed as part of Andy Mallon's DBA Database.
22 | https://github.com/amtwo/dba-database/blob/master/LICENSE
23 | ©2014-2020 ● Andy Mallon ● am2.co
24 | *************************************************************************************************/
25 | AS
26 | BEGIN
27 | DECLARE @Role nvarchar(60);
28 |
29 | --AM2 Make this work for 2008 & older, too
30 |
31 | DECLARE @Sql nvarchar(max);
32 |
33 | IF CAST(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(100)),2) as int) >= 11
34 | WITH hadr_role
35 | AS (
36 | SELECT d.name COLLATE SQL_Latin1_General_CP1_CI_AS AS Name,
37 | d.state_desc COLLATE SQL_Latin1_General_CP1_CI_AS AS StateDesc,
38 | rs.role_desc COLLATE SQL_Latin1_General_CP1_CI_AS AS RoleDesc
39 | FROM sys.databases d
40 | LEFT JOIN sys.dm_hadr_availability_replica_states rs
41 | ON rs.replica_id = d.replica_id AND rs.is_local = 1
42 | UNION ALL
43 | SELECT ag.name COLLATE SQL_Latin1_General_CP1_CI_AS,
44 | rs.operational_state_desc COLLATE SQL_Latin1_General_CP1_CI_AS,
45 | rs.role_desc COLLATE SQL_Latin1_General_CP1_CI_AS
46 | FROM sys.availability_groups ag
47 | LEFT JOIN sys.dm_hadr_availability_replica_states rs
48 | ON rs.group_id = ag.group_id AND rs.is_local = 1
49 | )
50 | SELECT @Role = COALESCE(RoleDesc, StateDesc)
51 | FROM hadr_role
52 | WHERE Name = @Name;
53 | ELSE
54 | SELECT @Role = d.state_desc FROM sys.databases d WHERE d.name = @Name;
55 |
56 | RETURN @Role;
57 | END
58 | GO
59 |
60 |
61 |
--------------------------------------------------------------------------------
/functions-scalar/dbo.EmailCss_Get.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'FN' AND object_id = object_id('dbo.EmailCss_Get'))
2 | EXEC ('CREATE FUNCTION dbo.EmailCss_Get() RETURNS nvarchar(60) AS BEGIN RETURN ''This is a stub''; END')
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.EmailCss_Get()
7 | RETURNS nvarchar(max)
8 | AS
9 | /*************************************************************************************************
10 | AUTHOR: Andy Mallon
11 | CREATED: 20141001
12 | This function returns a ';
64 | RETURN(@Style);
65 | END;
66 | GO
67 |
68 |
69 |
--------------------------------------------------------------------------------
/functions-scalar/dbo.EmailServerInfo_Get.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'FN' AND object_id = object_id('dbo.EmailServerInfo_Get'))
2 | EXEC ('CREATE FUNCTION dbo.EmailServerInfo_Get() RETURNS nvarchar(60) AS BEGIN RETURN ''This is a stub''; END')
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.EmailServerInfo_Get()
7 | RETURNS nvarchar(max)
8 | AS
9 | /*************************************************************************************************
10 | AUTHOR: Andy Mallon
11 | CREATED: 20150107
12 | This function returns an HTML table containing standard info about a SQL instance to
13 | be included in email alerts/reports
14 | * Instance name
15 | * Physical Server
16 | * Instance start time
17 |
18 | PARAMETERS
19 | * None
20 | **************************************************************************************************
21 | MODIFICATIONS:
22 | YYYYMMDDD - Initials - Description of changes
23 | **************************************************************************************************
24 | This code is licensed as part of Andy Mallon's DBA Database.
25 | https://github.com/amtwo/dba-database/blob/master/LICENSE
26 | ©2014-2020 ● Andy Mallon ● am2.co
27 | *************************************************************************************************/
28 | BEGIN
29 | DECLARE @ServerInfo nvarchar(max);
30 |
31 |
32 | SELECT @ServerInfo = N'
33 |
34 | SQL Instance |
35 | ' + @@SERVERNAME + N' |
36 |
37 | Physical Server |
38 | ' + CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS nvarchar(128)) + N' |
39 |
40 | Instance Start Time |
41 | ' + (SELECT CONVERT(nvarchar(20),create_date,120) FROM sys.databases WHERE Name = 'tempdb') + N' |
42 |
43 |
';
44 |
45 | RETURN(@ServerInfo);
46 | END;
47 | GO
48 |
49 |
50 |
--------------------------------------------------------------------------------
/functions-tvfs/dbo.AgentJobHistory_TimeConvert.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'IF' AND object_id = object_id('dbo.AgentJobHistory_TimeConvert'))
2 | EXEC ('CREATE FUNCTION dbo.AgentJobHistory_TimeConvert() RETURNS TABLE AS RETURN SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 | ALTER FUNCTION dbo.AgentJobHistory_TimeConvert (@Date int, @Time int, @Duration int)
6 | RETURNS TABLE
7 | /*************************************************************************************************
8 | AUTHOR: Andy Mallon
9 | CREATED: 20250307
10 | SQL Agent stores times & durations like it's 1982, using only integer datatypes.
11 | Intended to take in values from sysjobhistory & convert things to datetime2(0)
12 | PARAMETERS:
13 | @Date - Accepts run_date values (an integer date in the format yyyyMMDD )
14 | @Time - Accepts run_time values (an integer time in the format hh24mmss )
15 | @Duration - Accepts run_duration (an integer with a cyptic formula)
16 | EXAMPLES:
17 | * SELECT j.name, h.step_id, h.message, t.*
18 | FROM msdb.dbo.sysjobs j
19 | JOIN msdb.dbo.sysjobhistory h ON h.job_id = j.job_id
20 | CROSS APPLY dbo.AgentJobHistory_TimeConvert (h.run_date, h.run_time, h.run_duration) t
21 | **************************************************************************************************
22 | This code is licensed as part of Andy Mallon's DBA Database.
23 | https://github.com/amtwo/dba-database/blob/master/LICENSE
24 | ©2014-2025 ● Andy Mallon ● am2.co
25 | *************************************************************************************************/
26 | AS
27 | RETURN
28 |
29 | WITH TimeMath AS (
30 | SELECT DATETIMEFROMPARTS(@Date / 10000, -- years
31 | @Date % 10000 / 100, -- months
32 | @Date % 100, -- days
33 | @Time / 10000, -- hours
34 | @Time % 10000 / 100, -- minutes
35 | @Time % 100, -- seconds
36 | 0 -- milliseconds
37 | ) AS RunStartDateTime,
38 | (@Duration / 10000) * 3600 -- convert hours to seconds, can be greater than 24
39 | + ((@Duration % 10000) / 100) * 60 -- convert minutes to seconds
40 | + (@Duration % 100) AS RunDurationSeconds
41 | )
42 | SELECT RunStartDateTime = RunStartDateTime,
43 | RunFinishDateTime = DATEADD(SECOND,RunDurationSeconds,RunStartDateTime),
44 | RunDurationSeconds = RunDurationSeconds
45 | FROM TimeMath;
46 | GO
47 |
48 |
--------------------------------------------------------------------------------
/functions-tvfs/dbo.AgentJob_Status.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'IF' AND object_id = object_id('dbo.AgentJob_Status'))
2 | EXEC ('CREATE FUNCTION dbo.AgentJob_Status() RETURNS TABLE AS RETURN SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.AgentJob_Status (@JobName sysname)
7 | RETURNS TABLE
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20151225
11 | Alternative to xp_sqlagent_enum_jobs. Use this TVF to determine a job's execution status
12 | PARAMETERS:
13 | @JobName - Text string of a job's name (from msdb.dbo.sysjobs.name)
14 | EXAMPLES:
15 | * SELECT j.name, s.* FROM msdb.dbo.sysjobs j CROSS APPLY dbo.AgentJob_Status (j.name) s
16 | **************************************************************************************************
17 | MODIFICATIONS:
18 | 20160218 - More info here: https://am2.co/2016/02/xp_sqlagent_enum_jobs_alt/
19 | **************************************************************************************************
20 | This code is licensed as part of Andy Mallon's DBA Database.
21 | https://github.com/amtwo/dba-database/blob/master/LICENSE
22 | ©2014-2020 ● Andy Mallon ● am2.co
23 | *************************************************************************************************/
24 | AS
25 | RETURN
26 | SELECT TOP 1
27 | IsRunning = CASE WHEN ja.job_id IS NOT NULL AND ja.stop_execution_date IS NULL THEN 1 ELSE 0 END,
28 | LastRunTime = ja.start_execution_date,
29 | NextRunTime = ja.next_scheduled_run_date,
30 | LastJobStep = js.step_name,
31 | JobOutcome = CASE
32 | WHEN ja.job_id IS NOT NULL AND ja.stop_execution_date IS NULL THEN 'Running'
33 | WHEN run_status = 0 THEN 'Failed'
34 | WHEN run_status = 1 THEN 'Succeeded'
35 | WHEN run_status = 2 THEN 'Retry'
36 | WHEN run_status = 3 THEN 'Cancelled'
37 | END
38 | FROM msdb.dbo.sysjobs j
39 | LEFT JOIN msdb.dbo.sysjobactivity ja
40 | ON ja.job_id = j.job_id
41 | AND ja.run_requested_date IS NOT NULL
42 | AND ja.start_execution_date IS NOT NULL
43 | LEFT JOIN msdb.dbo.sysjobsteps js
44 | ON js.job_id = ja.job_id
45 | AND js.step_id = ja.last_executed_step_id
46 | LEFT JOIN msdb.dbo.sysjobhistory jh
47 | ON jh.job_id = j.job_id
48 | AND jh.instance_id = ja.job_history_id
49 | WHERE j.name = @JobName
50 | ORDER BY ja.start_execution_date DESC;
51 | GO
52 |
53 |
54 |
--------------------------------------------------------------------------------
/functions-tvfs/dbo.Convert_LSNFromHexToDecimal.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'IF' AND object_id = object_id('dbo.Convert_LSNFromHexToDecimal'))
2 | EXEC ('CREATE FUNCTION dbo.Convert_LSNFromHexToDecimal() RETURNS TABLE AS RETURN SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.Convert_LSNFromHexToDecimal (@LSN varchar(22))
7 | RETURNS TABLE
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20190401
11 | LSN is sometimes represented in hex (ie, from DBCC PAGE, fn_dblog(), sys.dm_db_page_info)
12 | Hex LSNs are represented in the format '0000001e:00000038:0001'
13 | Decimal LSNs are in the format 30000000005600001
14 | PARAMETERS:
15 | @LSN - Text string of the hex version of the LSN
16 | In the format '0000001e:00000038:0001'
17 | EXAMPLES:
18 | * SELECT * FROM dbo.Convert_LSNFromHexToDecimal(0000001e:00000038:0001')
19 | **************************************************************************************************
20 | MODIFICATIONS:
21 | 20190401 -
22 | **************************************************************************************************
23 | This code is licensed as part of Andy Mallon's DBA Database.
24 | https://github.com/amtwo/dba-database/blob/master/LICENSE
25 | ©2014-2020 ● Andy Mallon ● am2.co
26 | *************************************************************************************************/
27 |
28 | -- Split LSN into segments at colon
29 | -- Convert to binary style 1 -> int
30 | -- Add padded 0's to 2nd and 3rd string
31 | -- Concatenate those strings & convert back to int
32 |
33 | RETURN
34 | --First chunk
35 | SELECT LSN = CONVERT(decimal(25),
36 | CONVERT(varchar(10),
37 | CONVERT(int,
38 | CONVERT(varbinary, '0x' + RIGHT(REPLICATE('0', 8) + LEFT(@LSN, 8), 8), 1)
39 | )
40 | )
41 | --Second chunk
42 | + RIGHT(REPLICATE('0', 10) + CONVERT(varchar(10),
43 | CONVERT(int,
44 | CONVERT(varbinary, '0x' + RIGHT(REPLICATE('0', 8) + SUBSTRING(@LSN, 10, 8), 8), 1)
45 | )
46 | ),
47 | 10)
48 | --Third chunk
49 | + RIGHT(REPLICATE('0', 5) + CONVERT(varchar(5),
50 | CONVERT(int,
51 | CONVERT(varbinary, '0x' + RIGHT(REPLICATE('0', 8) + RIGHT(@LSN, 4), 8), 1)
52 | )
53 | ),
54 | 5)
55 | );
56 | GO
--------------------------------------------------------------------------------
/functions-tvfs/dbo.ParseFilePath.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'IF' AND object_id = object_id('dbo.ParseFilePath'))
2 | EXEC ('CREATE FUNCTION dbo.ParseFilePath() RETURNS TABLE AS RETURN SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.ParseFilePath (@FilePath nvarchar(300))
7 | RETURNS TABLE
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20180114
11 | Parses a full file path into separate file & path values.
12 | Also include the bare file name & file extension, because why not?
13 | PARAMETERS:
14 | @FilePath - Text string of a complete file & path
15 | EXAMPLES:
16 | *
17 | **************************************************************************************************
18 | MODIFICATIONS:
19 | 20160218 -
20 | **************************************************************************************************
21 | This code is licensed as part of Andy Mallon's DBA Database.
22 | https://github.com/amtwo/dba-database/blob/master/LICENSE
23 | ©2014-2020 ● Andy Mallon ● am2.co
24 | *************************************************************************************************/
25 | AS
26 | RETURN
27 | WITH ParseInfo AS(
28 | SELECT FilePath = @FilePath,
29 | PathLen = LEN(@FilePath),
30 | FinalSlashPos = CHARINDEX('\', REVERSE(@FilePath), 1)
31 | ),
32 | ParsedPaths AS (
33 | SELECT DirectoryPath = LEFT (FilePath, PathLen - FinalSlashPos + 1),
34 | FullFileName = RIGHT(FilePath, FinalSlashPos - 1),
35 | FileExtension = RIGHT(FilePath, CHARINDEX('.', REVERSE(FilePath)) -1),
36 | *
37 | FROM ParseInfo
38 | )
39 | SELECT DirectoryPath,
40 | FullFileName,
41 | BareFilename = LEFT(FullFilename,LEN(FullFilename)-(LEN(FileExtension)+1)),
42 | FileExtension
43 | FROM ParsedPaths;
44 |
45 | GO
46 |
47 |
48 |
--------------------------------------------------------------------------------
/functions-tvfs/dbo.ParseStatementByOffset.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'IF' AND object_id = object_id('dbo.ParseStatementByOffset'))
2 | EXEC ('CREATE FUNCTION dbo.ParseStatementByOffset() RETURNS TABLE AS RETURN SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.ParseStatementByOffset (
7 | @SqlHandle varbinary(64),
8 | @StartOffset int,
9 | @EndOffset int
10 | )
11 | RETURNS TABLE
12 | /*************************************************************************************************
13 | AUTHOR: Andy Mallon
14 | CREATED: 20231216
15 | Parses a statement out of the query text, based on the offsets used in DMVs (eg dm_exec_query_stats)
16 |
17 | Output contains the DatabaseId, DbName, ObjectId, ObjectName, and statement text.
18 | PARAMETERS:
19 | @SqlHandle - Sql Handle (or Plan Handle) that is used to parse text.
20 | @StartOffset - Indicates, in bytes, beginning with 0, the starting position of the query that
21 | the row describes within the text of its batch or persisted object.
22 | @EndOffset - Indicates, in bytes, starting with 0, the ending position of the query that the
23 | row describes within the text of its batch or persisted object.
24 | EXAMPLES:
25 | SELECT st.*
26 | FROM sys.dm_exec_query_stats AS qs
27 | CROSS APPLY dba.dbo.ParseStatementByOffset (qs.sql_handle,
28 | qs.statement_start_offset,
29 | qs.statement_end_offset
30 | ) AS st
31 | WHERE qs.execution_count > 1000000;
32 | **************************************************************************************************
33 | This code is licensed as part of Andy Mallon's DBA Database.
34 | https://github.com/amtwo/dba-database/blob/master/LICENSE
35 | ©2014-2020 ● Andy Mallon ● am2.co
36 | *************************************************************************************************/
37 | AS
38 | RETURN
39 | SELECT DatabaseId = t.dbid,
40 | DbName = DB_NAME(t.dbid),
41 | ObjectId = t.objectid,
42 | ObjectName = OBJECT_NAME(t.objectid, t.dbid),
43 | StatementText = COALESCE(
44 | SUBSTRING(t.text, (@StartOffset/2)+1, (
45 | (CASE @EndOffset
46 | WHEN -1 THEN DATALENGTH(t.text)
47 | ELSE @EndOffset
48 | END - @StartOffset)
49 | /2) + 1),'')
50 | FROM sys.dm_exec_sql_text (@SqlHandle) AS t;
51 |
52 | GO
53 |
54 |
--------------------------------------------------------------------------------
/functions-tvfs/dbo.fn_split.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'IF' AND object_id = object_id('dbo.fn_split'))
2 | EXEC ('CREATE FUNCTION dbo.fn_split() RETURNS TABLE AS RETURN SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 |
6 | ALTER FUNCTION dbo.fn_split (@Text nvarchar(4000), @Token nvarchar(20) = N',')
7 | RETURNS TABLE
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20140420
11 | Convert a delimited string (any delimiter can be passed, default assumes CSV.
12 | Use method of converting the CSV value into an XML document to make shredding more efficient.
13 |
14 | If you are using SQL Server 2016 or later, with compatibility level 130 or higher,
15 | use STRING_SPLIT() instead.
16 | PARAMETERS:
17 | @Text - Text string of delimited text
18 | @Token - Default , - Delimited used to parse the @Text string
19 | EXAMPLES:
20 | * SELECT * FROM dbo.fn_split('A,B,C',default)
21 | * SELECT * FROM dbo.fn_split('A|^B|^C','|^')
22 | **************************************************************************************************
23 | MODIFICATIONS:
24 | 20211019 - Updated to support Unicode lists (such as a list of database names)
25 | **************************************************************************************************
26 | This code is licensed as part of Andy Mallon's DBA Database.
27 | https://github.com/amtwo/dba-database/blob/master/LICENSE
28 | ©2014-2020 ● Andy Mallon ● am2.co
29 | *************************************************************************************************/
30 | AS
31 | RETURN
32 | SELECT ID, Value
33 | FROM (
34 | SELECT ID = m.n.value('for $i in . return count(../*[. << $i]) + 1', 'int')
35 | , Value = LTRIM(RTRIM(m.n.value('.[1]','nvarchar(4000)')))
36 | FROM (
37 | SELECT CAST('' + REPLACE(@Text,@Token,'') + '' AS XML) AS x
38 | )t
39 | CROSS APPLY x.nodes('/XMLRoot/RowData')m(n)
40 | ) AS R
41 | GO
42 |
43 |
44 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_AgLatency.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_AgLatency'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_AgLatency AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Check_AgLatency
7 | @Threshold int = 0,
8 | @DbName nvarchar(128) = N'%',
9 | @AgName nvarchar(128) = N'%',
10 | @UnhealthyOnly bit = 0
11 | AS
12 | /*************************************************************************************************
13 | AUTHOR: Andy Mallon
14 | CREATED: 20140409
15 | This Alert checks AG latency (unsent logs).
16 | Latency is based on the worst reported condition from both DMVs & perfmon.
17 |
18 | PARAMETERS
19 | * @Threshold - Default 5000 - Size in KB of the unsent log
20 | * @DbName - Default % (anything) - Filter by DbName, Can be wildcarded
21 | * @AgName - Default % (anything) - Filter by AgName, Can be wildcarded
22 | * @UnhealthyOnly - Default 0 (false) - Only select databases that have sync status of NOT HEALTHY
23 | EXAMPLES:
24 | *
25 | **************************************************************************************************
26 | MODIFICATIONS:
27 | 20140804 - Start tracking Hardened LSN from DMV each time sproc runs.
28 | 20150107 - Add calculation for "minutes behind" to show how far behind primary a DB is
29 | **************************************************************************************************
30 | This code is licensed as part of Andy Mallon's DBA Database.
31 | https://github.com/amtwo/dba-database/blob/master/LICENSE
32 | ©2014-2020 ● Andy Mallon ● am2.co
33 | *************************************************************************************************/
34 | SET NOCOUNT ON;
35 |
36 | DECLARE
37 | @ProductVersion tinyint;
38 |
39 | SET @ProductVersion = LEFT(CAST(SERVERPROPERTY('PRODUCTVERSION') AS varchar(20)),CHARINDEX('.',CAST(SERVERPROPERTY('PRODUCTVERSION') AS varchar(20)))-1)
40 |
41 | IF @ProductVersion < 11
42 | BEGIN
43 | SELECT 'SQL Server version does not support AGs';
44 | RETURN;
45 | END;
46 |
47 | CREATE TABLE #AgStatus ( --drop table #AgStatus
48 | RunDate smalldatetime NOT NULL ,
49 | ServerName sysname NOT NULL ,
50 | AgName sysname NOT NULL,
51 | DbName sysname NOT NULL ,
52 | AgRole nvarchar(60) NULL,
53 | SynchState nvarchar(60) NULL,
54 | AgHealth nvarchar(60) NULL,
55 | SuspendReason nvarchar(60) NULL,
56 | SynchHardenedLSN numeric(25,0) NULL,
57 | LastHardenedTime datetime2(3) NULL,
58 | LastRedoneTime datetime2(3) NULL,
59 | RedoEstSecCompletion bigint NULL,
60 | LastCommitTime datetime2(3) NULL,
61 | PRIMARY KEY CLUSTERED (RunDate, ServerName, DBName)
62 | );
63 |
64 | CREATE TABLE #SendStatus (
65 | ServerName sysname,
66 | DbName sysname,
67 | UnsentLogKb bigint
68 | );
69 |
70 | CREATE TABLE #Results (
71 | ServerName sysname,
72 | AgName sysname,
73 | DbName sysname,
74 | UnsentLogKb bigint,
75 | SynchState nvarchar(60),
76 | AgHealth nvarchar(60),
77 | SuspendReason nvarchar(60),
78 | LastHardenedTime datetime2(3),
79 | LastRedoneTime datetime2(3),
80 | RedoEstSecCompletion bigint,
81 | LastCommitTime datetime2(3),
82 | MinutesBehind int,
83 | SortOrder int
84 | );
85 |
86 |
87 | -- Grab the current status from DMVs for AGs
88 | -- In a distributed AG, "ServerName" is the AG name we're sending to.
89 | INSERT INTO #AgStatus (RunDate, ServerName, AgName, DbName, AgRole, SynchState, AgHealth, SuspendReason,
90 | SynchHardenedLSN, LastHardenedTime, LastRedoneTime, RedoEstSecCompletion,LastCommitTime)
91 | SELECT GETDATE() AS RunDate,
92 | ar.replica_server_name AS ServerName,
93 | ag.Name COLLATE SQL_Latin1_General_CP1_CI_AS AS AgName,
94 | db_name(ds.database_id) AS DbName,
95 | rs.role_desc COLLATE SQL_Latin1_General_CP1_CI_AS AS AgRole,
96 | ds.synchronization_state_desc COLLATE SQL_Latin1_General_CP1_CI_AS AS SynchState,
97 | ds.synchronization_health_desc COLLATE SQL_Latin1_General_CP1_CI_AS AS AgHealth,
98 | ds. suspend_reason_desc COLLATE SQL_Latin1_General_CP1_CI_AS AS SuspendReason,
99 | ds.last_hardened_lsn AS SynchHardenedLSN,
100 | ds.last_hardened_time AS LastHardenedTime,
101 | ds.last_redone_time AS LastRedoneTime,
102 | CASE WHEN redo_rate = 0 THEN 0 ELSE ds.redo_queue_size/ds.redo_rate END AS RedoEstCompletion,
103 | ds.last_commit_time AS LastCommitTime
104 | FROM sys.availability_groups AS ag
105 | JOIN sys.availability_replicas AS ar ON ar.group_id = ag.group_id
106 | JOIN sys.dm_hadr_database_replica_states AS ds ON ds.group_id = ar.group_id AND ds.replica_id = ar.replica_id
107 | JOIN sys.dm_hadr_availability_replica_states AS rs ON rs.replica_id = ds.replica_id;
108 |
109 |
110 | --Lets make this easy, and create a temp table with the current status
111 | -- UNION perfmon counters with dbm_monitor_data. They should be the same, but we don't trust them, so we check both.
112 | INSERT INTO #SendStatus (ServerName, DbName, UnsentLogKb)
113 | SELECT ar.replica_server_name AS ServerName,
114 | db_name( drs.database_id) AS DbName,
115 | COALESCE(drs.log_send_queue_size,99999) AS UnsentLogKb
116 | FROM sys.dm_hadr_database_replica_states drs
117 | JOIN sys.availability_replicas ar ON ar.replica_id = drs.replica_id
118 | WHERE drs.last_sent_time IS NOT NULL
119 | UNION
120 | SELECT @@SERVERNAME,
121 | LTRIM(RTRIM(instance_name)) as DbName,
122 | cntr_value AS UnsentLogKb
123 | FROM sys.[dm_os_performance_counters]
124 | WHERE object_name = 'SQLServer:Database Replica'
125 | AND counter_name = 'Log Send Queue';
126 |
127 | INSERT INTO #Results (ServerName, AgName, DbName, UnsentLogKb, SynchState, AgHealth, SuspendReason,
128 | LastHardenedTime, LastRedoneTime, RedoEstSecCompletion, LastCommitTime, SortOrder)
129 | SELECT COALESCE(ag.ServerName, @@SERVERNAME) AS ServerName,
130 | COALESCE(ag.AgName,'') AS AgName,
131 | COALESCE(sync.DbName, ag.DbName) AS DbName,
132 | MAX(sync.UnsentLogKb) AS UnsentLogKb,
133 | COALESCE(ag.SynchState,'') AS SynchState,
134 | COALESCE(ag.AgHealth,'') AS AgHealth,
135 | COALESCE(ag.SuspendReason,'') AS SuspendReason,
136 | MAX(ag.LastHardenedTime),
137 | MAX(ag.LastRedoneTime),
138 | MAX(ag.RedoEstSecCompletion),
139 | MAX(ag.LastCommitTime),
140 | CASE
141 | WHEN COALESCE(sync.DbName, ag.DbName) = '_Total' THEN 0
142 | WHEN MAX(sync.UnsentLogKb) > '1000' THEN 2
143 | WHEN COALESCE(ag.AgHealth,'') <> 'HEALTHY' THEN 3
144 | WHEN COALESCE(ag.SynchState,'') NOT IN ('SYNCHRONIZING','SYNCHRONIZED') THEN 4
145 | ELSE 5
146 | END AS SortOrder
147 | FROM #SendStatus AS sync
148 | LEFT JOIN #AgStatus AS ag ON sync.ServerName = ag.ServerName AND sync.DbName = ag.DbName
149 | GROUP BY COALESCE(ag.ServerName,@@SERVERNAME), COALESCE(ag.AgName,''), COALESCE(sync.DbName, ag.DbName),COALESCE(ag.SynchState,''), COALESCE(ag.AgHealth,''),
150 | COALESCE(ag.SuspendReason,'') ;
151 |
152 | UPDATE r
153 | SET MinutesBehind = DATEDIFF(mi,r2.LastCommitTime,r.LastCommitTime)
154 | FROM #Results r
155 | JOIN #Results r2 ON r2.AgName = r.AgName AND r2.DbName = r.DbName AND r2.LastHardenedTime IS NULL; --Primary
156 |
157 |
158 |
159 | --Output results
160 | -- Do filtering on the results here, rather than up above.
161 | -- There's not much data here, so no perf advantage to doing it sooner.
162 | IF NOT EXISTS (SELECT 1 FROM #Results)
163 | SELECT 'No AGs Exist' AS AgStatus;
164 | ELSE
165 | SELECT *
166 | FROM #Results AS r
167 | WHERE r.UnsentLogKb >= @Threshold
168 | AND r.DbName LIKE @DbName
169 | AND r.AgName LIKE @AgName
170 | AND r.DbName = CASE
171 | WHEN @UnhealthyOnly = 0
172 | THEN r.DbName
173 | WHEN EXISTS (SELECT 1 FROM #Results r2
174 | WHERE r2.AgHealth <> 'HEALTHY'
175 | AND r2.DbName = r.DbName)
176 | THEN r.DbName
177 | END
178 | ORDER BY SortOrder, UnsentLogKb DESC, ServerName, DbName;
179 | GO
180 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_Blocking.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_Blocking'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_Blocking AS SELECT ''This is a stub''')
3 | GO
4 |
5 | ALTER PROCEDURE dbo.Check_Blocking
6 | @BlockingDurationThreshold smallint = 60,
7 | @BlockedSessionThreshold smallint = NULL
8 | AS
9 | /*************************************************************************************************
10 | AUTHOR: Andy Mallon
11 | CREATED: 20141218
12 |
13 | PARAMETERS
14 | * @BlockingDurationThreshold - seconds - Shows blocked sessions that have been waiting longer than this many seconds.
15 | * @BlockedSessionThreshold - Shows blocking only when the number of blocked sessions is this number or higher.
16 | **************************************************************************************************
17 | MODIFICATIONS:
18 | 20141222 - AM2 - Parse out the Hex jobid in ProgramName & turn into the Job Name.
19 | 20141229 - AM2 - Parse out current SqlStatement from the complete SqlText.
20 | - Start including SqlStatement in the email instead of SqlText
21 | - I now have 3 different answers to "What is the current SQL?"
22 | 1) SqlText - This is the full output from sys.dm_exec_sql_text().
23 | - If a procedure is running, this will be the CREATE PROCEDURE statement.
24 | 2) SqlStatement - Uses Statement offset values to determine specific line from SqlText
25 | - If a procedure is running, this is the specific statement within that proc
26 | 3) InputBuffer - This is the output from DBCC INPUTBUFFER
27 | - If a procedure is running, this is the EXEC statement
28 | 20171208 - AM2 - Add some functionality so that I can alert on number of sessions blocked.
29 | 20171210 - AM2 - Add Debug Mode = 2 to return the Email Body as a chunk of HTML instead of emailing it.
30 |
31 | **************************************************************************************************
32 | This code is licensed as part of Andy Mallon's DBA Database.
33 | https://github.com/amtwo/dba-database/blob/master/LICENSE
34 | ©2014-2020 ● Andy Mallon ● am2.co
35 | *************************************************************************************************/
36 | SET NOCOUNT ON;
37 | --READ UNCOMMITTED, since we're dealing with blocking, we don't want to make things worse.
38 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
39 |
40 | ---Sure, it would work if you supplied both, but the ANDing of those gets confusing to people, so easier to just do this.
41 | IF ((@BlockingDurationThreshold IS NOT NULL AND @BlockedSessionThreshold IS NOT NULL)
42 | OR COALESCE(@BlockingDurationThreshold, @BlockedSessionThreshold) IS NULL)
43 | BEGIN
44 | RAISERROR('Must supply either @BlockingDurationThreshold or @BlockedSessionThreshold (but not both).',16,1);
45 | END;
46 |
47 |
48 | DECLARE @Id int = 1,
49 | @Spid int = 0,
50 | @JobIdHex nvarchar(34),
51 | @JobName nvarchar(256),
52 | @WaitResource nvarchar(256),
53 | @DbName nvarchar(256),
54 | @ObjectName nvarchar(256),
55 | @IndexName nvarchar(256),
56 | @Sql nvarchar(max);
57 |
58 | CREATE TABLE #Blocked (
59 | ID int identity(1,1) PRIMARY KEY,
60 | WaitingSpid smallint,
61 | BlockingSpid smallint,
62 | LeadingBlocker smallint,
63 | BlockingChain nvarchar(4000),
64 | DbName sysname,
65 | HostName nvarchar(128),
66 | ProgramName nvarchar(128),
67 | LoginName nvarchar(128),
68 | LoginTime datetime2(3),
69 | LastRequestStart datetime2(3),
70 | LastRequestEnd datetime2(3),
71 | TransactionCnt int,
72 | Command nvarchar(32),
73 | WaitTime int,
74 | WaitResource nvarchar(256),
75 | WaitDescription nvarchar(1000),
76 | SqlText nvarchar(max),
77 | SqlStatement nvarchar(max),
78 | InputBuffer nvarchar(4000),
79 | SessionInfo XML,
80 | );
81 |
82 | CREATE TABLE #InputBuffer (
83 | EventType nvarchar(30),
84 | Params smallint,
85 | EventInfo nvarchar(4000)
86 | );
87 |
88 | CREATE TABLE #LeadingBlocker (
89 | Id int identity(1,1) PRIMARY KEY,
90 | LeadingBlocker smallint,
91 | BlockedSpidCount int,
92 | DbName sysname,
93 | HostName nvarchar(128),
94 | ProgramName nvarchar(128),
95 | LoginName nvarchar(128),
96 | LoginTime datetime2(3),
97 | LastRequestStart datetime2(3),
98 | LastRequestEnd datetime2(3),
99 | TransactionCnt int,
100 | Command nvarchar(32),
101 | WaitTime int,
102 | WaitResource nvarchar(256),
103 | WaitDescription nvarchar(1000),
104 | SqlText nvarchar(max),
105 | SqlStatement nvarchar(max),
106 | InputBuffer nvarchar(4000),
107 | SessionInfo xml,
108 | );
109 |
110 |
111 | --Grab all sessions involved in Blocking (both blockers & waiters)
112 |
113 | INSERT INTO #Blocked (WaitingSpid, BlockingSpid, DbName, HostName, ProgramName, LoginName, LoginTime, LastRequestStart,
114 | LastRequestEnd, TransactionCnt, Command, WaitTime, WaitResource, SqlText, SqlStatement)
115 | -- WAITERS
116 | SELECT s.session_id AS WaitingSpid,
117 | r.blocking_session_id AS BlockingSpid,
118 | db_name(r.database_id) AS DbName,
119 | s.host_name AS HostName,
120 | s.program_name AS ProgramName,
121 | s.login_name AS LoginName,
122 | s.login_time AS LoginTime,
123 | s.last_request_start_time AS LastRequestStart,
124 | s.last_request_end_time AS LastRequestEnd,
125 | -- Need to use sysprocesses for now until we're fully on 2012/2014
126 | (SELECT TOP 1 sp.open_tran FROM master.sys.sysprocesses sp WHERE sp.spid = s.session_id) AS TransactionCnt,
127 | --s.open_transaction_count AS TransactionCnt,
128 | r.command AS Command,
129 | r.wait_time AS WaitTime,
130 | r.wait_resource AS WaitResource,
131 | COALESCE(t.text,'') AS SqlText,
132 | COALESCE(SUBSTRING(t.text, (r.statement_start_offset/2)+1, (
133 | (CASE r.statement_end_offset
134 | WHEN -1 THEN DATALENGTH(t.text)
135 | ELSE r.statement_end_offset
136 | END - r.statement_start_offset)
137 | /2) + 1),'') AS SqlStatement
138 | FROM sys.dm_exec_sessions s
139 | INNER JOIN sys.dm_exec_requests r ON r.session_id = s.session_id
140 | OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) t
141 | WHERE r.blocking_session_id <> 0 --Blocked
142 | AND r.wait_time >= COALESCE(@BlockingDurationThreshold,0)*1000
143 | UNION
144 | -- BLOCKERS
145 | SELECT s.session_id AS WaitingSpid,
146 | COALESCE(r.blocking_session_id,0) AS BlockingSpid,
147 | COALESCE(db_name(r.database_id),'') AS DbName,
148 | s.host_name AS HostName,
149 | s.program_name AS ProgramName,
150 | s.login_name AS LoginName,
151 | s.login_time AS LoginTime,
152 | s.last_request_start_time AS LastRequestStart,
153 | s.last_request_end_time AS LastRequestEnd,
154 | -- Need to use sysprocesses for now until we're fully on 2012/2014
155 | (SELECT TOP 1 sp.open_tran FROM master.sys.sysprocesses sp WHERE sp.spid = s.session_id) AS TransactionCnt,
156 | --s.open_transaction_count AS TransactionCnt,
157 | COALESCE(r.command,'') AS Command,
158 | COALESCE(r.wait_time,'') AS WaitTime,
159 | COALESCE(r.wait_resource,'') AS WaitResource,
160 | COALESCE(t.text,'') AS SqlText,
161 | COALESCE(SUBSTRING(t.text, (r.statement_start_offset/2)+1, (
162 | (CASE r.statement_end_offset
163 | WHEN -1 THEN DATALENGTH(t.text)
164 | ELSE r.statement_end_offset
165 | END - r.statement_start_offset)
166 | /2) + 1),'') AS SqlStatement
167 | FROM sys.dm_exec_sessions s
168 | LEFT JOIN sys.dm_exec_requests r ON r.session_id = s.session_id
169 | OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) t
170 | WHERE s.session_id IN (SELECT blocking_session_id FROM sys.dm_exec_requests ) --Blockers
171 | AND COALESCE(r.blocking_session_id,0) = 0; --Not blocked
172 |
173 |
174 | -- Grab the input buffer for all sessions, too.
175 | WHILE EXISTS (SELECT 1 FROM #Blocked WHERE InputBuffer IS NULL)
176 | BEGIN
177 | TRUNCATE TABLE #InputBuffer;
178 |
179 | SELECT TOP 1 @Spid = WaitingSpid, @ID = ID
180 | FROM #Blocked
181 | WHERE InputBuffer IS NULL;
182 |
183 | SET @Sql = 'DBCC INPUTBUFFER (' + CAST(@Spid AS varchar(10)) + ');';
184 |
185 | BEGIN TRY
186 | INSERT INTO #InputBuffer
187 | EXEC sp_executesql @sql;
188 | END TRY
189 | BEGIN CATCH
190 | PRINT 'InputBuffer Failed';
191 | END CATCH
192 |
193 | --SELECT @id, @Spid, COALESCE((SELECT TOP 1 EventInfo FROM #InputBuffer),'')
194 | --EXEC sp_executesql @sql;
195 |
196 | UPDATE b
197 | SET InputBuffer = COALESCE((SELECT TOP 1 EventInfo FROM #InputBuffer),'')
198 | FROM #Blocked b
199 | WHERE ID = @Id;
200 | END;
201 |
202 | --Convert Hex job_ids for SQL Agent jobs to names.
203 | WHILE EXISTS(SELECT 1 FROM #Blocked WHERE ProgramName LIKE 'SQLAgent - TSQL JobStep (Job 0x%')
204 | BEGIN
205 | SELECT @JobIdHex = '', @JobName = '';
206 |
207 | SELECT TOP 1 @ID = ID,
208 | @JobIdHex = SUBSTRING(ProgramName,30,34)
209 | FROM #Blocked
210 | WHERE ProgramName LIKE 'SQLAgent - TSQL JobStep (Job 0x%';
211 |
212 | SELECT @Sql = N'SELECT @JobName = name FROM msdb.dbo.sysjobs WHERE job_id = ' + @JobIdHex;
213 | EXEC sp_executesql @Sql, N'@JobName nvarchar(256) OUT', @JobName = @JobName OUT;
214 |
215 | UPDATE b
216 | SET ProgramName = LEFT(REPLACE(ProgramName,@JobIdHex,@JobName),128)
217 | FROM #Blocked b
218 | WHERE ID = @Id;
219 | END;
220 |
221 | --Decypher wait resources.
222 | DECLARE wait_cur CURSOR FOR
223 | SELECT WaitingSpid, WaitResource FROM #Blocked WHERE WaitResource <> '';
224 |
225 | OPEN wait_cur;
226 | FETCH NEXT FROM wait_cur INTO @Spid, @WaitResource;
227 | WHILE @@FETCH_STATUS = 0
228 | BEGIN
229 | IF @WaitResource LIKE 'KEY%'
230 | BEGIN
231 | --Decypher DB portion of wait resource
232 | SET @WaitResource = LTRIM(REPLACE(@WaitResource,'KEY:',''));
233 | SET @DbName = db_name(SUBSTRING(@WaitResource,0,CHARINDEX(':',@WaitResource)));
234 | --now get the object name
235 | SET @WaitResource = SUBSTRING(@WaitResource,CHARINDEX(':',@WaitResource)+1,256);
236 | SELECT @Sql = 'SELECT @ObjectName = SCHEMA_NAME(o.schema_id) + ''.'' + o.name, @IndexName = i.name ' +
237 | 'FROM ' + QUOTENAME(@DbName) + '.sys.partitions p ' +
238 | 'JOIN ' + QUOTENAME(@DbName) + '.sys.objects o ON p.OBJECT_ID = o.OBJECT_ID ' +
239 | 'JOIN ' + QUOTENAME(@DbName) + '.sys.indexes i ON p.OBJECT_ID = i.OBJECT_ID AND p.index_id = i.index_id ' +
240 | 'WHERE p.hobt_id = SUBSTRING(@WaitResource,0,CHARINDEX('' '',@WaitResource))'
241 | EXEC sp_executesql @sql,N'@WaitResource nvarchar(256),@ObjectName nvarchar(256) OUT,@IndexName nvarchar(256) OUT',
242 | @WaitResource = @WaitResource, @ObjectName = @ObjectName OUT, @IndexName = @IndexName OUT
243 | --now populate the WaitDescription column
244 | UPDATE b
245 | SET WaitDescription = 'KEY WAIT: ' + @DbName + '.' + @ObjectName + ' (' + COALESCE(@IndexName,'') + ')'
246 | FROM #Blocked b
247 | WHERE WaitingSpid = @Spid;
248 | END;
249 | ELSE IF @WaitResource LIKE 'OBJECT%'
250 | BEGIN
251 | --Decypher DB portion of wait resource
252 | SET @WaitResource = LTRIM(REPLACE(@WaitResource,'OBJECT:',''));
253 | SET @DbName = db_name(SUBSTRING(@WaitResource,0,CHARINDEX(':',@WaitResource)));
254 | --now get the object name
255 | SET @WaitResource = SUBSTRING(@WaitResource,CHARINDEX(':',@WaitResource)+1,256);
256 | SET @Sql = 'SELECT @ObjectName = schema_name(schema_id) + ''.'' + name FROM [' + @DbName + '].sys.objects WHERE object_id = SUBSTRING(@WaitResource,0,CHARINDEX('':'',@WaitResource))';
257 | EXEC sp_executesql @sql,N'@WaitResource nvarchar(256),@ObjectName nvarchar(256) OUT',@WaitResource = @WaitResource, @ObjectName = @ObjectName OUT;
258 | --Now populate the WaitDescription column
259 | UPDATE b
260 | SET WaitDescription = 'OBJECT WAIT: ' + @DbName + '.' + @ObjectName
261 | FROM #Blocked b
262 | WHERE WaitingSpid = @Spid;
263 | END;
264 | ELSE IF (@WaitResource LIKE 'PAGE%' OR @WaitResource LIKE 'RID%')
265 | BEGIN
266 | --Decypher DB portion of wait resource
267 | SELECT @WaitResource = LTRIM(REPLACE(@WaitResource,'PAGE:',''));
268 | SELECT @WaitResource = LTRIM(REPLACE(@WaitResource,'RID:',''));
269 | SET @DbName = db_name(SUBSTRING(@WaitResource,0,CHARINDEX(':',@WaitResource)));
270 | --now get the file name
271 | SET @WaitResource = SUBSTRING(@WaitResource,CHARINDEX(':',@WaitResource)+1,256)
272 | SELECT @ObjectName = name
273 | FROM sys.master_files
274 | WHERE database_id = db_id(@DbName)
275 | AND file_id = SUBSTRING(@WaitResource,0,CHARINDEX(':',@WaitResource));
276 | --Now populate the WaitDescription column
277 | SET @WaitResource = SUBSTRING(@WaitResource,CHARINDEX(':',@WaitResource)+1,256)
278 | IF @WaitResource LIKE '%:%'
279 | BEGIN
280 | UPDATE b
281 | SET WaitDescription = 'ROW WAIT: ' + @DbName + ' File: ' + @ObjectName + ' Page_id/Slot: ' + @WaitResource
282 | FROM #Blocked b
283 | WHERE WaitingSpid = @Spid;
284 | END;
285 | ELSE
286 | BEGIN
287 | UPDATE b
288 | SET WaitDescription = 'PAGE WAIT: ' + @DbName + ' File: ' + @ObjectName + ' Page_id: ' + @WaitResource
289 | FROM #Blocked b
290 | WHERE WaitingSpid = @Spid;
291 | END;
292 | END;
293 | FETCH NEXT FROM wait_cur INTO @Spid, @WaitResource;
294 | END;
295 | CLOSE wait_cur;
296 | DEALLOCATE wait_cur;
297 |
298 |
299 | --Move the LEADING blockers out to their own table.
300 | INSERT INTO #LeadingBlocker (LeadingBlocker, DbName, HostName, ProgramName, LoginName, LoginTime, LastRequestStart, LastRequestEnd,
301 | TransactionCnt, Command, WaitTime, WaitResource, WaitDescription, SqlText, SqlStatement, InputBuffer)
302 | SELECT WaitingSpid, DbName, HostName, ProgramName, LoginName, LoginTime, LastRequestStart, LastRequestEnd,
303 | TransactionCnt, Command, WaitTime, WaitResource, WaitDescription, SqlText, SqlStatement, InputBuffer
304 | FROM #Blocked b
305 | WHERE BlockingSpid = 0
306 | AND EXISTS (SELECT 1 FROM #Blocked b1 WHERE b1.BlockingSpid = b.WaitingSpid);
307 |
308 | DELETE FROM #Blocked WHERE BlockingSpid = 0;
309 |
310 | --Update #Blocked to include LeadingBlocker & BlockingChain
311 | WITH BlockingChain AS (
312 | SELECT LeadingBlocker AS Spid,
313 | CAST(0 AS smallint) AS Blocker,
314 | CAST(LeadingBlocker AS nvarchar(4000)) AS BlockingChain,
315 | LeadingBlocker AS LeadingBlocker
316 | FROM #LeadingBlocker
317 | UNION ALL
318 | SELECT b.WaitingSpid AS Spid,
319 | b.BlockingSpid AS Blocker,
320 | RIGHT((CAST(b.WaitingSpid AS nvarchar(10)) + N' ' + CHAR(187) + N' ' + bc.BlockingChain),4000) AS BlockingChain,
321 | bc.LeadingBlocker
322 | FROM #Blocked b
323 | JOIN BlockingChain bc ON bc.Spid = b.BlockingSpid
324 | )
325 | UPDATE b
326 | SET LeadingBlocker = bc.LeadingBlocker,
327 | BlockingChain = bc.BlockingChain
328 | FROM #Blocked b
329 | JOIN BlockingChain bc ON b.WaitingSpid = bc.Spid;
330 |
331 | -- Populate BlockedSpidCount for #LeadingBlocker
332 | UPDATE lb
333 | SET BlockedSpidCount = cnt.BlockedSpidCount
334 | FROM #LeadingBlocker lb
335 | JOIN (SELECT LeadingBlocker, COUNT(*) BlockedSpidCount FROM #Blocked GROUP BY LeadingBlocker) cnt
336 | ON cnt.LeadingBlocker = lb.LeadingBlocker;
337 |
338 |
339 | -- Populate SessionInfo column with HTML details for sending email
340 | -- Since there's a bunch of logic here, code is more readable doing this separate than mashing it in with the rest of HTML email creation
341 |
342 | UPDATE lb
343 | SET SessionInfo = (SELECT LeadingBlocker,
344 | LoginName,
345 | TransactionCnt,
346 | WaitResource = COALESCE(WaitDescription,WaitResource),
347 | HostName,
348 | DbName,
349 | LastRequest = CONVERT(varchar(20),LastRequestStart,20),
350 | ProgramName,
351 | InputBuffer,
352 | SqlStatement,
353 | SqlText
354 | FROM #LeadingBlocker lb2
355 | WHERE lb.id = lb2.id
356 | FOR XML PATH ('LeadBlocker'))
357 | FROM #LeadingBlocker lb;
358 |
359 |
360 | /*UPDATE b
361 | SET SessionInfo = '' + LoginName + '' +
362 | '' + HostName + '' +
363 | CASE WHEN TransactionCnt <> 0
364 | THEN '' + CAST(TransactionCnt AS nvarchar(10)) + ''
365 | ELSE ''
366 | END +
367 | CASE WHEN WaitResource <> ''
368 | THEN '' + COALESCE(WaitDescription,WaitResource) + ''
369 | ELSE ''
370 | END +
371 | '' + DbName + '' +
372 | '' + CONVERT(varchar(20),LastRequestStart,20) + '' +
373 | '' + ProgramName + ''
374 | FROM #Blocked b;
375 | */
376 | UPDATE b
377 | SET SessionInfo = (SELECT WaitingSpid,
378 | BlockingChain,
379 | LoginName,
380 | TransactionCnt,
381 | WaitResource = COALESCE(WaitDescription,WaitResource),
382 | HostName,
383 | DbName,
384 | LastRequest = CONVERT(varchar(20),LastRequestStart,20),
385 | ProgramName,
386 | InputBuffer,
387 | SqlStatement,
388 | SqlText
389 | FROM #Blocked b2
390 | WHERE b.id = b2.id
391 | FOR XML PATH ('BlockedSession'))
392 | FROM #Blocked b;
393 |
394 | --output results
395 | IF NOT EXISTS (SELECT 1 FROM #LeadingBlocker WHERE BlockedSpidCount >= COALESCE(@BlockedSessionThreshold,BlockedSpidCount))
396 | SELECT 'No Blocking Detected' AS Blocking;
397 | ELSE
398 | BEGIN
399 | SELECT * FROM #LeadingBlocker
400 | WHERE BlockedSpidCount >= COALESCE(@BlockedSessionThreshold,BlockedSpidCount)
401 | ORDER BY LoginTime;
402 | --
403 | SELECT * FROM #Blocked b
404 | WHERE EXISTS (SELECT 1 FROM #LeadingBlocker lb
405 | WHERE lb.LeadingBlocker = b.LeadingBlocker
406 | AND lb.BlockedSpidCount >= COALESCE(@BlockedSessionThreshold,lb.BlockedSpidCount))
407 | ORDER BY b.WaitTime DESC;
408 | END;
409 |
410 |
411 |
412 | GO
413 |
414 |
415 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_DriveSpace.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_DriveSpace'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_DriveSpace AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Check_DriveSpace
7 | AS
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20141001
11 | This procedure checks all drives that contain data files for available space.
12 |
13 | PARAMETERS
14 | * None
15 | **************************************************************************************************
16 | MODIFICATIONS:
17 | YYYYMMDDD - Initials - Description of changes
18 | **************************************************************************************************
19 | This code is licensed as part of Andy Mallon's DBA Database.
20 | https://github.com/amtwo/dba-database/blob/master/LICENSE
21 | ©2014-2020 ● Andy Mallon ● am2.co
22 | *************************************************************************************************/
23 | SET NOCOUNT ON;
24 | DECLARE @database_id int,
25 | @file_id int;
26 |
27 | --Temp tables
28 | CREATE TABLE #FileStats (
29 | database_id int,
30 | file_id int,
31 | volume_mount_point nvarchar(512),
32 | file_system_type nvarchar(512),
33 | total_bytes bigint,
34 | available_bytes bigint
35 | );
36 |
37 | CREATE TABLE #Drives (
38 | volume_mount_point nvarchar(512),
39 | file_system_type nvarchar(512),
40 | total_GB numeric(10,3),
41 | available_GB numeric(10,3),
42 | available_percent numeric(5,3)
43 | );
44 |
45 | --Cursors
46 | DECLARE filestats_cur CURSOR FOR
47 | SELECT database_id, file_id
48 | FROM sys.master_files;
49 |
50 | --Get filestats drive info for every datafile to get every drive
51 | --just in case there's a mountpoint that isn't a drive
52 |
53 | OPEN filestats_cur;
54 | FETCH NEXT FROM filestats_cur INTO @database_id, @file_id;
55 |
56 | WHILE @@FETCH_STATUS = 0
57 | BEGIN
58 | INSERT INTO #FileStats (database_id, file_id, volume_mount_point, file_system_type, total_bytes, available_bytes)
59 | SELECT database_id, file_id, volume_mount_point, file_system_type, total_bytes, available_bytes
60 | FROM sys.dm_os_volume_stats (@database_id,@file_id);
61 |
62 | FETCH NEXT FROM filestats_cur INTO @database_id, @file_id;
63 | END
64 | CLOSE filestats_cur;
65 | DEALLOCATE filestats_cur;
66 |
67 | --dedupe info to get drive info
68 | INSERT INTO #Drives (volume_mount_point, file_system_type, total_GB, available_GB)
69 | SELECT volume_mount_point, file_system_type, min(total_bytes)/1024/1024/1024., min(available_bytes)/1024/1024/1024.
70 | FROM #FileStats
71 | GROUP BY volume_mount_point, file_system_type;
72 |
73 | UPDATE #Drives
74 | SET available_percent = available_GB/total_GB*100;
75 |
76 |
77 | SELECT * FROM #Drives;
78 |
79 |
80 | GO
81 |
82 |
83 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_FileSize.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_FileSize'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_FileSize AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Check_FileSize
7 | @DbName sysname = NULL,
8 | @Drive char(1) = NULL,
9 | @IncludeDataFiles bit = 1,
10 | @IncludeLogFiles bit = 1,
11 | @OrderBy nvarchar(100) = NULL
12 | AS
13 | /*************************************************************************************************
14 | AUTHOR: Andy Mallon
15 | CREATED: 20140917
16 | This returns data related to file size & and usage.
17 | PARAMETERS
18 | * @DbName - Default NULL - Specific database to check for file size/usage. Can be wildcarded
19 | When NULL, check all databases
20 | * @Drive - Default NULL - Specific drive letter to check for file size/usage.
21 | When NULL, check all drives
22 | * @IncludeDataFiles - Default 1 (True) - Flag to enable checking of data file sizes. Defaults to true.
23 | * @IncludeLogFiles - Default 1 (True) - Flag to enable checking of log file sizes. Defaults to true.
24 | * @OrderBy - Default NULL - The value used in the order by clause of the result set.
25 | When NULL or an invalid value passed, ordered by ServerName, DbName, LogicalFileName
26 |
27 | EXAMPLES:
28 | * Check File size/usage for internal_tracking database
29 | EXEC Check_FileSize @DbName = 'internal_tracking'
30 | * Check File size/usage for all data & log files for all databases on the D drive
31 | EXEC Check_FileSize @Drive = 'D'
32 | * Check File size/usage for all data files (but not logs) for the internal_tracking database on the D drive
33 | EXEC Check_FileSize @DbName = 'internal_tracking', @Drive = 'D', @IncludeLogFiles = 0
34 | **************************************************************************************************
35 | MODIFICATIONS:
36 | 20140101 - Initials - Modification description
37 | 20200424 - AM2 - Update to pass @DbName to sp_foreachdb like a big boy, instead of
38 | just querying on the output table. This is a big difference on servers with
39 | many databases
40 |
41 | **************************************************************************************************
42 | This code is licensed as part of Andy Mallon's DBA Database.
43 | https://github.com/amtwo/dba-database/blob/master/LICENSE
44 | ©2014-2020 ● Andy Mallon ● am2.co
45 | *************************************************************************************************/
46 | SET NOCOUNT ON;
47 |
48 | CREATE TABLE #FileSizeInfo
49 | (
50 | ServerName NVARCHAR(128),
51 | DbName NVARCHAR(128),
52 | LogicalFileName NVARCHAR(128),
53 | FileType NVARCHAR(10),
54 | FileSizeMB INT,
55 | SpaceUsedMB INT,
56 | FreeSpaceMB INT,
57 | FreeSpacePct VARCHAR(7),
58 | GrowthAmount VARCHAR(20),
59 | PhysicalFileName NVARCHAR(520)
60 | );
61 |
62 |
63 | --if no @OrderBy supplied or an invalid option, use DBName, LogicalFileName
64 | IF (@OrderBy IS NULL
65 | OR EXISTS (SELECT * FROM dbo.fn_split(REPLACE(REPLACE(@OrderBy,'ASC',''),'DESC',''),',')
66 | WHERE value NOT IN (SELECT name FROM tempdb.sys.columns WHERE object_id = object_id('tempdb..#FileSizeInfo') )
67 | ))
68 | SET @OrderBy = 'ServerName, DbName, LogicalFileName';
69 |
70 | IF @DbName IS NULL
71 | BEGIN
72 | SET @DbName = N'%';
73 | END
74 |
75 | -- Because of log-shipped databases, we want to use sys.master_files for the file location NOT sys.sysfiles
76 | -- sys.master_files will show the location on *this* server.
77 | -- sys.sysfiles in the DB will show the location of the files on the *primary* server.
78 | -- Using sys.master_files has the right location in all cases.
79 | -- Because of TempDB, we want to use sys.sysfiles for the file size, not sys.master_files
80 | -- sys.master_files will show the *starting* file size, not the actual file size.
81 | -- sys.sysfiles will show the *current* file size
82 | -- Using sys.sysfiles has the right current file size in all cases.
83 |
84 | INSERT #FileSizeInfo (ServerName, DbName, FileSizeMB, SpaceUsedMB, GrowthAmount, LogicalFileName, PhysicalFileName, FileType, FreeSpaceMB, FreeSpacePct)
85 | EXEC dbo.sp_ineachdb
86 | @suppress_quotename = 1,
87 | @state_desc = 'ONLINE',
88 | @name_pattern = @DbName,
89 | @command = '
90 | SELECT @@servername as ServerName, db_name() AS DatabaseName,
91 | CAST(f.size/128.0 AS decimal(20,2)) AS FileSize,
92 | CASE
93 | WHEN mf.type_desc = ''FILESTREAM'' THEN CAST(f.size/128.0 AS decimal(20,2))
94 | ELSE CAST(FILEPROPERTY(mf.name, ''SpaceUsed'')/128.0 as decimal (20,2))
95 | END AS ''SpaceUsed'',
96 | CASE
97 | WHEN mf.type_desc = ''FILESTREAM'' THEN NULL
98 | WHEN mf.is_percent_growth = 0
99 | THEN convert(varchar,ceiling((mf.growth * 8192.0)/(1024.0*1024.0))) + '' MB''
100 | ELSE convert (varchar, mf.growth) + '' Percent''
101 | END AS FileGrowth, mf.name AS LogicalFileName,
102 | mf.physical_name AS PhysicalFileName, mf.type_desc AS FileType,
103 | CAST(f.size/128.0 - CAST(FILEPROPERTY(mf.name, ''SpaceUsed'' ) AS int)/128.0 AS int) AS FreeSpaceMB,
104 | CAST(100 * (CAST (((f.size/128.0 -CAST(FILEPROPERTY(mf.name,
105 | ''SpaceUsed'' ) AS int)/128.0)/(f.size/128.0)) AS decimal(4,2))) AS varchar(8)) + ''%'' AS FreeSpacePct
106 | FROM sys.master_files mf
107 | JOIN sys.database_files f ON f.file_id = mf.file_id AND mf.database_id = db_id();
108 | ' ;
109 |
110 |
111 | DECLARE @sql nvarchar(4000);
112 | SET @sql = N'SELECT * FROM #FileSizeInfo WHERE 1=1';
113 |
114 | --Include optional filters
115 | IF @IncludeDataFiles = 0
116 | SET @sql = @sql + N' AND FileType <> ''ROWS''';
117 | IF @IncludeLogFiles = 0
118 | SET @sql = @sql + N' AND FileType <> ''LOG''';
119 | IF @Drive IS NOT NULL
120 | SET @sql = @sql + N' AND PhysicalFileName LIKE ''' + @Drive + N'%''';
121 |
122 | --include order by
123 | SET @sql = @sql + N' ORDER BY ' + @OrderBy;
124 |
125 | PRINT @sql;
126 |
127 | EXEC sys.sp_executesql @sql;
128 |
129 | GO
130 |
131 |
132 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_LogVLF.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_LogVLF'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_LogVLF AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Check_LogVLF
7 | @Threshold tinyint = 0
8 | AS
9 | /*************************************************************************************************
10 | AUTHOR: Andy Mallon
11 | CREATED: 20141001
12 | This checks all tran logs for the number of VLFs. When transaction logs contains
13 | "too many" VLFs, it can impact database recovery & failover.
14 | The @Threshold controls what DBs should be included in the result set
15 |
16 | PARAMETERS
17 | * @Threshold - Default 0 - Number of VLFs. Can be used to filter out databases with a small
18 | number of VLFs, in case you don't care about those.
19 | EXAMPLES:
20 |
21 |
22 | **************************************************************************************************
23 | This code is licensed as part of Andy Mallon's DBA Database.
24 | https://github.com/amtwo/dba-database/blob/master/LICENSE
25 | ©2014-2020 ● Andy Mallon ● am2.co
26 | *************************************************************************************************/
27 | SET NOCOUNT ON;
28 |
29 | DECLARE @DbName sysname,
30 | @SQL nvarchar(max)
31 |
32 | CREATE TABLE #Results (
33 | DbName sysname,
34 | LogFileName sysname,
35 | PhysicalName sysname,
36 | Growth sysname,
37 | VLF int);
38 |
39 | CREATE TABLE #LogInfo
40 | (RecoveryUnitID tinyint,
41 | fileid tinyint,
42 | file_size bigint,
43 | start_offset bigint,
44 | FSeqNo int,
45 | [status] tinyint,
46 | parity tinyint,
47 | create_lsn numeric(25,0) );
48 |
49 |
50 | INSERT INTO #Results (DbName, LogFileName, PhysicalName, Growth)
51 | EXEC dbo.sp_ineachdb @suppress_quotename = 1, @command = '
52 | SELECT db_name() , name, physical_name,
53 | CASE WHEN growth = 0 THEN ''fixed'' ELSE
54 | CASE WHEN is_percent_growth = 0 THEN CONVERT(varchar(10), (growth/128)) + '' MB''
55 | WHEN is_percent_growth = 1 THEN CONVERT(varchar(10), growth) +'' PERCENT'' END
56 | END AS [growth]
57 | FROM sys.database_files
58 | WHERE type_desc = ''LOG''; ';
59 |
60 |
61 | DECLARE db_cur CURSOR FOR
62 | SELECT dbname FROM #Results ORDER BY dbname;
63 |
64 | OPEN db_cur;
65 | FETCH NEXT FROM db_cur INTO @DbName;
66 | WHILE @@FETCH_STATUS=0
67 | BEGIN
68 | DELETE FROM #LogInfo;
69 | --RecoveryUnitID column is only used in 2012 and up.
70 | IF CAST(LEFT(CAST(SERVERPROPERTY('ProductVersion') as varchar(12)),2) as tinyint) <= 10
71 | SET @sql='Insert #LogInfo(fileid, file_size, start_offset, FSeqNo, [status], parity, create_lsn) Exec(''DBCC loginfo ('+QUOTENAME(@dbname)+')'')';
72 | ELSE
73 | SET @sql='Insert #LogInfo(RecoveryUnitID, fileid, file_size, start_offset, FSeqNo, [status], parity, create_lsn) Exec(''DBCC loginfo ('+QUOTENAME(@dbname)+')'')';
74 | PRINT @sql;
75 | EXEC sys.sp_executesql @stmt = @sql;
76 | UPDATE #Results SET vlf=(SELECT COUNT(*) FROM #LogInfo) WHERE dbname=@DbName;
77 | FETCH Next FROM db_cur INTO @DbName;
78 | END;
79 | CLOSE db_cur;
80 | DEALLOCATE db_cur;
81 |
82 |
83 | SELECT *
84 | FROM #Results
85 | WHERE vlf >= @Threshold
86 | ORDER BY VLF DESC;
87 |
88 |
89 | GO
90 |
91 |
92 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_OpenTransactions.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_OpenTransactions'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_OpenTransactions AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Check_OpenTransactions
7 | @DurationThreshold smallint = 1,
8 | @OnlySleepingSessions bit = 0
9 | AS
10 | /*************************************************************************************************
11 | AUTHOR: Andy Mallon
12 | CREATED: 20141218
13 | This procedure checks for locking exceeding a duration of @DurationThreshold.
14 | Query to identify locks is based on query from Paul Randal:
15 | https://www.sqlskills.com/blogs/paul/script-open-transactions-with-text-and-plans/
16 |
17 | PARAMETERS
18 | * @DurationThreshold - minutes - Alters when database locks have been holding log space
19 | for this many minutes.
20 | * @OnlySleepingSessions - bit - Only show sessions that are sleeping
21 | **************************************************************************************************
22 | MODIFICATIONS:
23 | 20141222 - AM2 - Parse out the Hex jobid in ProgramName & turn into the Job Name.
24 | 20141229 - AM2 - Parse out current SqlStatement from the complete SqlText.
25 | - Start including SqlStatement in the email instead of SqlText
26 | - I now have 3 different answers to "What is the current SQL?"
27 | 1) SqlText - This is the full output from sys.dm_exec_sql_text().
28 | - If a procedure is running, this will be the CREATE PROCEDURE statement.
29 | 2) SqlStatement - Uses Statement offset values to determine specific line from SqlText
30 | - If a procedure is running, this is the specific statement within that proc
31 | 3) InputBuffer - This is the output from DBCC INPUTBUFFER
32 | - If a procedure is running, this is the EXEC statement
33 | 20190401 - AM2 - Add filter to only include sleeping sessions in results
34 | **************************************************************************************************
35 | This code is licensed as part of Andy Mallon's DBA Database.
36 | https://github.com/amtwo/dba-database/blob/master/LICENSE
37 | ©2014-2020 ● Andy Mallon ● am2.co
38 | *************************************************************************************************/
39 | SET NOCOUNT ON;
40 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
41 |
42 | --If we're in Debug mode, ignore @DurationThreshold parameter, Always use 1 minute.
43 | DECLARE @Id int = 1,
44 | @Spid int = 0,
45 | @JobIdHex nvarchar(34),
46 | @JobName nvarchar(256),
47 | @Sql nvarchar(max),
48 | @EmailFrom varchar(max),
49 | @EmailBody nvarchar(max),
50 | @EmailSubject nvarchar(255);
51 |
52 | CREATE TABLE #OpenTrans (
53 | Id int identity(1,1) PRIMARY KEY,
54 | Spid smallint,
55 | BlockingSpid smallint,
56 | TransactionLengthMinutes AS DATEDIFF(mi,TransactionStart,GETDATE()),
57 | DbName sysname,
58 | HostName nvarchar(128),
59 | ProgramName nvarchar(128),
60 | LoginName nvarchar(128),
61 | LoginTime datetime2(3),
62 | LastRequestStart datetime2(3),
63 | LastRequestEnd datetime2(3),
64 | TransactionCnt int,
65 | TransactionStart datetime2(3),
66 | TransactionState tinyint,
67 | Command nvarchar(32),
68 | WaitTime int,
69 | WaitResource nvarchar(256),
70 | SqlText nvarchar(max),
71 | SqlStatement nvarchar(max),
72 | InputBuffer nvarchar(4000),
73 | SessionInfo xml
74 | );
75 |
76 | CREATE TABLE #InputBuffer (
77 | EventType nvarchar(30),
78 | Params smallint,
79 | EventInfo nvarchar(4000)
80 | );
81 |
82 |
83 | --Grab all sessions with open transactions
84 |
85 | INSERT INTO #OpenTrans (Spid, BlockingSpid, DbName, HostName, ProgramName, LoginName, LoginTime, LastRequestStart,
86 | LastRequestEnd, TransactionCnt, TransactionStart, TransactionState, Command, WaitTime, WaitResource, SqlText, SqlStatement)
87 | SELECT s.session_id AS Spid,
88 | r.blocking_session_id AS BlockingSpid,
89 | COALESCE(db_name(dt.database_id),CAST(dt.database_id as nvarchar(10))) AS DbName,
90 | s.host_name AS HostName,
91 | s.program_name AS ProgramName,
92 | s.login_name AS LoginName,
93 | s.login_time AS LoginTime,
94 | s.last_request_start_time AS LastRequestStart,
95 | s.last_request_end_time AS LastRequestEnd,
96 | -- Need to use sysprocesses for now until we're fully on 2012/2014
97 | (SELECT TOP 1 sp.open_tran FROM master.sys.sysprocesses sp WHERE sp.spid = s.session_id) AS TransactionCnt,
98 | --s.open_transaction_count AS TransactionCnt,
99 | COALESCE(dt.database_transaction_begin_time,s.last_request_start_time) AS TransactionStart,
100 | dt.database_transaction_state AS TransactionState,
101 | r.command AS Command,
102 | r.wait_time AS WaitTime,
103 | r.wait_resource AS WaitResource,
104 | COALESCE(t.text,'') AS SqlText,
105 | COALESCE(SUBSTRING(t.text, (r.statement_start_offset/2)+1, (
106 | (CASE r.statement_end_offset
107 | WHEN -1 THEN DATALENGTH(t.text)
108 | ELSE r.statement_end_offset
109 | END - r.statement_start_offset)
110 | /2) + 1),'') AS SqlStatement
111 | FROM sys.dm_exec_sessions s
112 | JOIN sys.dm_tran_session_transactions st ON st.session_id = s.session_id
113 | JOIN sys.dm_tran_database_transactions dt ON dt.transaction_id = st.transaction_id
114 | LEFT JOIN sys.dm_exec_requests r ON r.session_id = s.session_id
115 | OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) t
116 | WHERE dt.database_transaction_state NOT IN (3) -- 3 means transaction has been initialized but has not generated any log records. Ignore it
117 | AND (@OnlySleepingSessions = 0 OR s.status = 'sleeping')
118 | AND COALESCE(dt.database_transaction_begin_time,s.last_request_start_time) < DATEADD(mi,-1*@DurationThreshold ,GETDATE());
119 |
120 | -- Grab the input buffer for all sessions, too.
121 | WHILE EXISTS (SELECT 1 FROM #OpenTrans WHERE InputBuffer IS NULL)
122 | BEGIN
123 | TRUNCATE TABLE #InputBuffer;
124 |
125 | SELECT TOP 1 @Spid = Spid, @Id = Id
126 | FROM #OpenTrans
127 | WHERE InputBuffer IS NULL;
128 |
129 | SET @Sql = 'DBCC INPUTBUFFER (' + CAST(@Spid AS varchar(10)) + ');';
130 |
131 | BEGIN TRY
132 | INSERT INTO #InputBuffer
133 | EXEC sp_executesql @sql;
134 | END TRY
135 | BEGIN CATCH
136 | PRINT 'InputBuffer Failed';
137 | END CATCH
138 |
139 | UPDATE b
140 | SET InputBuffer = COALESCE((SELECT TOP 1 EventInfo FROM #InputBuffer),'')
141 | FROM #OpenTrans b
142 | WHERE ID = @Id;
143 | END;
144 |
145 | --Convert Hex job_ids for SQL Agent jobs to names.
146 | WHILE EXISTS(SELECT 1 FROM #OpenTrans WHERE ProgramName LIKE 'SQLAgent - TSQL JobStep (Job 0x%')
147 | BEGIN
148 | SELECT @JobIdHex = '', @JobName = '';
149 |
150 | SELECT TOP 1 @ID = ID,
151 | @JobIdHex = SUBSTRING(ProgramName,30,34)
152 | FROM #OpenTrans
153 | WHERE ProgramName LIKE 'SQLAgent - TSQL JobStep (Job 0x%';
154 |
155 | SELECT @Sql = N'SELECT @JobName = name FROM msdb.dbo.sysjobs WHERE job_id = ' + @JobIdHex;
156 | EXEC sp_executesql @Sql, N'@JobName nvarchar(256) OUT', @JobName = @JobName OUT;
157 |
158 | UPDATE b
159 | SET ProgramName = LEFT(REPLACE(ProgramName,@JobIdHex,@JobName),128)
160 | FROM #OpenTrans b
161 | WHERE ID = @Id;
162 | END;
163 |
164 | -- Populate SessionInfo column with HTML details for sending email
165 | -- Since there's a bunch of logic here, code is more readable doing this separate than mashing it in with the rest of HTML email creation
166 | UPDATE t
167 | SET SessionInfo = (SELECT TransactionState =
168 | CASE TransactionState
169 | WHEN 1 THEN 'The transaction has not been initialized.'
170 | WHEN 3 THEN 'The transaction has been initialized but has not generated any log records.' -- We don�t alert on this status
171 | WHEN 4 THEN 'The transaction has generated log records.'
172 | WHEN 5 THEN 'The transaction has been prepared.'
173 | WHEN 10 THEN 'The transaction has been committed.'
174 | WHEN 11 THEN 'The transaction has been rolled back.'
175 | WHEN 12 THEN 'The transaction is being committed. In this state the log record is being generated, but it has not been materialized or persisted.'
176 | ELSE CAST(TransactionState as varchar)
177 | END,
178 | TransactionLengthMinutes = CONVERT(varchar(20),TransactionLengthMinutes,20),
179 | SessionID = Spid,
180 | DbName,
181 | LoginName,
182 | HostName,
183 | DbName,
184 | WaitResource,
185 | LoginTime = CONVERT(varchar(20),LoginTime,20),
186 | LastRequest = CONVERT(varchar(20),LastRequestStart,20),
187 | ProgramName
188 | FROM #OpenTrans t2
189 | WHERE t2.id = t.id
190 | FOR XML PATH ('Transaction') )
191 | FROM #OpenTrans t;
192 |
193 |
194 | --output results in debug mode:
195 | IF NOT EXISTS (SELECT 1 FROM #OpenTrans)
196 | SELECT 'No Open Transactions longer than ' + CAST(@DurationThreshold AS varchar(10)) + ' minutes exist' AS OpenTransactions;
197 | ELSE
198 | BEGIN
199 | SELECT * FROM #OpenTrans;
200 | END;
201 |
202 | GO
203 |
204 |
205 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_QueryStoreRegressedQueries.sql:
--------------------------------------------------------------------------------
1 | CREATE OR ALTER PROCEDURE dbo.Check_QueryStoreRegressedQueries
2 | --These get passed to sp_ineachdb to control which DBs we run for:
3 | @DbNamePattern nvarchar(300) = NULL,
4 | @DatabaseList nvarchar(max) = NULL,
5 | @DbExcludePattern nvarchar(300) = NULL,
6 | @DbExcludeList nvarchar(max) = NULL,
7 | --These are the params that control the data returned from Query Stor
8 | @results_row_count int = 25,
9 | @recent_start_time datetimeoffset(7) = NULL,
10 | @recent_end_time datetimeoffset(7) = NULL,
11 | @history_start_time datetimeoffset(7) = NULL,
12 | @history_end_time datetimeoffset(7) = NULL,
13 | @min_exec_count bigint = 2,
14 | -- AM2 special sauce
15 | @Debug bit = 0
16 | AS
17 | BEGIN
18 | SET NOCOUNT ON;
19 | --
20 | SELECT
21 | @recent_start_time = COALESCE(@recent_start_time ,DATEADD(HOUR,-2,GETDATE())),
22 | @recent_end_time = COALESCE(@recent_end_time ,GETDATE()),
23 | @history_start_time = COALESCE(@history_start_time ,DATEADD(DAY,-7,GETDATE())),
24 | @history_end_time = COALESCE(@history_end_time ,GETDATE());
25 |
26 | IF @Debug = 1
27 | BEGIN
28 | SELECT
29 | ResultsRowCount = @results_row_count ,
30 | RecentStartTime = @recent_start_time ,
31 | RecentEndTime = @recent_end_time ,
32 | BaselineStartTime = @history_start_time,
33 | BaselineEndTime = @history_end_time ,
34 | MinExecCount = @min_exec_count ;
35 | END;
36 |
37 | DECLARE @CheckSql nvarchar(max);
38 |
39 | SET @CheckSql = N'
40 | DECLARE
41 | @results_row_count int ,
42 | @recent_start_time datetimeoffset(7) ,
43 | @recent_end_time datetimeoffset(7) ,
44 | @history_start_time datetimeoffset(7) ,
45 | @history_end_time datetimeoffset(7) ,
46 | @min_exec_count bigint ;
47 |
48 | SELECT
49 | @results_row_count = ' + CONVERT(nvarchar(10),@results_row_count) + N',
50 | @recent_start_time = ' + QUOTENAME(CONVERT(nvarchar(35),@recent_start_time) , CHAR(39))+ N',
51 | @recent_end_time = ' + QUOTENAME(CONVERT(nvarchar(35),@recent_end_time) , CHAR(39))+ N',
52 | @history_start_time = ' + QUOTENAME(CONVERT(nvarchar(35),@history_start_time) , CHAR(39))+ N',
53 | @history_end_time = ' + QUOTENAME(CONVERT(nvarchar(35),@history_end_time) , CHAR(39))+ N',
54 | @min_exec_count = ' + CONVERT(nvarchar(10),@min_exec_count) + N';
55 |
56 | WITH hist AS (
57 | SELECT
58 | p.query_id query_id,
59 | ROUND(CONVERT(float, SUM(rs.avg_duration*rs.count_executions))*0.001,2) total_duration,
60 | SUM(rs.count_executions) count_executions,
61 | COUNT(distinct p.plan_id) num_plans
62 | FROM sys.query_store_runtime_stats rs
63 | JOIN sys.query_store_plan p ON p.plan_id = rs.plan_id
64 | WHERE NOT (rs.first_execution_time > @history_end_time OR rs.last_execution_time < @history_start_time)
65 | GROUP BY p.query_id
66 | ),
67 | recent AS (
68 | SELECT
69 | p.query_id query_id,
70 | ROUND(CONVERT(float, SUM(rs.avg_duration*rs.count_executions))*0.001,2) total_duration,
71 | SUM(rs.count_executions) count_executions,
72 | COUNT(distinct p.plan_id) num_plans
73 | FROM sys.query_store_runtime_stats rs
74 | JOIN sys.query_store_plan p ON p.plan_id = rs.plan_id
75 | WHERE NOT (rs.first_execution_time > @recent_end_time OR rs.last_execution_time < @recent_start_time)
76 | GROUP BY p.query_id )
77 | SELECT TOP (@results_row_count)
78 | results.query_id query_id,
79 | results.object_id object_id,
80 | ISNULL(OBJECT_NAME(results.object_id),'''') object_name,
81 | results.query_sql_text query_sql_text,
82 | results.additional_duration_workload additional_duration_workload,
83 | results.total_duration_recent total_duration_recent,
84 | results.total_duration_hist total_duration_hist,
85 | ISNULL(results.count_executions_recent, 0) count_executions_recent,
86 | ISNULL(results.count_executions_hist, 0) count_executions_hist,
87 | queries.num_plans num_plans
88 | FROM (
89 | SELECT
90 | hist.query_id query_id,
91 | q.object_id object_id,
92 | qt.query_sql_text query_sql_text,
93 | ROUND(CONVERT(float, recent.total_duration/recent.count_executions-hist.total_duration/hist.count_executions)*(recent.count_executions), 2) additional_duration_workload,
94 | ROUND(recent.total_duration, 2) total_duration_recent,
95 | ROUND(hist.total_duration, 2) total_duration_hist,
96 | recent.count_executions count_executions_recent,
97 | hist.count_executions count_executions_hist
98 | FROM hist
99 | JOIN recent ON hist.query_id = recent.query_id
100 | JOIN sys.query_store_query q ON q.query_id = hist.query_id
101 | JOIN sys.query_store_query_text qt ON q.query_text_id = qt.query_text_id
102 | WHERE recent.count_executions >= @min_exec_count
103 | ) AS results
104 | JOIN (
105 | SELECT
106 | p.query_id query_id,
107 | COUNT(distinct p.plan_id) num_plans
108 | FROM sys.query_store_plan p
109 | GROUP BY p.query_id
110 | HAVING COUNT(distinct p.plan_id) >= 1
111 | ) AS queries ON queries.query_id = results.query_id
112 | WHERE additional_duration_workload > 0
113 | ORDER BY additional_duration_workload DESC
114 | OPTION (MERGE JOIN);';
115 |
116 | PRINT @CheckSql;
117 |
118 | EXEC DBA.dbo.sp_ineachdb
119 | @command = @CheckSQL,
120 | @print_command = @Debug,
121 | @name_pattern = @DbNamePattern,
122 | @database_list = @DatabaseList,
123 | @exclude_pattern = @DbExcludePattern,
124 | @exclude_list = @DbExcludeList
125 |
126 |
127 | END
128 | GO
129 |
130 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_SessionLocking.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/amtwo/dba-database/78c223a24984dd51900437d9f167498771bee320/stored-procedures/dbo.Check_SessionLocking.sql
--------------------------------------------------------------------------------
/stored-procedures/dbo.Check_TableUsage.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Check_TableUsage'))
2 | EXEC ('CREATE PROCEDURE dbo.Check_TableUsage AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Check_TableUsage
7 | @DbName sysname,
8 | @SchemaName sysname,
9 | @TableName sysname
10 | AS
11 | /*************************************************************************************************
12 | AUTHOR: Andy Mallon
13 | CREATED: 20170916
14 | This checks index usage stats plus dependency references *from within the same db* to
15 | as one tool to help determine if a table is being actively used.
16 |
17 | PARAMETERS
18 | * @DbName - Name of the database to evaluate
19 | * @SchemaName - Name of the schema to evaluate. If NULL, checks all schemas.
20 | * @TableName - Name of the table to evaluate. Can be wildcarded.
21 | EXAMPLES:
22 |
23 | **************************************************************************************************
24 | MODIFICATIONS:
25 | 20150107 -
26 | **************************************************************************************************
27 | This code is licensed as part of Andy Mallon's DBA Database.
28 | https://github.com/amtwo/dba-database/blob/master/LICENSE
29 | ©2014-2020 ● Andy Mallon ● am2.co
30 | *************************************************************************************************/
31 | SET NOCOUNT ON;
32 |
33 | DECLARE @params nvarchar(500),
34 | @sql nvarchar(max);
35 |
36 | SELECT @params = N'@DbName sysname, @SchemaName sysname, @TableName sysname';
37 |
38 | SELECT @sql = N'SELECT TableName = schema_name(o.schema_id) + ''.'' + o.name,
39 | IndexName = i.name,
40 | us.user_seeks,
41 | us.user_scans,
42 | us.user_lookups,
43 | us.last_user_seek,
44 | us.last_user_scan,
45 | us.last_user_lookup,
46 | us.last_user_update
47 | FROM ' + QUOTENAME(@DbName) + N'.sys.objects o
48 | JOIN ' + QUOTENAME(@DbName) + N'.sys.indexes i ON o.object_id = i.object_id
49 | JOIN sys.dm_db_index_usage_stats us ON us.object_id = o.object_id AND us.index_id = i.index_id
50 | WHERE us.database_id = db_id(@DbName)
51 | AND o.schema_id = COALESCE(schema_id(@SchemaName),o.schema_id)
52 | AND o.name LIKE @TableName
53 | ORDER BY schema_name(o.schema_id) + ''.'' + o.name, i.name; ';
54 |
55 | EXEC sp_executesql @statement = @sql, @params = @params, @DbName = @DbName, @SchemaName = @SchemaName, @TableName = @TableName;
56 |
57 |
58 | --referencing code
59 | SELECT @sql = N'SELECT ReferencedTableName = schema_name(o.schema_id) + ''.'' + o.name,
60 | ReferencingEntity = r.referencing_schema_name + ''.'' + r.referencing_entity_name,
61 | r.referencing_id,
62 | r.referencing_class_desc,
63 | r.is_caller_dependent
64 | FROM ' + QUOTENAME(@DbName) + N'.sys.objects o
65 | CROSS APPLY ' + QUOTENAME(@DbName) + N'.sys.dm_sql_referencing_entities (schema_name(o.schema_id) + ''.'' + o.name, ''OBJECT'') r
66 | WHERE o.schema_id = COALESCE(schema_id(@SchemaName),o.schema_id)
67 | AND o.name LIKE @TableName
68 | ORDER BY schema_name(o.schema_id) + ''.'' + o.name; ';
69 |
70 | EXEC sp_executesql @statement = @sql, @params = @params, @DbName = @DbName, @SchemaName = @SchemaName, @TableName = @TableName;
71 |
72 |
73 | GO
74 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Cleanup_BackupHistory.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Cleanup_BackupHistory'))
2 | EXEC ('CREATE PROCEDURE dbo.Cleanup_BackupHistory AS SELECT ''This is a stub''')
3 | GO
4 |
5 | ALTER PROCEDURE dbo.Cleanup_BackupHistory
6 | @oldest_date datetime
7 | AS
8 | /*************************************************************************************************
9 | AUTHOR: Erik Darling
10 | CREATED: 20190329
11 | Originally sp_delete_backuphistory_pro
12 | This procedure cleans up the msdb backup history, using temp tables to manage what data needs
13 | to be deleted. This should improve performance compared to the standard MS-provided
14 | sp_delete_backuphistory.
15 |
16 | PARAMETERS
17 | * @oldest_date - datetime - Oldest date/time to retain backup history for
18 | **************************************************************************************************
19 | MODIFICATIONS:
20 | 20190329 - AM2 - Erik hates semicolons, but I love them.
21 |
22 | **************************************************************************************************
23 | This code is licensed as part of Andy Mallon's DBA Database.
24 | https://github.com/amtwo/dba-database/blob/master/LICENSE
25 | ©2014-2020 ● Andy Mallon ● am2.co
26 | *************************************************************************************************/
27 | BEGIN
28 | SET NOCOUNT ON;
29 |
30 | CREATE TABLE #backup_set_id (backup_set_id INT PRIMARY KEY CLUSTERED);
31 | CREATE TABLE #media_set_id (media_set_id INT PRIMARY KEY CLUSTERED);
32 | CREATE TABLE #restore_history_id (restore_history_id INT PRIMARY KEY CLUSTERED);
33 |
34 | INSERT INTO #backup_set_id WITH (TABLOCKX) (backup_set_id)
35 | SELECT DISTINCT backup_set_id
36 | FROM msdb.dbo.backupset
37 | WHERE backup_finish_date < @oldest_date;
38 |
39 | INSERT INTO #media_set_id WITH (TABLOCKX) (media_set_id)
40 | SELECT DISTINCT media_set_id
41 | FROM msdb.dbo.backupset
42 | WHERE backup_finish_date < @oldest_date;
43 |
44 | INSERT INTO #restore_history_id WITH (TABLOCKX) (restore_history_id)
45 | SELECT DISTINCT restore_history_id
46 | FROM msdb.dbo.restorehistory
47 | WHERE backup_set_id IN (SELECT backup_set_id
48 | FROM #backup_set_id);
49 |
50 | BEGIN TRANSACTION;
51 |
52 | DELETE FROM msdb.dbo.backupfile
53 | WHERE backup_set_id IN (SELECT backup_set_id
54 | FROM #backup_set_id);
55 | IF (@@error > 0)
56 | GOTO Quit;
57 |
58 | DELETE FROM msdb.dbo.backupfilegroup
59 | WHERE backup_set_id IN (SELECT backup_set_id
60 | FROM #backup_set_id);
61 | IF (@@error > 0)
62 | GOTO Quit;
63 |
64 | DELETE FROM msdb.dbo.restorefile
65 | WHERE restore_history_id IN (SELECT restore_history_id
66 | FROM #restore_history_id);
67 | IF (@@error > 0)
68 | GOTO Quit;
69 |
70 | DELETE FROM msdb.dbo.restorefilegroup
71 | WHERE restore_history_id IN (SELECT restore_history_id
72 | FROM #restore_history_id);
73 | IF (@@error > 0)
74 | GOTO Quit;
75 |
76 | DELETE FROM msdb.dbo.restorehistory
77 | WHERE restore_history_id IN (SELECT restore_history_id
78 | FROM #restore_history_id);
79 | IF (@@error > 0)
80 | GOTO Quit;
81 |
82 | DELETE FROM msdb.dbo.backupset
83 | WHERE backup_set_id IN (SELECT backup_set_id
84 | FROM #backup_set_id);
85 | IF (@@error > 0)
86 | GOTO Quit;
87 |
88 | DELETE msdb.dbo.backupmediafamily
89 | FROM msdb.dbo.backupmediafamily bmf
90 | WHERE bmf.media_set_id IN (SELECT media_set_id
91 | FROM #media_set_id)
92 | AND ((SELECT COUNT(*)
93 | FROM msdb.dbo.backupset
94 | WHERE media_set_id = bmf.media_set_id) = 0);
95 | IF (@@error > 0)
96 | GOTO Quit;
97 |
98 | DELETE msdb.dbo.backupmediaset
99 | FROM msdb.dbo.backupmediaset bms
100 | WHERE bms.media_set_id IN (SELECT media_set_id
101 | FROM #media_set_id)
102 | AND ((SELECT COUNT(*)
103 | FROM msdb.dbo.backupset
104 | WHERE media_set_id = bms.media_set_id) = 0);
105 | IF (@@error > 0)
106 | GOTO Quit;
107 |
108 | COMMIT TRANSACTION;
109 | RETURN;
110 |
111 | Quit:
112 | ROLLBACK TRANSACTION;
113 |
114 | END
115 | GO
--------------------------------------------------------------------------------
/stored-procedures/dbo.Cleanup_CommandLog.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Cleanup_CommandLog'))
2 | EXEC ('CREATE PROCEDURE dbo.Cleanup_CommandLog AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Cleanup_CommandLog
7 | @RetainDays_Backup int = 30,
8 | @RetainDays_DBCC int = 180,
9 | @RetainDays_Index int = 180,
10 | @RetainDays_Stats int = 180,
11 | @RetainDays_Other int = 20
12 | AS
13 | /*************************************************************************************************
14 | AUTHOR: Andy Mallon
15 | CREATED: 20150128
16 | This procedure cleans up data in the CommandLog table in the DBA database.
17 | The CommandLog table is part of Ola Hallengren's maintenance code, but we don't
18 | need those logs forever.
19 |
20 | We should delete in batches to minimize blocking.
21 | But maybe I'll do that in v 2.0
22 |
23 |
24 | PARAMETERS
25 | * @RetainDays - number of days to retain data on Monitor_xxx tables.
26 | **************************************************************************************************
27 | MODIFICATIONS:
28 | YYYYMMDD -
29 | **************************************************************************************************
30 | This code is licensed as part of Andy Mallon's DBA Database.
31 | https://github.com/amtwo/dba-database/blob/master/LICENSE
32 | ©2014-2020 ● Andy Mallon ● am2.co
33 | *************************************************************************************************/
34 | SET NOCOUNT ON;
35 |
36 | DECLARE @CleanupDateTime datetime2(0);
37 |
38 | --CommandLog Cleanup (for Ola Hallengren's logging table)
39 | --One ugly statement so just scan the table once.
40 | --
41 | DELETE c
42 | FROM dbo.CommandLog c
43 | WHERE 1=1
44 | AND (
45 | --Backups
46 | (StartTime <= DATEADD(dd,-1*@RetainDays_Backup,GETDATE())
47 | AND CommandType IN ('BACKUP_DATABASE','BACKUP_LOG','RESTORE_VERIFYONLY'))
48 | OR
49 | --DBCC
50 | (StartTime <= DATEADD(dd,-1*@RetainDays_DBCC,GETDATE())
51 | AND CommandType IN ('DBCC_CHECKDB'))
52 | OR
53 | --Index
54 | (StartTime <= DATEADD(dd,-1*@RetainDays_Index,GETDATE())
55 | AND CommandType IN ('ALTER_INDEX'))
56 | OR
57 | --Stats
58 | (StartTime <= DATEADD(dd,-1*@RetainDays_Stats,GETDATE())
59 | AND CommandType IN ('UPDATE_STATISTICS'))
60 | OR
61 | --Other
62 | (StartTime <= DATEADD(dd,-1*@RetainDays_Other,GETDATE())
63 | AND CommandType IN ('xp_create_subdir','xp_delete_file'))
64 | )
65 | GO
66 |
67 |
68 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Cleanup_Msdb.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Cleanup_Msdb'))
2 | EXEC ('CREATE PROCEDURE dbo.Cleanup_Msdb AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Cleanup_Msdb
7 | @RetainDays int = 30
8 | AS
9 | /*************************************************************************************************
10 | AUTHOR: Andy Mallon
11 | CREATED: 20150618
12 | This procedure cleans up data in msdb as part of standard retention.
13 | Call system stored procs when possible to do cleanup for us.
14 | Reorganize big tables after cleanup to get space back, or msdb will be huge.
15 |
16 | Cleanup based on code from MADK
17 |
18 | PARAMETERS
19 | * @RetainDays - number of days to retain data in msdb
20 | **************************************************************************************************
21 | MODIFICATIONS:
22 | YYYYMMDD -
23 | **************************************************************************************************
24 | This code is licensed as part of Andy Mallon's DBA Database.
25 | https://github.com/amtwo/dba-database/blob/master/LICENSE
26 | ©2014-2020 ● Andy Mallon ● am2.co
27 | *************************************************************************************************/
28 | SET NOCOUNT ON;
29 |
30 | DECLARE @RetainDate datetime2;
31 |
32 | SELECT @RetainDate = DATEADD(DAY,-1*@RetainDays,SYSDATETIME());
33 |
34 | -- Delete backup history
35 | EXEC dbo.Cleanup_BackupHistory @oldest_date = @RetainDate;
36 |
37 | -- Delete the SQL Server agent job history log
38 | EXEC msdb.dbo.sp_purge_jobhistory @oldest_date = @RetainDate;
39 |
40 | -- Delete the log of the sent items
41 | EXEC msdb.dbo.sysmail_delete_log_sp @logged_before = @RetainDate;
42 |
43 | -- Delete old mail items
44 | EXEC msdb.dbo.sysmail_delete_mailitems_sp @sent_before = @RetainDate;
45 |
46 | -- Run PBM cleanup
47 | -- Retention based on SELECT current_value FROM msdb.dbo.syspolicy_configuration WHERE name = N'HistoryRetentionInDays';
48 | -- Set retention with sp_syspolicy_set_config_history_retention [ @value = ] value
49 | EXEC msdb.dbo.sp_syspolicy_purge_history;
50 |
51 | --And do index maintenance
52 | -- if you aren't doing index maintenance on msdb, we'll force it here
53 | -- sometimes this prevents significant space bloat, esp on older versions
54 | DECLARE @Sql nvarchar(max) = N''
55 | SELECT @Sql = @Sql + N'ALTER INDEX ' + QUOTENAME(i.name) + N' ON [msdb].' + QUOTENAME(s.name) + N'.' + QUOTENAME(t.name) + N' REORGANIZE;' + CHAR(10)
56 | FROM msdb.sys.tables t
57 | JOIN msdb.sys.indexes i ON t.object_id = i.object_id
58 | JOIN msdb.sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
59 | JOIN msdb.sys.schemas s ON t.schema_id = s.schema_id
60 | WHERE p.rows > 1000;
61 |
62 |
63 | EXEC sys.sp_executesql @Sql
64 | GO
65 |
66 |
67 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Cleanup_TableByID.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Cleanup_TableByID'))
2 | EXEC ('CREATE PROCEDURE dbo.Cleanup_TableByID AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Cleanup_TableByID
7 | @DbName nvarchar(128),
8 | @SchemaName nvarchar(128) = 'dbo',
9 | @TableName nvarchar(128),
10 | @DateColumnName nvarchar(128),
11 | @IDColumnName nvarchar(128),
12 | @RetainDays int = 180,
13 | @ChunkSize int = 5000,
14 | @LoopWaitTime time = '00:00:00.5',
15 | @Debug bit = 0
16 | AS
17 | /*************************************************************************************************
18 | AUTHOR: Andy Mallon
19 | CREATED: 20171012
20 | This procedure cleans up data in the specified database & table.
21 | This procedure requires that the table have an ID column, AND some sort of date/time column.
22 | The ID is used for efficiency when doing deletes, and the date/time column is needed to
23 | determine when data ages out.
24 | **The date/time column should be the date inserted**
25 | The code assumes that both the ID & date/time columns are ever-increasing.
26 | This includes two controls to help minimize blocking and prevent the transaction log from
27 | growing during a large data cleanup. These two params can be adjusted to fine-tune the cleanup
28 | @ChunkSize controls how the max size of each delete operation.
29 | @LoopWaitTime introduces a wait between each delete to throttle activity between log backups
30 |
31 | KNOWN LIMITATION: If you reseed the identity column back to 0, you're going to delete all
32 | your data. All of it. Don't do that.
33 |
34 | PARAMETERS
35 | * @DbName - Name of the database containing the table
36 | * @SchemaName - Name of the schema containing the table
37 | * @TableName - Table to be cleaned up
38 | * @DateColumnName - Name of the date/time column to be used to determine cleanup
39 | * @IDColumnName - Name of the IDENTITY column, to be used for Chunking of deletes
40 | * @RetainDays - Number of days to retain data before cleaning up
41 | * @ChunkSize - Number of rows to delete in each batch
42 | * @LoopWaitTime - Time to wait after each delete.
43 | * @Debug - Print DELETE statements instead of actually deleting.
44 | **************************************************************************************************
45 | MODIFICATIONS:
46 | YYYYMMDD -
47 | **************************************************************************************************
48 | This code is licensed as part of Andy Mallon's DBA Database.
49 | https://github.com/amtwo/dba-database/blob/master/LICENSE
50 | ©2014-2020 ● Andy Mallon ● am2.co
51 | *************************************************************************************************/
52 | SET NOCOUNT ON;
53 |
54 | DECLARE @MaxID bigint;
55 | DECLARE @ChunkID bigint;
56 | DECLARE @Sql nvarchar(max);
57 |
58 | --Shuffle this into datetime datatype to make WAITFOR DELAY happy. Still use time on the param for better validation
59 | DECLARE @LoopWaitDateTime datetime = @LoopWaitTime;
60 | --Plop the quoted DB.Schema.Table into one variable so I don't screw it up later.
61 | DECLARE @SqlObjectName nvarchar(386) = QUOTENAME(@DbName) + N'.' + QUOTENAME(@SchemaName) + N'.' + QUOTENAME(@TableName);
62 |
63 | --
64 | -- Get the range of ID values we want to delete
65 | --
66 | SELECT @sql = N'SELECT @ChunkID = MIN(' + QUOTENAME(@IDColumnName) + N'), @MaxID = MAX(' + QUOTENAME(@IDColumnName) + N') FROM ' + @SqlObjectName + N' WHERE ' + QUOTENAME(@DateColumnName) + ' < DATEADD(DAY,-1*@RetainDays,GETDATE());';
67 |
68 | IF @Debug = 1
69 | BEGIN
70 | PRINT @sql;
71 | END;
72 | -- Even in Debug mode, we run this to get min/max values. We're not changing data yet.
73 | EXEC sp_executesql @stmt = @sql, @params = N'@RetainDays int, @ChunkID bigint OUT, @MaxID bigint OUT', @RetainDays = @RetainDays, @ChunkID = @ChunkID OUT, @MaxID = @MaxID OUT;
74 |
75 | --
76 | --Now loop through those values and delete
77 | --
78 | WHILE @ChunkID < @MaxID
79 | BEGIN
80 | SELECT @ChunkID = @ChunkID + @ChunkSize;
81 |
82 | SELECT @sql = N'DELETE TOP (@ChunkSize) x FROM ' + @SqlObjectName + N' AS x WHERE x.' + QUOTENAME(@IDColumnName) + N' < @ChunkID AND x.' + QUOTENAME(@IDColumnName) + N' < @MaxID;'
83 | --if we're not in debug mode, then run the delete
84 | IF @Debug = 0
85 | BEGIN
86 | EXEC sp_executesql @stmt = @sql, @params = N'@ChunkSize int, @ChunkID bigint, @MaxID bigint', @ChunkSize = @ChunkSize, @ChunkID = @ChunkID, @MaxID = @MaxID;
87 | WAITFOR DELAY @LoopWaitDateTime;
88 | END;
89 | --if we're in debug mode, just print the DELETE statement
90 | ELSE
91 | BEGIN
92 | PRINT @sql;
93 | END;
94 | END;
95 | GO
96 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Find_StringInModules.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Find_StringInModules'))
2 | EXEC ('CREATE PROCEDURE dbo.Find_StringInModules AS SELECT ''This is a stub''')
3 | GO
4 |
5 | ALTER PROCEDURE dbo.Find_StringInModules
6 | @search_string nvarchar(4000),
7 | @database_list nvarchar(max) = NULL,
8 | @case_sensitive bit = 0,
9 | @search_jobs bit = 0,
10 | @search_job_and_step_names bit = 0,
11 | @search_schema_names bit = 0,
12 | @search_object_names bit = 0,
13 | @search_column_names bit = 0,
14 | @search_parameter_names bit = 0,
15 | @search_system_objects bit = 0,
16 | @search_system_databases bit = 0,
17 | @search_everything bit = 0,
18 | @debug bit = 0
19 | AS
20 | /*************************************************************************************************
21 | AUTHOR: Aaron Bertrand
22 | CREATED: 20211018
23 | Searches procedures, triggers, views, etc. for a specified search string.
24 | This is NOT for searching within data stored inside string columns.
25 | Supports Unicode / supplementary characters in both search string and object/database names.
26 | Can optionally search for the search string contained in:
27 | - job step command text (even if it's not T-SQL)
28 | - job and step names
29 | - object, schema, column, and parameter names
30 | - system objects (including those within system databases)
31 |
32 | PARAMETERS
33 | @search_string The string you want to search for. You don't need to surround it with %.
34 | @database_list Comma-separated list of databases, e.g. N'AdventureWorks,msdb'.
35 | - currently this overrides @search_system_databases.
36 | @case_sensitive Set this to 1 if you want Andy to only match Andy and not ANDy or andY.
37 | @search_jobs Set to 1 if you want to search the command text of all job steps.
38 | @search_job_and_step_names Set to 1 if you want to search within job and step names.
39 | Will only work if @search_jobs is also set to 1.
40 | @search_schema_names Set to 1 if you want to search within schema names.
41 | @search_object_names Set to 1 if you want to search within object names.
42 | @search_column_names Set to 1 if you want to search within column names.
43 | @search_parameter_names Set to 1 if you want to search within parameter names.,
44 | @search_system_objects Set to 1 if you want to search within system objects.
45 | - this will return multiple hits for system objects that are in every database.
46 | @search_system_databases Set to 1 if you want to search master, model, msdb, and tempdb.
47 | - this won't search the resource database (or objects that require DAC).
48 | @search_everything Overrides all of the above bit parameters to 1.
49 | @debug Set to 1 if you just want print output of the commands.
50 |
51 | KNOWN ISSUES
52 | The split function uses XML, so if @database_list contains a database name with non-XML-safe
53 | characters (e.g. < or &), the convert to XML will fail.
54 |
55 | **************************************************************************************************
56 | This code is licensed as part of Andy Mallon's DBA Database.
57 | https://github.com/amtwo/dba-database/blob/master/LICENSE
58 | ©2014-2021 ● Andy Mallon ● am2.co
59 | *************************************************************************************************/
60 | BEGIN
61 | SET NOCOUNT ON;
62 |
63 | IF @search_everything = 1
64 | BEGIN
65 | SELECT
66 | @search_jobs = 1,
67 | @search_job_and_step_names = 1,
68 | @search_object_names = 1,
69 | @search_schema_names = 1,
70 | @search_column_names = 1,
71 | @search_parameter_names = 1,
72 | @search_system_objects = 1,
73 | @search_system_databases = 1;
74 | END
75 |
76 | DECLARE @sql nvarchar(max),
77 | @template nvarchar(max),
78 | @exec nvarchar(1024),
79 | @all_text nvarchar(128),
80 | @coll_text nvarchar(128);
81 |
82 | SELECT @sql = N'',
83 | @template = N'',
84 | @all_text = CASE @search_system_objects
85 | WHEN 1 THEN N'all_' ELSE N'' END,
86 | @coll_text = CASE @case_sensitive
87 | WHEN 1 THEN N'Latin1_General_100_CS_AS_SC'
88 | WHEN 0 THEN N'Latin1_General_100_CI_AS_SC'
89 | END;
90 |
91 | CREATE TABLE #o
92 | (
93 | [database] nvarchar(130),
94 | [schema] nvarchar(130),
95 | [object] nvarchar(130),
96 | [type] nvarchar(130),
97 | create_date datetime,
98 | modify_date datetime,
99 | column_name nvarchar(130),
100 | param_name nvarchar(130),
101 | definition xml
102 | );
103 |
104 | SET @search_string = N'%' + @search_string + N'%';
105 |
106 | SET @template = N'
107 | SELECT [database] = DB_NAME(),
108 | [schema] = s.name,
109 | [object] = o.name,
110 | [type] = o.type_desc,
111 | o.create_date,
112 | o.modify_date,
113 | [column_name] = $col$,
114 | [param_name] = $param$,
115 | definition = CONVERT(xml, '''')
118 | FROM sys.$all$objects AS o
119 | INNER JOIN sys.schemas AS s
120 | ON o.[schema_id] = s.[schema_id]';
121 |
122 |
123 | SET @sql = @sql + REPLACE(REPLACE(@template, N'$col$', N'NULL'), N'$param$', N'NULL')
124 | + N'
125 | ' + N' WHERE OBJECT_DEFINITION(o.[object_id]) COLLATE $coll$
126 | ' + N' LIKE @s COLLATE $coll$';
127 |
128 | SET @sql = @sql + CASE @search_schema_names WHEN 1 THEN N'
129 | OR s.name COLLATE $coll$
130 | LIKE @s COLLATE $coll$' ELSE N'' END;
131 |
132 | SET @sql = @sql + CASE @search_object_names WHEN 1 THEN N'
133 | OR o.name COLLATE $coll$
134 | LIKE @s COLLATE $coll$' ELSE N'' END;
135 |
136 | SET @sql = @sql + CASE @search_column_names WHEN 1 THEN N';
137 | ' + REPLACE(REPLACE(@template, N'$col$', N'c.name'),N'$param$',N'NULL')
138 | + N'
139 | INNER JOIN sys.$all$columns AS c ON o.[object_id] = c.[object_id]
140 | AND c.name COLLATE $coll$
141 | LIKE @s COLLATE $coll$;' ELSE N'' END;
142 |
143 | SET @sql = @sql + CASE @search_parameter_names WHEN 1 THEN N';
144 | ' + REPLACE(REPLACE(@template, N'$col$', N'NULL'),N'$param$',N'p.name')
145 | + N'
146 | INNER JOIN sys.$all$parameters AS p ON o.[object_id] = p.[object_id]
147 | AND p.name COLLATE $coll$
148 | LIKE @s COLLATE $coll$;' ELSE N'' END;
149 |
150 | SET @sql = REPLACE(REPLACE(@sql, N'$coll$', @coll_text), N'$all$', @all_text);
151 |
152 | DECLARE @db sysname, @c cursor;
153 |
154 | SET @c = cursor FORWARD_ONLY STATIC READ_ONLY FOR
155 | SELECT QUOTENAME(name) FROM sys.databases AS d
156 | LEFT OUTER JOIN dbo.fn_split(@database_list, N',') AS s ON 1 = 1
157 | WHERE
158 | (
159 | LOWER(d.name) = LOWER(LTRIM(RTRIM(s.value)))
160 | OR NULLIF(RTRIM(@database_list), N'') IS NULL
161 | )
162 | AND d.database_id >= CASE @search_system_databases
163 | WHEN 1 THEN 1 ELSE 5 END
164 | AND d.database_id < 32767
165 | AND d.state = 0;
166 |
167 | OPEN @c;
168 |
169 | FETCH NEXT FROM @c INTO @db;
170 |
171 | WHILE @@FETCH_STATUS = 0
172 | BEGIN
173 | SET @exec = @db + N'.sys.sp_executesql';
174 |
175 | IF @debug = 1
176 | BEGIN
177 | RAISERROR(N'Running dynamic SQL on %s:', 1, 0, @db);
178 | PRINT @sql;
179 | END
180 | ELSE
181 | BEGIN
182 | INSERT #o
183 | (
184 | [database],
185 | [schema],
186 | [object],
187 | [type],
188 | create_date,
189 | modify_date,
190 | column_name,
191 | param_name,
192 | definition
193 | )
194 | EXEC @exec @sql, N'@s nvarchar(4000)', @s = @search_string;
195 | END
196 |
197 | FETCH NEXT FROM @c INTO @db;
198 | END
199 |
200 | IF @debug = 0
201 | BEGIN
202 | SELECT [database],
203 | [schema],
204 | [object],
205 | [type],
206 | create_date,
207 | modify_date,
208 | column_name,
209 | param_name,
210 | definition
211 | FROM #o
212 | ORDER BY [database], [schema], [object], [column_name], [param_name];
213 | END
214 |
215 | /* jobs */
216 |
217 | IF @search_jobs = 1
218 | BEGIN
219 | SET @template = N'SELECT
220 | job_name = j.name,
221 | s.step_id,
222 | s.step_name,
223 | j.date_created,
224 | j.date_modified,
225 | [command_with_use] = CONVERT(xml, N'''')
228 | FROM msdb.dbo.sysjobs AS j
229 | INNER JOIN msdb.dbo.sysjobsteps AS s
230 | ON j.job_id = s.job_id
231 | WHERE s.command COLLATE $coll$
232 | LIKE @s COLLATE $coll$'
233 | + CASE @search_job_and_step_names WHEN 1 THEN
234 | N' OR j.name COLLATE $coll$
235 | LIKE @s COLLATE $coll$
236 | OR s.step_name COLLATE $coll$
237 | LIKE @s COLLATE $coll$'
238 | ELSE N'' END
239 | + N' ORDER BY j.name, s.step_id;';
240 |
241 | SET @sql = REPLACE(@template, N'$coll$', @coll_text);
242 |
243 | IF @debug = 1
244 | BEGIN
245 | PRINT N'Running this for jobs:';
246 | PRINT @sql;
247 | END
248 | ELSE
249 | BEGIN
250 | EXEC sys.sp_executesql @sql, N'@s nvarchar(4000)', @s = @search_string;
251 | END
252 | END
253 | END
254 | GO
255 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Get_DetachAttachSql.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Get_DetachAttachSql'))
2 | EXEC ('CREATE PROCEDURE dbo.Get_DetachAttachSql AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Get_DetachAttachSql
7 | @name_pattern nvarchar(300) = N'%',
8 | @database_list nvarchar(max) = NULL,
9 | @exclude_pattern nvarchar(300) = NULL,
10 | @exclude_list nvarchar(max) = 'master,tempdb,model,msdb,distribution,dba',
11 | @recovery_model_desc nvarchar(120) = NULL,
12 | @compatibility_level tinyint = NULL,
13 | @state_desc nvarchar(120) = N'ONLINE',
14 | @is_read_only bit = 0
15 |
16 | AS
17 | /*************************************************************************************************
18 | AUTHOR: Andy Mallon
19 | CREATED: 20240304
20 | This procedure returns a table with the detach & attach SQL code for each database.
21 | Designed to be used for server migrations or other work where you may need to
22 | detach and/or attach every database on an instance.
23 |
24 | Please don't abuse detach & attach. This isn't how you back up a database, y'all.
25 |
26 | PARAMETERS
27 | All parameters are inherited from `sp_ineachdb`, and used to control which database(s)
28 | are included in the output.
29 | **************************************************************************************************
30 | MODIFICATIONS:
31 | YYYYMMDDD - Initials - Description of changes
32 | **************************************************************************************************
33 | This code is licensed as part of Andy Mallon's DBA Database.
34 | https://github.com/amtwo/dba-database/blob/master/LICENSE
35 | ©2014-2020 ● Andy Mallon ● am2.co
36 | *************************************************************************************************/
37 | SET NOCOUNT ON;
38 | BEGIN
39 | DROP TABLE IF EXISTS #AttachSql;
40 | CREATE TABLE #AttachSql (
41 | DatabaseId int,
42 | DbName sysname,
43 | AttachSql nvarchar(max)
44 | );
45 |
46 | DECLARE @ineachdb_sql nvarchar(max);
47 |
48 | SET @ineachdb_sql = N'DECLARE @sql nvarchar(max) = N''CREATE DATABASE '' + QUOTENAME(DB_NAME()) + N''
49 | ON '';
50 |
51 | SELECT @sql += N'' (FILENAME = '' + QUOTENAME(physical_name,CHAR(39)) + N''),'' + CHAR(13) + CHAR(10)
52 | FROM sys.database_files;
53 |
54 | SET @sql = LEFT(@sql,LEN(@sql)-1)
55 |
56 | SET @sql += N'' FOR ATTACH;''
57 |
58 | SELECT db_id(), db_name(), @sql';
59 |
60 | INSERT INTO #AttachSql (DatabaseId, DbName, AttachSql)
61 | EXEC dbo.sp_ineachdb
62 | @command = @ineachdb_sql,
63 | @name_pattern = @name_pattern,
64 | @database_list = @database_list,
65 | @exclude_pattern = @exclude_pattern,
66 | @exclude_list = @exclude_list,
67 | @recovery_model_desc = @recovery_model_desc,
68 | @compatibility_level = @compatibility_level,
69 | @state_desc = @state_desc,
70 | @is_read_only = @is_read_only;
71 |
72 |
73 | WITH DetachSql AS (
74 | SELECT
75 | DatabaseId = database_id,
76 | DbName = name,
77 | DetachSQL = N'EXEC sp_detach_db @dbname = ' + QUOTENAME(name) + ', @skipchecks = ''true'';'
78 | FROM sys.databases
79 | )
80 | SELECT a.DatabaseId, a.DbName, d.DetachSQL, a.AttachSql
81 | FROM #AttachSql AS a
82 | JOIN DetachSql AS d ON d.DatabaseId = a.DatabaseId
83 | ORDER BY a.DbName;
84 | END
85 |
86 | GO
87 |
88 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.PlanGuide_SetHintForProcedureStatement.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.PlanGuide_SetHintForProcedureStatement'))
2 | EXEC ('CREATE PROCEDURE dbo.PlanGuide_SetHintForProcedureStatement AS SELECT ''This is a stub''')
3 | GO
4 |
5 | ALTER PROCEDURE dbo.PlanGuide_SetHintForProcedureStatement
6 | @DbName sysname,
7 | @ProcedureSchema sysname,
8 | @ProcedureName sysname,
9 | @StatementMatchText nvarchar(max),
10 | @PlanGuideName sysname,
11 | @HintText nvarchar(1000),
12 | @DropExisting bit = 0,
13 | @Debug bit = 0
14 | AS
15 | /*************************************************************************************************
16 | AUTHOR: Andy Mallon
17 | CREATED: 20231216
18 | This procedure creates (or replaces) a plan guide for a statement within a stored procedure.
19 | Plan guides require an **EXACT** (binary) match on query text in order for it to work.
20 | This can sometimes be tricky to get correct, particularly with non-printing characters such
21 | as varying line endings (CRLF vs LF). This procedure resolves that by allowing you to use a
22 | wildcarded string to identify the statement text programatically, then constructing the plan
23 | guide via dynamic SQL to ensure an exact match to the statement.
24 |
25 | To achieve a perfect match, this procedure pulls the directly from sys.dm_exec_query_stats,
26 | which requires that the stored procedure be executed at least once to generate the query
27 | stats data to pull from. If the procedure has not been executed, this procedure will fail
28 | to identify a matching statement.
29 |
30 | PARAMETERS
31 | * @DbName - Name of the database to create the Plan Guide in
32 | * @ProcedureSchema - Together with @ProcedureName identifies the procedure that contains the statement
33 | for which the plan guide will be created.
34 | * @ProcedureName - Together with @ProcedureSchema identifies the procedure that contains the statement
35 | for which the plan guide will be created.
36 | * StatementMatchText - Wildcarded portion of the statement that will uniquely identify the statement
37 | within the procedure text. By default does a "Begins with%" search.
38 | * PlanGuideName - Name of the plan guide to create (or modify). When modifying a plan guide,
39 | you must also set @DropExisting = 1.
40 | * HintText - The text of the hint you want to use in the plan guide.
41 | * DropExisting - Default 0 (false) - When modifying an existing plan guide, you must also set @DropExisting = 1.
42 | * Debug - Default 0 (false) - Instead of creating a plan guide, outputs information, including
43 | dynamic SQL statements that are/would be run.
44 |
45 | **************************************************************************************************
46 | This code is licensed as part of Andy Mallon's DBA Database.
47 | https://github.com/amtwo/dba-database/blob/master/LICENSE
48 | ©2014-2020 ● Andy Mallon ● am2.co
49 | *************************************************************************************************/
50 |
51 |
52 | SET NOCOUNT ON;
53 | BEGIN
54 |
55 | --
56 | DECLARE @StatementFullText nvarchar(max);
57 | DECLARE @ProcedureFQN nvarchar(1000);
58 | DECLARE @Sql nvarchar(max);
59 | DECLARE @ExistingGuide bit;
60 |
61 | --TODO check if a plan guide with this name already exists;
62 |
63 | SET @StatementMatchText += N'%';
64 | SET @ProcedureFQN = QUOTENAME(@DbName) + '.' + QUOTENAME(@ProcedureSchema) + '.' + QUOTENAME(@ProcedureName);
65 |
66 | DROP TABLE IF EXISTS #QueryDetails;
67 | CREATE TABLE #QueryDetails(
68 | Id int identity(1,1) PRIMARY KEY CLUSTERED,
69 | DbName sysname,
70 | StatementText nvarchar(max),
71 | SqlHandle varbinary(64),
72 | StatementStartOffset int,
73 | StatementEndOffset int,
74 | PlanHandle varbinary(64)
75 | );
76 |
77 | WITH QueryDetails AS (
78 | SELECT DbName = t.DbName,
79 | StatementText = t.StatementText,
80 | qs.*
81 | FROM sys.dm_exec_procedure_stats ps
82 | JOIN sys.dm_exec_query_stats qs ON ps.sql_handle = qs.sql_handle
83 | CROSS APPLY dbo.ParseStatementByOffset(ps.sql_handle, qs.statement_start_offset, qs.statement_end_offset) t
84 | WHERE ps.object_id = object_id(@ProcedureFQN)
85 | AND ps.database_id = db_id(@DbName)
86 | )
87 | INSERT INTO #QueryDetails(DbName, StatementText, SqlHandle, StatementStartOffset, StatementEndOffset, PlanHandle)
88 | SELECT DbName, StatementText, sql_handle, statement_start_offset, statement_end_offset, plan_handle
89 | FROM QueryDetails
90 | WHERE StatementText LIKE @StatementMatchText;
91 |
92 | --TODO need to handle cases where there are != 1 rows returned.
93 | IF (SELECT COUNT(DISTINCT StatementText) FROM #QueryDetails) > 1
94 | BEGIN
95 | SELECT * FROM #QueryDetails;
96 | THROW 60000, 'There are multiple statements that match this @StatementMatchText. Please be more specific. @StatementMatchText must return exactly 1 row.',1;
97 | END;
98 |
99 | IF (SELECT COUNT(DISTINCT StatementText) FROM #QueryDetails) = 0
100 | BEGIN
101 | SELECT * FROM #QueryDetails;
102 | THROW 60001, 'There are zero statements that match this criteria. Criteria must return exactly 1 row from the plan cache.',1;
103 | END;
104 |
105 |
106 | IF (@Debug = 1)
107 | BEGIN
108 | SELECT * FROM #QueryDetails;
109 | END;
110 |
111 | SELECT TOP 1
112 | @StatementFullText = StatementText
113 | FROM #QueryDetails;
114 |
115 | IF (@Debug = 1)
116 | BEGIN
117 | SELECT FullStatementText = @StatementFullText;
118 | END;
119 |
120 | --Check for existing guides & drop/continue/error based on existence & @DropExisting
121 | SET @sql = 'SELECT @ExistingGuide = COUNT(*) FROM ' + QUOTENAME(@DbName) + '.sys.plan_guides WHERE name = @PlanGuideName;'
122 | EXEC sys.sp_executesql @stmt = @sql,
123 | @params = N'@PlanGuideName sysname, @ExistingGuide int OUT',
124 | @PlanGuideName = @PlanGuideName,
125 | @ExistingGuide = @ExistingGuide OUT;
126 |
127 | IF (@ExistingGuide = 1 AND @DropExisting = 0)
128 | BEGIN
129 | SET @sql = 'SELECT * FROM ' + QUOTENAME(@DbName) + '.sys.plan_guides WHERE name = @PlanGuideName;';
130 | EXEC sys.sp_executesql @stmt = @sql,
131 | @params = N'@PlanGuideName sysname',
132 | @PlanGuideName = @PlanGuideName;
133 | THROW 60002, 'An existing Plan Guide already exists with this name. Choose a new name or use @DropExisting=1.', 1;
134 | END;
135 |
136 | IF (@ExistingGuide = 1 AND @DropExisting = 1)
137 | BEGIN
138 | SET @sql = 'EXEC ' + QUOTENAME(@DbName) + '.sys.sp_control_plan_guide N''DROP'', @PlanGuideName;';
139 |
140 | IF (@Debug = 0)
141 | BEGIN
142 | EXEC sys.sp_executesql @stmt = @sql,
143 | @params = N'@PlanGuideName sysname',
144 | @PlanGuideName = @PlanGuideName;
145 | END;
146 | IF (@Debug = 1)
147 | BEGIN
148 | PRINT @sql;
149 | PRINT '@PlanGuideName = ' + @PlanGuideName;
150 | END;
151 | END;
152 |
153 | --OK, now finally create the plan guide!
154 | SET @sql = 'EXEC ' + QUOTENAME(@DbName) + '.sys.sp_create_plan_guide
155 | @name = @PlanGuideName,
156 | @stmt = @StatementFullText,
157 | @type = N''OBJECT'',
158 | @module_or_batch = @ProcedureName,
159 | @params = NULL,
160 | @hints = @HintText;'
161 |
162 | IF (@Debug = 1)
163 | BEGIN
164 | PRINT @sql;
165 | END;
166 | IF (@Debug = 0)
167 | BEGIN
168 | EXEC sys.sp_executesql
169 | @stmt = @sql,
170 | @params = N'@PlanGuideName sysname, @StatementFullText nvarchar(max), @ProcedureName sysname, @HintText nvarchar(1000)',
171 | @PlanGuideName = @PlanGuideName,
172 | @StatementFullText = @StatementFullText,
173 | @ProcedureName = @ProcedureName,
174 | @HintText = @HintText;
175 | END;
176 | END;
177 |
178 | GO
179 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Repl_AddAllTables.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Repl_AddAllTables'))
2 | EXEC ('CREATE PROCEDURE dbo.Repl_AddAllTables AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Repl_AddAllTables
7 | @PubDbName nvarchar(256),
8 | @PublicationName nvarchar(256),
9 | @ExcludeTables nvarchar(256) = NULL,
10 | @Debug bit = 0
11 | AS
12 | /*************************************************************************************************
13 | AUTHOR: Andy Mallon
14 | CREATED: 20140101
15 | This procedure loops through all tables in the database and adds them to replication.
16 | Made this for a specific use case, so its not glamorous.
17 |
18 | PARAMETERS
19 | * The @ExcludeTables parameter requires the value be a comma-separated, single-quoted list.
20 | That's kind of icky, but we can make this more robust in v 2.0. I don't think I'll use this exclude list very often
21 | **************************************************************************************************
22 | MODIFICATIONS:
23 | YYYYMMDDD - Initials - Description of changes
24 | **************************************************************************************************
25 | This code is licensed as part of Andy Mallon's DBA Database.
26 | https://github.com/amtwo/dba-database/blob/master/LICENSE
27 | ©2014-2020 ● Andy Mallon ● am2.co
28 | *************************************************************************************************/
29 | SET NOCOUNT ON;
30 |
31 | DECLARE @sql nvarchar(max);
32 | DECLARE @ArticleName nvarchar(256);
33 |
34 | CREATE TABLE #article (
35 | ID int identity(1,1) PRIMARY KEY,
36 | ArticleName nvarchar(256));
37 |
38 | --Get all unpublished tables that have a PK
39 | SET @sql = N'SELECT t.name
40 | FROM ' + QUOTENAME(@PubDbName) + '.sys.objects t
41 | JOIN ' + QUOTENAME(@PubDbName) + '.sys.objects pk ON pk.parent_object_id = t.object_id
42 | WHERE t.is_ms_shipped = 0
43 | AND t.is_published = 0
44 | AND t.name NOT IN (' + COALESCE(@ExcludeTables,'''''') + ')
45 | AND t.type = ''U'';';
46 |
47 | INSERT INTO #article
48 | EXEC sys.sp_executesql @sql;
49 |
50 | --Call Repl_AddArticle in a loop for every table in #article
51 | --Debug mode works by passing parameter through to Repl_AddArticle to print statement
52 |
53 | DECLARE article_cur CURSOR FOR
54 | SELECT DISTINCT ArticleName FROM #article;
55 |
56 | OPEN article_cur;
57 | FETCH NEXT FROM article_cur INTO @ArticleName;
58 |
59 | WHILE @@FETCH_STATUS = 0
60 | BEGIN
61 | EXEC dbo.Repl_AddArticle
62 | @PubDbName = @PubDbName,
63 | @PublicationName = @PublicationName,
64 | @ArticleName = @ArticleName,
65 | @Debug = @Debug
66 | FETCH NEXT FROM article_cur INTO @ArticleName;
67 | END;
68 |
69 | CLOSE article_cur;
70 | DEALLOCATE article_cur;
71 |
72 | DROP TABLE #article;
73 | GO
74 |
75 |
76 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Repl_AddArticle.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Repl_AddArticle'))
2 | EXEC ('CREATE PROCEDURE dbo.Repl_AddArticle AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Repl_AddArticle
7 | @PubDbName nvarchar(256),
8 | @PublicationName nvarchar(256),
9 | @ArticleName nvarchar(256),
10 | @SchemaOption binary(8) NULL,
11 | @Debug bit = 0
12 | AS
13 | /*************************************************************************************************
14 | AUTHOR: Andy Mallon
15 | CREATED: 20140101
16 | This procedure adds a specific article to a given publication.
17 | The @SchemaOption parameter is hard-coded and might not be the right mask for everyone.
18 |
19 | PARAMETERS
20 | *
21 | **************************************************************************************************
22 | MODIFICATIONS:
23 | YYYYMMDDD - Initials - Description of changes
24 | **************************************************************************************************
25 | This code is licensed as part of Andy Mallon's DBA Database.
26 | https://github.com/amtwo/dba-database/blob/master/LICENSE
27 | ©2014-2020 ● Andy Mallon ● am2.co
28 | *************************************************************************************************/
29 | SET NOCOUNT ON
30 | ---------------------
31 | DECLARE @sql nvarchar(max);
32 | DECLARE @OK bit = 1;
33 |
34 | IF @SchemaOption IS NULL
35 | BEGIN
36 | SELECT @SchemaOption = VarbinaryValue
37 | FROM dbo.Config
38 | WHERE ConfigCode = 'REPLSCMOPT';
39 | END;
40 |
41 | --Check to see if article exists in Published database
42 | SET @sql = N'SELECT @OK = 0
43 | WHERE NOT EXISTS (SELECT 1 FROM [' + @PubDbName + N'].sys.objects WHERE name = @ArticleName);'
44 | EXEC sys.sp_executesql @sql, N'@ArticleName sysname, @OK bit OUTPUT', @ArticleName = @ArticleName, @OK = @OK OUTPUT;
45 | IF @OK = 0
46 | BEGIN
47 | RAISERROR ('Article does not exist in specified database',16,1);
48 | RETURN -1;
49 | END
50 |
51 | --Check that the article is not already published
52 | --If already published, don't error, just print the info.
53 | SET @sql = N'SELECT @OK = 0
54 | WHERE EXISTS (SELECT 1 FROM [' + @PubDbName + N'].sys.objects
55 | WHERE name = @ArticleName AND is_published = 1);'
56 | EXEC sys.sp_executesql
57 | @stmt = @sql,
58 | @params = N'@ArticleName sysname, @OK bit OUTPUT',
59 | @ArticleName = @ArticleName,
60 | @OK = @OK OUTPUT;
61 | IF @OK = 0
62 | BEGIN
63 | RAISERROR ('Article is already published',10,1);
64 | RETURN 0;
65 | END
66 |
67 | --and now call the system sproc to actually add the article to publication
68 | DECLARE @InsertCommand nvarchar(128) = N'CALL sp_MSins_dbo' + @ArticleName;
69 | DECLARE @UpdateCommand nvarchar(128) = N'CALL sp_MSupd_dbo' + @ArticleName;
70 | DECLARE @DeleteCommand nvarchar(128) = N'CALL sp_MSdel_dbo' + @ArticleName;
71 |
72 |
73 | SET @sql = N'EXEC ' + QUOTENAME(@PubDbName) + N'.sys.sp_addarticle
74 | @publication = @PublicationName,
75 | @article = @ArticleName,
76 | @source_owner = N''dbo'',
77 | @source_object = @ArticleName,
78 | @type = N''logbased'',
79 | @description = null,
80 | @creation_script = null,
81 | @pre_creation_cmd = N''drop'',
82 | @schema_option = @SchemaOption,
83 | @identityrangemanagementoption = N''manual'',
84 | @destination_table = @ArticleName,
85 | @destination_owner = N''dbo'',
86 | @vertical_partition = N''false'',
87 | @ins_cmd = @InsertCommand,
88 | @upd_cmd = @UpdateCommand,
89 | @del_cmd = @DeleteCommand'
90 |
91 | IF @Debug = 0
92 | EXEC sys.sp_executesql @stmt = @sql,
93 | @params = N'@PublicationName nvarchar(128),
94 | @ArticleName nvarchar(128),
95 | @SchemaOption binary(8),
96 | @InsertCommand nvarchar(128),
97 | @UpdateCommand nvarchar(128),
98 | @DeleteCommand nvarchar(128)',
99 | @PublicationName = @PublicationName,
100 | @ArticleName = @ArticleName,
101 | @SchemaOption = @SchemaOption,
102 | @InsertCommand = @InsertCommand,
103 | @UpdateCommand = @UpdateCommand,
104 | @DeleteCommand = @DeleteCommand;
105 | ELSE
106 | PRINT @sql;
107 | PRINT N' Publication: ' + @PublicationName
108 | PRINT N' Article: ' + @ArticleName
109 | PRINT N' SchemaOption: ' + CONVERT(nvarchar(max), @SchemaOption)
110 | PRINT N' InsertCommand: ' + @InsertCommand
111 | PRINT N' UpdateCommand: ' + @UpdateCommand
112 | PRINT N' DeleteCommand: ' + @DeleteCommand
113 |
114 | GO
115 |
116 |
117 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Repl_CreatePublication.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Repl_CreatePublication'))
2 | EXEC ('CREATE PROCEDURE dbo.Repl_CreatePublication AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Repl_CreatePublication
7 | @PubDbName nvarchar(256),
8 | @PublicationName nvarchar(256),
9 | @Debug bit = 0
10 | AS
11 | /*************************************************************************************************
12 | AUTHOR: Andy Mallon
13 | CREATED: 20140101
14 | This procedure creates a publication using the specific defaults that I needed to use at the time.
15 |
16 | PARAMETERS
17 | *
18 | **************************************************************************************************
19 | MODIFICATIONS:
20 | YYYYMMDDD - Initials - Description of changes
21 | **************************************************************************************************
22 | This code is licensed as part of Andy Mallon's DBA Database.
23 | https://github.com/amtwo/dba-database/blob/master/LICENSE
24 | ©2014-2020 ● Andy Mallon ● am2.co
25 | *************************************************************************************************/
26 | SET NOCOUNT ON;
27 | ---------------------
28 | DECLARE @sql nvarchar(max);
29 | DECLARE @Publisher nvarchar(256);
30 | DECLARE @Distributor nvarchar(256);
31 |
32 | --Figure out what server is the distributor. We'll need it later if this DB is in an AG
33 | SELECT @Distributor = data_source
34 | FROM master.sys.servers
35 | where name = 'repl_distributor';
36 |
37 | IF @Distributor IS NULL
38 | BEGIN
39 | RAISERROR ('Server is not configured for replication. Configure a distributor and try again.',16,1)
40 | RETURN -1;
41 | END;
42 |
43 | --@Publisher is either the AG name or the instance name
44 | --HACK - Wrapping this in an IF statement to support 2008
45 | IF (object_id('sys.availability_groups') IS NOT NULL)
46 | BEGIN
47 | SELECT @Publisher = ag.name
48 | FROM master.sys.databases d
49 | JOIN master.sys.availability_databases_cluster agd ON d.group_database_id = agd.group_database_id
50 | JOIN master.sys.availability_groups ag ON agd.group_id = ag.group_id
51 | WHERE d.name = @PubDbName
52 | END;
53 |
54 | SELECT @Publisher = COALESCE(@Publisher,@@SERVERNAME)
55 |
56 | --Enable DB as replication publisher
57 | SET @sql = 'USE [' + @PubDbName + ']' + CHAR(10) + CHAR(13);
58 |
59 | SET @sql = @sql + N'EXEC sp_replicationdboption
60 | @dbname = N''' + @PubDbName + N''',
61 | @optname = N''publish'',
62 | @value = N''true'';' + CHAR(10)+CHAR(13) ;
63 |
64 | IF @Debug = 0
65 | EXEC sp_executesql @sql;
66 | ELSE
67 | PRINT @sql;
68 |
69 | -- Adding the transactional publication
70 | SET @sql = 'USE [' + @PubDbName + '];' + CHAR(10) + CHAR(13);
71 |
72 | SET @sql = @sql + N'EXEC sp_addpublication
73 | @publication = N''' + @PublicationName + ''',
74 | @description = N''Transactional publication of database ''''' + @PubDbName + ''''' from Publisher ''''' + @Publisher + '''''.'',
75 | @sync_method = N''concurrent'',
76 | @retention = 0,
77 | @allow_push = N''true'',
78 | @allow_pull = N''true'',
79 | @allow_anonymous = N''false'',
80 | @enabled_for_internet = N''false'',
81 | @snapshot_in_defaultfolder = N''true'',
82 | @compress_snapshot = N''false'',
83 | @ftp_port = 21,
84 | @allow_subscription_copy = N''false'',
85 | @add_to_active_directory = N''false'',
86 | @repl_freq = N''continuous'',
87 | @status = N''active'',
88 | @independent_agent = N''true'',
89 | @immediate_sync = N''false'',
90 | @allow_sync_tran = N''false'',
91 | @allow_queued_tran = N''false'',
92 | @allow_dts = N''false'',
93 | @replicate_ddl = 1,
94 | @allow_initialize_from_backup = N''false'',
95 | @enabled_for_p2p = N''false'',
96 | @enabled_for_het_sub = N''false'';' + CHAR(10)+CHAR(13) ;
97 |
98 | IF @Debug = 0
99 | EXEC sp_executesql @sql;
100 | ELSE
101 | PRINT @sql;
102 |
103 |
104 | -- Set snapshot agent to run on a schedule (hourly) to make sure new/changed articles
105 | SET @sql = 'USE [' + @PubDbName + ']' + CHAR(10) + CHAR(13);
106 |
107 | SET @sql = @sql + 'exec sp_addpublication_snapshot
108 | @publication = N''' + @PublicationName + ''',
109 | @frequency_type = 4,
110 | @frequency_interval = 1,
111 | @frequency_relative_interval = 1,
112 | @frequency_recurrence_factor = 0,
113 | @frequency_subday = 8,
114 | @frequency_subday_interval = 1,
115 | @active_start_time_of_day = 0,
116 | @active_end_time_of_day = 235959,
117 | @active_start_date = 0,
118 | @active_end_date = 0,
119 | @job_login = null,
120 | @job_password = null,
121 | @publisher_security_mode = 1;' + CHAR(10)+CHAR(13) ;
122 |
123 | IF @Debug = 0
124 | EXEC sp_executesql @sql;
125 | ELSE
126 | PRINT @sql;
127 |
128 |
129 | --If DB is in an AG, update distributor to know that
130 | IF @Publisher <> @@SERVERNAME
131 | BEGIN
132 | SET @sql = 'EXEC OPENDATASOURCE(''SQLNCLI'',''Data Source=' + @Distributor + ';Integrated Security=SSPI'').distribution.sys.sp_redirect_publisher
133 | @original_publisher = ''' + @@SERVERNAME + ''',
134 | @publisher_db = ''' + @PubDbName + ''',
135 | @redirected_publisher = ''' + @Publisher + ''';' + CHAR(10)+CHAR(13) ;
136 | IF @Debug = 0
137 | EXEC sp_executesql @sql;
138 | ELSE
139 | PRINT @sql;
140 | END;
141 | GO
142 |
143 |
144 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Repl_CreateSubscription.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Repl_CreateSubscription'))
2 | EXEC ('CREATE PROCEDURE dbo.Repl_CreateSubscription AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Repl_CreateSubscription
7 | @PubDbName nvarchar(256),
8 | @PublicationName nvarchar(256),
9 | @Subscriber nvarchar(256),
10 | @SubscriberDbName nvarchar(256),
11 | @Debug bit = 0
12 | AS
13 | /*************************************************************************************************
14 | AUTHOR: Andy Mallon
15 | CREATED: 20140101
16 | This procedure creates a push subscription for a given publication.
17 |
18 | PARAMETERS
19 | *
20 | **************************************************************************************************
21 | MODIFICATIONS:
22 | YYYYMMDDD - Initials - Description of changes
23 | **************************************************************************************************
24 | This code is licensed as part of Andy Mallon's DBA Database.
25 | https://github.com/amtwo/dba-database/blob/master/LICENSE
26 | ©2014-2020 ● Andy Mallon ● am2.co
27 | *************************************************************************************************/
28 | SET NOCOUNT ON;
29 | ---------------------
30 | DECLARE @sql nvarchar(max);
31 |
32 | --Add the Subscriber
33 | SET @sql = 'USE [' + @PubDbName + ']' + CHAR(10) + CHAR(13);
34 |
35 | SET @sql = @sql + 'EXEC sp_addsubscription
36 | @publication = N''' + @PublicationName + ''',
37 | @subscriber = N''' + @Subscriber + ''',
38 | @destination_db = N''' + @SubscriberDbName + ''',
39 | @subscription_type = N''Push'',
40 | @sync_type = N''automatic'',
41 | @article = N''all'',
42 | @update_mode = N''read only'',
43 | @subscriber_type = 0;' + CHAR(10)+CHAR(13) ;
44 |
45 | IF @Debug = 0
46 | EXEC sp_executesql @sql;
47 | ELSE
48 | PRINT @sql;
49 |
50 | --Create the agent job
51 | SET @sql = 'USE [' + @PubDbName + ']' + CHAR(10) + CHAR(13);
52 |
53 | SET @sql = @sql + 'EXEC sp_addpushsubscription_agent
54 | @publication = N''' + @PublicationName + ''',
55 | @subscriber = N''' + @Subscriber + ''',
56 | @subscriber_db = N''' + @SubscriberDbName + ''',
57 | @job_login = null,
58 | @job_password = null,
59 | @subscriber_security_mode = 1,
60 | @frequency_type = 64,
61 | @frequency_interval = 0,
62 | @frequency_relative_interval = 0,
63 | @frequency_recurrence_factor = 0,
64 | @frequency_subday = 0,
65 | @frequency_subday_interval = 0,
66 | @active_start_time_of_day = 0,
67 | @active_end_time_of_day = 235959,
68 | @active_start_date = 20150227,
69 | @active_end_date = 99991231,
70 | @enabled_for_syncmgr = N''False'',
71 | @dts_package_location = N''Distributor'';'
72 |
73 | IF @Debug = 0
74 | EXEC sp_executesql @sql;
75 | ELSE
76 | PRINT @sql;
77 | GO
78 |
79 |
80 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Set_AGReadOnlyRouting.sql:
--------------------------------------------------------------------------------
1 | CREATE OR ALTER PROCEDURE dbo.Set_AGReadOnlyRouting
2 | @Action varchar(10),
3 | @AGNamePattern nvarchar(128) = N'%',
4 | @ModifyReplicaPattern nvarchar(128) = N'%',
5 | @RoutingListPattern nvarchar(max) = NULL,
6 | @RoutingListCSV nvarchar(max) = NULL,
7 | @Debug bit = 0
8 | AS
9 | /*************************************************************************************************
10 | AUTHOR: Andy Mallon
11 | CREATED: 20220920
12 | This procedure can be used to enable or disable Read-Only Routing on an Availability Group.
13 | Parameters allow you to optinally control a subset of replicas to modify the ROR list on.
14 | The read-only routing list can either be specified explicitly, or build dynamically based
15 | on a naming convention.
16 |
17 | Note that the @RoutingListPattern and @RoutingListCSV parameters are mutually exclusive,
18 | and you must supply exactly one of the two parameters. Supplying both or neither will
19 | cause the procedure to fail and return an error.
20 |
21 | PARAMETERS
22 | * @Action - Either "ENABLE" or "DISABLE". All other values will cause the stored
23 | procedure to fail & return an error
24 | * @AGNamePattern - Defaults to '%', which will modify all AGs.
25 | The Name or wildcarded partial name of the AG(s) you want to modify
26 | the ROR on. This is compared to AG names using a LIKE. You must supply
27 | wildcards as needed.
28 | Note that _ is treated as a single-character wildcard.
29 | * @ModifyReplicaPattern - Defaults to '%', which will modify all Replicas.
30 | The Name or wildcarded partial name of the replicas AG(s) you want to
31 | modify the ROR for when they are the Primary replica. This is compared
32 | to replica names using a LIKE. You must supply wildcards as needed.
33 | Note that _ is treated as a single-character wildcard.
34 | * @RoutingListPattern - Defaults to NULL.
35 | Wildcarded partial name of the replicas AG(s) you want to use to build
36 | the ROR list. This is compared to replica names using a LIKE.
37 | You must supply wildcards as needed.
38 | Note that _ is treated as a single-character wildcard.
39 | When building the ROR list with this method, matching replicas are
40 | included in alphabetical order. When a replica is in it's own ROR list,
41 | it will always be included last, so that read-only traffic prefers
42 | secondary nodes, and not Primary.
43 | * @RoutingListCSV - If you want to explicitly supply the ROR list, include a comma-separated
44 | list of servers here. Order will be preserved and the ROR list will be
45 | included in the specified order for all modified replicas.
46 | * @Debug - Defaults to False. Supplying a 1 for this bit will not perform any
47 | changes to AG configuration, but will instead simply PRINT the
48 | constructed SQL.
49 |
50 | EXAMPLES:
51 | --For all AGs,
52 | --Enable ROR for Replicas with names starting with BOS
53 | --In the ROR routing list, use only replicas with names starting with BOS
54 | EXEC DBA.dbo.Set_AGReadOnlyRouting
55 | @Action = 'ENABLE',
56 | @ModifyReplicaPattern = 'BOS%',
57 | @RoutingListPattern = 'BOS%';
58 |
59 | --For AGs with names starting with "AG-AM2",
60 | --Disable ROR for Replicas with names starting with DR
61 | --But don't run the DISABLE, just print it instead.
62 | EXEC DBA.dbo.Set_AGReadOnlyRouting
63 | @Action = 'DISABLE',
64 | @AgNamePattern = 'AG-AM2%',
65 | @ModifyReplicaPattern = 'DR%',
66 | @Debug = 1;
67 |
68 | --For all AGs,
69 | --Enable ROR for Replicas with names starting with BOS
70 | --Use the specified servers as the ROR list for every AG replica
71 | EXEC DBA.dbo.Set_AGReadOnlyRouting
72 | @Action = 'ENABLE',
73 | @ModifyReplicaPattern = '%',
74 | @RoutingListCSV = 'BOS-SQL98, BOS-SQL99',
75 | @Debug = 1;
76 |
77 | **************************************************************************************************
78 | This code is licensed as part of Andy Mallon's DBA Database.
79 | https://github.com/amtwo/dba-database/blob/master/LICENSE
80 | ©2014-2023 ● Andy Mallon ● am2.co
81 | *************************************************************************************************/
82 |
83 | SET NOCOUNT ON;
84 |
85 | --
86 | --
87 | -- Validate inputs!
88 | --
89 | --
90 | IF (@Action NOT IN ('DISABLE','ENABLE') )
91 | BEGIN
92 | -- Did not specify a valid Action
93 | RAISERROR ('@Action must be specified as either "ENABLE" or "DISABLE".',16,1)
94 | RETURN;
95 | END;
96 |
97 | IF (@Action = 'DISABLE'
98 | AND COALESCE(@RoutingListCSV,@RoutingListPattern) IS NOT NULL)
99 | BEGIN
100 | -- Disable will reset routing list to NONE. Not allowed to specify a routing list on Disable action
101 | RAISERROR ('For "DISABLE" @Action, both @RoutingListCSV and @RoutingListPattern must be NULL.',16,1)
102 | RETURN;
103 | END;
104 |
105 | IF (@Action = 'ENABLE'
106 | AND @RoutingListCSV IS NOT NULL
107 | AND @RoutingListPattern IS NOT NULL)
108 | BEGIN
109 | -- Enable routing with BOTH a CSV & Pattern for ROR list is not allowed
110 | RAISERROR ('For "ENABLE" @Action, specify a value for either @RoutingListCSV or @RoutingListPattern. The unused parameter must be NULL. Providing both is not allowed.',16,1)
111 | RETURN;
112 | END;
113 |
114 | IF (@Action = 'ENABLE'
115 | AND @RoutingListCSV IS NULL
116 | AND @RoutingListPattern IS NULL)
117 | BEGIN
118 | -- Enable routing with NEITHER a CSV & Pattern for ROR list is not allowed
119 | RAISERROR ('For "ENABLE" @Action, specify a value for either @RoutingListCSV or @RoutingListPattern. The unused parameter must be NULL. Providing neither is not allowed.',16,1)
120 | RETURN;
121 | END;
122 |
123 | --
124 | --
125 | -- Vars go here
126 | --
127 | --
128 | DECLARE @AgList TABLE (
129 | GroupId uniqueidentifier,
130 | AgName nvarchar(256)
131 | );
132 | DECLARE @RorList TABLE (
133 | GroupId uniqueidentifier,
134 | ReplicaId uniqueidentifier,
135 | ReplicaName nvarchar(256),
136 | RoutingList nvarchar(max)
137 | );
138 | DECLARE @sql nvarchar(max) = N'USE [master];' + CHAR(10);
139 |
140 | --
141 | --
142 | -- OK, now do stuff
143 | --
144 | --
145 |
146 |
147 | INSERT INTO @AgList (GroupId, AgName)
148 | SELECT ag.group_id,
149 | ag.name
150 | FROM sys.availability_groups AS ag
151 | JOIN sys.dm_hadr_availability_group_states AS ags ON ag.group_id = ags.group_id
152 | WHERE ags.primary_replica = @@SERVERNAME
153 | AND ag.is_distributed = 0
154 | AND ag.name LIKE @AgNamePattern;
155 |
156 | IF @Action = 'DISABLE'
157 | BEGIN
158 | SELECT @sql +=
159 | N'ALTER AVAILABILITY GROUP ' + QUOTENAME(ag.AgName) + CHAR(10) +
160 | N' MODIFY REPLICA ON ' + QUOTENAME(rcs.replica_server_name, NCHAR(39) ) + CHAR(10) +
161 | N' WITH (PRIMARY_ROLE(READ_ONLY_ROUTING_LIST = NONE )); ' + CHAR(10)
162 | FROM @AgList AS ag
163 | JOIN sys.dm_hadr_availability_replica_cluster_states AS rcs ON rcs.group_id = ag.GroupId
164 | WHERE rcs.replica_server_name LIKE @ModifyReplicaPattern;
165 | END;
166 |
167 |
168 | IF @Action = 'ENABLE'
169 | BEGIN
170 | --Sorting out the Read-Only-Routing (ROR) lists is the hard part.
171 | INSERT INTO @RorList (GroupId, ReplicaId, ReplicaName, RoutingList)
172 | SELECT ar.group_id,
173 | ar.replica_id,
174 | ar.replica_server_name,
175 | RoutingList = STRING_AGG('N''' + ror.replica_server_name + '''',',') WITHIN GROUP (ORDER BY IIF(ror.replica_server_name = ar.replica_server_name, 9, 0), ar.replica_server_name)
176 | FROM sys.availability_replicas AS ar
177 | JOIN sys.availability_replicas AS ror ON ror.group_id = ar.group_id
178 | WHERE ar.replica_server_name LIKE @ModifyReplicaPattern
179 | AND ror.replica_server_name LIKE @RoutingListPattern
180 | AND @RoutingListCSV IS NULL
181 | AND ror.secondary_role_allow_connections IN (1,2)
182 | GROUP BY ar.group_id, ar.replica_id, ar.replica_server_name
183 | UNION ALL
184 | SELECT ar.group_id,
185 | ar.replica_id,
186 | ar.replica_server_name,
187 | STRING_AGG('N''' + ror.replica_server_name + '''',',') WITHIN GROUP (ORDER BY l.sort)
188 | FROM sys.availability_replicas AS ar
189 | JOIN sys.availability_replicas AS ror ON ror.group_id = ar.group_id
190 | JOIN (SELECT Sort = csv.ID,
191 | ReplicaName = csv.Value
192 | FROM dbo.fn_split(@RoutingListCSV,N',') AS csv) AS l ON l.ReplicaName = ror.replica_server_name
193 | WHERE @RoutingListPattern IS NULL
194 | AND ror.secondary_role_allow_connections IN (1,2)
195 | GROUP BY ar.group_id, ar.replica_id, ar.replica_server_name
196 |
197 | --Now generate the actual ALTER
198 | SELECT @sql +=
199 | N'ALTER AVAILABILITY GROUP ' + QUOTENAME(ag.AgName) + CHAR(10) +
200 | N' MODIFY REPLICA ON ' + QUOTENAME(rl.ReplicaName, NCHAR(39) ) + CHAR(10) +
201 | N' WITH (PRIMARY_ROLE(READ_ONLY_ROUTING_LIST = (' + rl.RoutingList + N'))); ' + CHAR(10)
202 | FROM @AgList AS ag
203 | JOIN @RorList AS rl ON rl.GroupId = ag.GroupId
204 | END;
205 |
206 | IF @Debug = 0
207 | BEGIN
208 | EXEC sys.sp_executesql @stmt = @sql;
209 | END
210 | ELSE
211 | BEGIN
212 | PRINT @sql;
213 | END;
214 | GO
215 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Set_StatisticsNorecomputeByTable.sql:
--------------------------------------------------------------------------------
1 | CREATE OR ALTER PROCEDURE dbo.Set_StatisticsNorecomputeByTable
2 | @ObjectList dbo.ObjectNameListWithDb READONLY,
3 | @SampleSize tinyint = 100,
4 | @IncludeIndexStats bit = 1,
5 | @IncludeColumnStats bit = 0,
6 | @Debug bit = 0
7 | AS
8 | /*************************************************************************************************
9 | AUTHOR: Andy Mallon
10 | CREATED: 20240820
11 | This procedure can be used to enable or disable the "norecompute" flag on statistics for
12 | specific tables. If the stats object is already flagged as "norecompute" that stats object
13 | will not be touched.
14 |
15 | This can be helpful for very large, high volume tables with volatile stats, where you want
16 | only manually-trigger stats updates, and do not want auto stats triggered
17 | due to small sample size used on large tables.
18 |
19 | This will perform an UPDATE STATISTICS operation when run.
20 |
21 | PARAMETERS
22 | * @ObjectList - Required - TVP of objects that should have stats modified.
23 | * @IncludeIndexStats - Defaults to 1 (true).
24 | * @IncludeColumnStats - Defaults to 1 (true).
25 | * @SampleSize - Defaults to 100 (FULLSCAN).
26 | * @Debug - Defaults to False. Supplying a 1 for this bit will not perform any
27 | changes to stats, but will instead simply output the
28 | constructed SQL.
29 |
30 | EXAMPLES:
31 |
32 |
33 | **************************************************************************************************
34 | This code is licensed as part of Andy Mallon's DBA Database.
35 | https://github.com/amtwo/dba-database/blob/master/LICENSE
36 | ©2014-2024 ● Andy Mallon ● am2.co
37 | *************************************************************************************************/
38 | SET NOCOUNT ON;
39 |
40 | CREATE TABLE #Results (
41 | DbName sysname,
42 | SchemaName sysname,
43 | ObjectName sysname,
44 | StatisticsList nvarchar(max),
45 | UpdateStatsSql AS N'UPDATE STATISTICS ' + QUOTENAME(DbName) + N'.' + QUOTENAME(SchemaName) + N'.' + QUOTENAME(ObjectName) + N'
46 | (' + StatisticsList + N'
47 | ) WITH SAMPLE @@@SampleSize PERCENT, NORECOMPUTE;'
48 | );
49 |
50 | DECLARE @DbName sysname;
51 | DECLARE @sql nvarchar(max)
52 |
53 |
54 | DECLARE db_cursor CURSOR FOR
55 | SELECT DISTINCT DbName FROM @ObjectList ;
56 |
57 | OPEN db_cursor;
58 | FETCH NEXT FROM db_cursor INTO @DbName;
59 |
60 | WHILE @@FETCH_STATUS = 0
61 | BEGIN
62 | --Are we doing Index stats?
63 | IF @IncludeIndexStats = 1
64 | BEGIN
65 | SET @sql = N'
66 | SELECT @DbName, s.name, o.name, STRING_AGG(CONVERT(nvarchar(max),st.name),N'','')
67 | FROM ' + QUOTENAME(@DbName) + N'.sys.objects o
68 | JOIN ' + QUOTENAME(@DbName) + N'.sys.schemas s ON s.schema_id = o.schema_id
69 | JOIN ' + QUOTENAME(@DbName) + N'.sys.indexes i ON i.object_id = o.object_id
70 | JOIN ' + QUOTENAME(@DbName) + N'.sys.stats st ON st.object_id = o.object_id AND st.name = i.name
71 | JOIN @ObjectList ol ON
72 | ol.DbName = @DbName
73 | AND ol.SchemaName = s.name
74 | AND ol.ObjectName = o.name
75 | WHERE st.no_recompute = 0 /*Only stats that arent already norecompute*/
76 | GROUP BY s.name, o.name';
77 |
78 | IF @Debug = 1
79 | BEGIN
80 | PRINT @sql;
81 | END;
82 |
83 | INSERT INTO #Results (DbName, SchemaName, ObjectName, StatisticsList)
84 | EXEC sys.sp_executesql
85 | @stmt = @sql,
86 | @params = N'@DbName sysname, @ObjectList dbo.ObjectNameListWithDb READONLY',
87 | @DbName = @DbName,
88 | @ObjectList = @ObjectList;
89 | END;
90 |
91 | --Are we doing Column stats?
92 | IF @IncludeColumnStats = 1
93 | BEGIN
94 | SET @sql = N'
95 | SELECT @DbName, s.name, o.name, STRING_AGG(CONVERT(nvarchar(max),st.name),N'','')
96 | FROM ' + QUOTENAME(@DbName) + N'.sys.objects o
97 | JOIN ' + QUOTENAME(@DbName) + N'.sys.schemas s ON s.schema_id = o.schema_id
98 | JOIN ' + QUOTENAME(@DbName) + N'.sys.stats st ON st.object_id = o.object_id
99 | JOIN @ObjectList ol ON
100 | ol.DbName = @DbName
101 | AND ol.SchemaName = s.name
102 | AND ol.ObjectName = o.name
103 | WHERE NOT EXISTS (SELECT 1 FROM ' + QUOTENAME(@DbName) + N'.sys.indexes i WHERE i.object_id = o.object_id AND st.name = i.name )
104 | AND st.no_recompute = 0 /*Only stats that arent already norecompute*/
105 | GROUP BY s.name, o.name';
106 |
107 | IF @Debug = 1
108 | BEGIN
109 | PRINT @sql;
110 | END;
111 |
112 | INSERT INTO #Results (DbName, SchemaName, ObjectName, StatisticsList)
113 | EXEC sys.sp_executesql
114 | @stmt = @sql,
115 | @params = N'@DbName sysname, @ObjectList dbo.ObjectNameListWithDb READONLY',
116 | @DbName = @DbName,
117 | @ObjectList = @ObjectList;
118 | END;
119 |
120 | FETCH NEXT FROM db_cursor INTO @DbName;
121 | END
122 |
123 | CLOSE db_cursor;
124 | DEALLOCATE db_cursor;
125 |
126 | IF @Debug = 1
127 | BEGIN
128 | SELECT * FROM #Results;
129 | END;
130 |
131 | SET @sql = N''
132 | SELECT @sql += REPLACE(UpdateStatsSql,N'@@@SampleSize', CONVERT(nvarchar(max),@SampleSize)) + CHAR(13) + CHAR(10)
133 | FROM #Results;
134 |
135 | IF @Debug = 1
136 | BEGIN
137 | PRINT @sql;
138 | END;
139 |
140 | IF @Debug = 0
141 | BEGIN
142 | EXEC sys.sp_executesql @stmt = @sql;
143 | END;
144 | GO
145 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.Views_RecompileAll.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND object_id = object_id('dbo.Views_RecompileAll'))
2 | EXEC ('CREATE PROCEDURE dbo.Views_RecompileAll AS SELECT ''This is a stub''')
3 | GO
4 |
5 |
6 | ALTER PROCEDURE dbo.Views_RecompileAll
7 | @DbName nvarchar(128),
8 | @Debug bit = 0
9 | AS
10 | /*************************************************************************************************
11 | AUTHOR: Andy Mallon
12 | CREATED: 20150511
13 | This procedure loops through all views in a database and marks them for recompilation.
14 | If NULL is passed for DbName, all views in all databases will be marked for recompilation.
15 |
16 | If a linked server is moved or column data type changed, views referencing that server/column
17 | may need to be recompiled to realize the issue. This sproc is a quick fix to hit all views
18 | in order to resolve the problem.
19 |
20 | PARAMETERS
21 | * @DbName - Required - The name of a database to recompile views for. If NULL, do all Databases.
22 | * @Debug - default 0 - determines if sp_recompile statements should be output or executed
23 | EXAMPLES:
24 | *
25 | **************************************************************************************************
26 | MODIFICATIONS:
27 | YYYYMMDD -
28 | **************************************************************************************************
29 | This code is licensed as part of Andy Mallon's DBA Database.
30 | https://github.com/amtwo/dba-database/blob/master/LICENSE
31 | ©2014-2020 ● Andy Mallon ● am2.co
32 | *************************************************************************************************/
33 | SET NOCOUNT ON;
34 |
35 | DECLARE @Sql nvarchar(max);
36 |
37 |
38 | CREATE TABLE #Commands (
39 | Cmd nvarchar(max)
40 | )
41 |
42 | DECLARE db_cur CURSOR FOR
43 | SELECT name AS DbName
44 | FROM sys.databases
45 | WHERE dbo.dm_hadr_db_role(name) IN ('PRIMARY','ONLINE')
46 | AND name = COALESCE(@DbName,name);
47 |
48 | DECLARE cmd_cur CURSOR FOR
49 | SELECT Cmd
50 | FROM #Commands;
51 |
52 |
53 | --Build commands one Db at a time, store in #Commands table
54 | OPEN db_cur;
55 | FETCH NEXT FROM db_cur INTO @DbName;
56 |
57 | WHILE @@FETCH_STATUS = 0
58 | BEGIN
59 | SET @Sql = 'SELECT ''EXEC ' + @DbName + '.sys.sp_recompile '''''' + name + '''''';'' FROM [' + @DbName + '].sys.objects WHERE type = ''V'' AND is_ms_shipped = 0;';
60 |
61 | INSERT INTO #Commands (Cmd)
62 | EXEC sp_executesql @Sql
63 |
64 | FETCH NEXT FROM db_cur INTO @DbName;
65 | END;
66 |
67 | CLOSE db_cur;
68 | DEALLOCATE db_cur;
69 |
70 |
71 | IF @Debug = 1
72 | BEGIN
73 | --If Debug mode, just select out the commands.
74 | SELECT Cmd FROM #Commands;
75 | END;
76 | ELSE
77 | BEGIN
78 | --Otherwise, execute them
79 | OPEN cmd_cur;
80 | FETCH NEXT FROM cmd_cur INTO @Sql;
81 |
82 | WHILE @@FETCH_STATUS = 0
83 | BEGIN
84 |
85 | EXEC sp_executesql @Sql
86 |
87 | FETCH NEXT FROM cmd_cur INTO @Sql;
88 | END;
89 |
90 | CLOSE cmd_cur;
91 | DEALLOCATE cmd_cur;
92 | END;
93 |
94 | RETURN 0;
95 | GO
96 |
97 |
98 |
--------------------------------------------------------------------------------
/stored-procedures/dbo.sp_Get_BaseTableList.sql:
--------------------------------------------------------------------------------
1 | USE master
2 | GO
3 | --We don't want to drop/create this guy once we mark it as system
4 | --Once a developer starts using this in production, will cause problems when it disappears
5 | --Instead: if it doesn't exist, create a stub & grant permissions, then alter the sproc to use the correct code.
6 | IF OBJECT_ID('sp_get_basetable_list', 'P') IS NULL
7 | BEGIN
8 | --do this in dynamic SQL so CREATE PROCEDURE can be nested in this IF block
9 | EXEC ('CREATE PROCEDURE dbo.sp_get_basetable_list AS SELECT 1')
10 | --mark it as a system object
11 | --EXEC sp_MS_marksystemobject sp_get_basetable_list
12 | --grant permission to the whole world
13 | --GRANT EXECUTE ON sp_get_basetable_list to PUBLIC
14 | END
15 | GO
16 |
17 | --Now do an alter
18 | ALTER PROCEDURE dbo.sp_get_basetable_list
19 | @object_name varchar(776) = NULL,
20 | @debug bit = 0
21 | AS
22 | /*************************************************************************************************
23 | AUTHOR: Andy Mallon
24 | CREATED: 20140228
25 | This procedure can be called two ways:
26 | 1) by passing a view/synonym/table name to the @object_name parameter
27 | 2) by creating & populating #tables (matching schema at start of sproc) then calling the
28 | sproc with that table populated.
29 |
30 | If option 1 is used to call the sproc, the table list will be returned in the form
31 | of a result set.
32 | If option 2 is used to call the sproc, then #tables will be populated with the physical
33 | tables.
34 |
35 | For the object(s) passed to this sproc, look up the physical tables behind it.
36 | * If a synonym is passed, return the base table of that synonym
37 | * If a view is passed, return ALL the base tables of that view
38 | * If a table is passed, return the table itself
39 |
40 | Lookup is recursive and only ends when #tables contains only tables.
41 |
42 | PARAMETERS
43 | * @object_name - Optional - accept three-part object name (Database.Schema.Table)
44 | - If not provided, #tables should exist & be populated, otherwise, raiserror
45 | **************************************************************************************************
46 | MODIFICATIONS:
47 | YYYYMMDDD - Initials - Description of changes
48 | **************************************************************************************************
49 | This code is licensed as part of Andy Mallon's DBA Database.
50 | https://github.com/amtwo/dba-database/blob/master/LICENSE
51 | ©2014-2020 ● Andy Mallon ● am2.co
52 | *************************************************************************************************/
53 |
54 | SET NOCOUNT ON
55 | --If #tables doesn't exist, create it, and populate it from the input param
56 |
57 | IF (object_id('tempdb..#tables') IS NULL)
58 | BEGIN
59 | IF @object_name IS NULL
60 | RAISERROR ('No table(s) provided.',16,1)
61 | CREATE TABLE #tables (DbName sysname, SchemaName sysname, TableName sysname, ObjType char(2) CONSTRAINT pk_tables PRIMARY KEY (DbName, SchemaName, TableName))
62 | INSERT INTO #tables (DbName, SchemaName, TableName)
63 | SELECT COALESCE(parsename(@object_name,3),db_name()),
64 | COALESCE(parsename(@object_name,2),schema_name()),
65 | parsename(@object_name,1)
66 | END
67 |
68 |
69 | DECLARE @sql nvarchar(2070)
70 | DECLARE @DbName varchar(256)
71 | DECLARE @SchemaName varchar(256)
72 | DECLARE @TableName varchar(256)
73 | DECLARE @ObjType char(2)
74 |
75 | WHILE EXISTS(SELECT 1 FROM #tables WHERE COALESCE(ObjType,'x') <> 'U')
76 | BEGIN
77 | DECLARE db_cur CURSOR FOR
78 | SELECT DISTINCT DbName FROM #tables
79 |
80 | OPEN db_cur
81 | FETCH NEXT FROM db_cur INTO @DbName
82 |
83 | WHILE @@FETCH_STATUS = 0
84 | BEGIN
85 | -- Get the object types for everything in this DB
86 | SET @sql = N'UPDATE t SET ObjType = o.type FROM #tables t JOIN ' + @DbName + '.sys.objects o ON o.schema_id = schema_id(t.SchemaName) AND o.name = t.TableName WHERE t.DbName = ''' + @DbName + ''''
87 | IF @debug = 1
88 | PRINT @sql
89 | EXEC (@sql)
90 |
91 | IF EXISTS (SELECT 1 FROM #tables WHERE DbName = @DbName AND ObjType IS NULL)
92 | BEGIN
93 | PRINT 'Unable to determine object type for one or more objects.'
94 | DELETE FROM #tables WHERE DbName = @DbName AND ObjType IS NULL
95 | END
96 |
97 | DECLARE tab_cur CURSOR FOR
98 | SELECT SchemaName, TableName, ObjType
99 | FROM #tables
100 | WHERE DbName = @DbName
101 |
102 | OPEN tab_cur
103 | FETCH NEXT FROM tab_cur INTO @SchemaName, @TableName, @ObjType
104 | WHILE @@FETCH_STATUS = 0
105 | BEGIN
106 | IF (@ObjType ='SN')
107 | BEGIN
108 | --Its not a table. Delete the current row & replace with object(s) it references
109 | DELETE #tables WHERE DbName = @DbName AND SchemaName = @SchemaName AND TableName = @TableName
110 | SET @sql = N'INSERT INTO #tables (DbName, SchemaName, TableName) SELECT COALESCE(PARSENAME(base_object_name,3),db_name()), '
111 | + 'COALESCE(PARSENAME(base_object_name,2),schema_name()), PARSENAME(base_object_name,1) FROM ' + @DbName
112 | + '.sys.synonyms WHERE name = ''' + @TableName + ''' AND schema_id = schema_id(''' + @SchemaName + ''')'
113 | IF @debug = 1
114 | PRINT @sql
115 | EXEC (@sql)
116 | END
117 |
118 | ELSE IF (@ObjType <> 'U')
119 | BEGIN
120 | --Its not a table. Delete the current row & replace with object(s) it references
121 | DELETE #tables WHERE DbName = @DbName AND SchemaName = @SchemaName AND TableName = @TableName
122 | SET @sql = N'INSERT INTO #tables (DbName, SchemaName, TableName) SELECT DISTINCT COALESCE(referenced_database_name,'''
123 | + @DbName + '''), COALESCE(referenced_schema_name,''' + @SchemaName + '''), referenced_entity_name FROM ' + QUOTENAME(@DbName)
124 | + '.sys.dm_sql_referenced_entities (''' + QUOTENAME(@SchemaName) + '.' + QUOTENAME(@TableName) + ''',''OBJECT'') r '
125 | + 'WHERE NOT EXISTS(SELECT 1 FROM #tables t WHERE t.DbName = COALESCE(r.referenced_database_name,''' + @DbName + ''') AND '
126 | + 't.SchemaName = COALESCE(r.referenced_schema_name,''' + @SchemaName + ''') AND t.TableName = r.referenced_entity_name)'
127 | IF @debug = 1
128 | PRINT @sql
129 | EXEC (@sql)
130 | END
131 | FETCH NEXT FROM tab_cur INTO @SchemaName, @TableName, @ObjType
132 | END
133 |
134 | CLOSE tab_cur
135 | DEALLOCATE tab_cur
136 | FETCH NEXT FROM db_cur INTO @DbName
137 | END
138 | CLOSE db_cur
139 | DEALLOCATE db_cur
140 | END
141 |
142 | IF (@object_name IS NOT NULL)
143 | SELECT DbName, SchemaName, TableName FROM #tables
144 |
145 | GO
146 |
147 |
148 |
--------------------------------------------------------------------------------
/tables/dbo.CommandLog.Indexes.sql:
--------------------------------------------------------------------------------
1 | --The CommandLog table comes from Ola's maintenance package.
2 | --Table definition comes from there; These are indexes only.
3 | --Add a couple additional indexes to support querying the log.
4 | IF EXISTS (SELECT 1 FROM sys.objects WHERE object_id = object_id('dbo.CommandLog'))
5 | BEGIN
6 | IF NOT EXISTS (SELECT * FROM sys.indexes
7 | WHERE object_id = object_id('dbo.CommandLog')
8 | AND name = 'ix_CommandLog_CommandType_StartTime')
9 | BEGIN
10 | CREATE INDEX ix_CommandLog_CommandType_StartTime
11 | ON dbo.CommandLog (CommandType, StartTime);
12 | END;
13 |
14 | IF NOT EXISTS (SELECT * FROM sys.indexes
15 | WHERE object_id = object_id('dbo.CommandLog')
16 | AND name = 'ix_CommandLog_StartTime')
17 | BEGIN
18 | CREATE INDEX ix_CommandLog_StartTime
19 | ON dbo.CommandLog (StartTime);
20 | END;
21 |
22 | END;
23 |
24 | DECLARE @version_chr varchar(10) = CAST(SERVERPROPERTY('ProductVersion') as varchar(10))
25 | DECLARE @version_num int = SUBSTRING(@version_chr,1,CHARINDEX('.',@version_chr,0)-1)
26 | --Compress the PK on Ola's table + custom indexes, if the version/edition supports it
27 | IF EXISTS (SELECT 1
28 | WHERE SERVERPROPERTY('EngineEdition') NOT IN (2,4) --Compresion was enterprise only back in the day
29 | OR (@version_num = 13 AND SERVERPROPERTY('EngineEdition') = N'RTM') -- With 2016, everything but RTM supports compression
30 | OR (@version_num >= 14) -- 2017+, everyone supports compression
31 | )
32 | BEGIN
33 | IF EXISTS (SELECT 1 FROM sys.partitions
34 | WHERE object_id = object_id('dbo.CommandLog')
35 | AND data_compression_desc = 'NONE')
36 | BEGIN
37 | ALTER INDEX PK_CommandLog ON dbo.CommandLog
38 | REBUILD WITH (DATA_COMPRESSION=PAGE);
39 | END;
40 |
41 | IF EXISTS (SELECT 1 FROM sys.partitions p
42 | JOIN sys.indexes i ON i.object_id = p.object_id AND i.index_id = p.index_id
43 | WHERE p.object_id = object_id('dbo.CommandLog')
44 | AND i.name = 'ix_CommandLog_CommandType_StartTime'
45 | AND p.data_compression_desc = 'NONE')
46 | BEGIN
47 | ALTER INDEX ix_CommandLog_CommandType_StartTime ON dbo.CommandLog
48 | REBUILD WITH (DATA_COMPRESSION=PAGE);
49 | END;
50 |
51 | IF EXISTS (SELECT 1 FROM sys.partitions p
52 | JOIN sys.indexes i ON i.object_id = p.object_id AND i.index_id = p.index_id
53 | WHERE p.object_id = object_id('dbo.CommandLog')
54 | AND i.name = 'ix_CommandLog_StartTime'
55 | AND p.data_compression_desc = 'NONE')
56 | BEGIN
57 | ALTER INDEX ix_CommandLog_StartTime ON dbo.CommandLog
58 | REBUILD WITH (DATA_COMPRESSION=PAGE);
59 | END;
60 |
61 | END;
62 |
--------------------------------------------------------------------------------
/tables/dbo.Config.sql:
--------------------------------------------------------------------------------
1 | --dbo.Config
2 | IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = object_id('dbo.Config'))
3 | BEGIN
4 | CREATE TABLE dbo.Config(
5 | ConfigCode varchar(16) NOT NULL,
6 | ConfigCategory varchar(128) NOT NULL,
7 | ConfigName varchar(128) NOT NULL,
8 | UnicodeValue nvarchar(max) NULL,
9 | NumericValue numeric(16,6) NULL,
10 | VarbinaryValue varbinary(max) NULL,
11 | CONSTRAINT PK_Config PRIMARY KEY CLUSTERED (ConfigCode),
12 | CONSTRAINT UIX_Category_Name UNIQUE NONCLUSTERED (ConfigCategory,ConfigName),
13 | -- Make sure at most one value is specified
14 | CONSTRAINT CK_Config_Values
15 | CHECK(
16 | ( CASE WHEN UnicodeValue IS NULL THEN 0 ELSE 1 END
17 | + CASE WHEN NumericValue IS NULL THEN 0 ELSE 1 END
18 | + CASE WHEN VarbinaryValue IS NULL THEN 0 ELSE 1 END
19 | ) <= 1
20 | )
21 | ) ON [DATA];
22 | END
23 | GO
24 |
25 |
26 | -- There's a better way to manage this config data, but I'll handle the number of configs warrants it
27 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'REPLSCMOPT')
28 | BEGIN
29 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, VarbinaryValue)
30 | VALUES ('REPLSCMOPT', 'Replication', 'Schema Option', 0x00000044080350DF)
31 | END;
32 |
33 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'EMAILBOLDCOLOR')
34 | BEGIN
35 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, UnicodeValue)
36 | VALUES ('EMAILBOLDCOLOR', 'Alerting', 'Email Bold Color', '#032E57')
37 | END;
38 |
39 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'EMAILALERTCOLOR')
40 | BEGIN
41 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, UnicodeValue)
42 | VALUES ('EMAILALERTCOLOR', 'Alerting', 'Email Alert Color', '#DC080A')
43 | END;
44 |
45 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'EMAILBGCOLOR')
46 | BEGIN
47 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, UnicodeValue)
48 | VALUES ('EMAILBGCOLOR', 'Alerting', 'Email Background Color', '#D0CAC4')
49 | END;
50 |
51 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'EMAILBGCOLOR2')
52 | BEGIN
53 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, UnicodeValue)
54 | VALUES ('EMAILBGCOLOR2', 'Alerting', 'Email Background Color (Alternate)', '#E4F1FE')
55 | END;
56 |
57 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'EMAILALRTBGCOLOR')
58 | BEGIN
59 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, UnicodeValue)
60 | VALUES ('EMAILALRTBGCOLOR', 'Alerting', 'Email Background Color Alert', '#FEF1E4')
61 | END;
62 |
63 | IF NOT EXISTS (SELECT 1 FROM dbo.Config WHERE ConfigCode = 'EMAILALRTDOMAIN')
64 | BEGIN
65 | INSERT INTO dbo.Config (ConfigCode, ConfigCategory, ConfigName, UnicodeValue)
66 | VALUES ('EMAILALRTDOMAIN', 'Alerting', 'Email Sender Domain', 'example.com')
67 | END;
68 |
--------------------------------------------------------------------------------
/tables/dbo.Monitor_Blocking.sql:
--------------------------------------------------------------------------------
1 | --dbo.Alert_Blocking stored procedure will log blocking to this table.
2 | IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = object_id('dbo.Monitor_Blocking'))
3 | BEGIN
4 | CREATE TABLE dbo.Monitor_Blocking(
5 | LogId int IDENTITY(1,1) NOT NULL,
6 | LogDateTime datetime2(0) NOT NULL CONSTRAINT DF_Monitor_Blocking_LogDateTime DEFAULT getdate(),
7 | LeadingBlocker smallint NULL,
8 | BlockedSpidCount int NULL,
9 | DbName sysname NOT NULL,
10 | HostName nvarchar(128) NULL,
11 | ProgramName nvarchar(128) NULL,
12 | LoginName nvarchar(128) NULL,
13 | LoginTime datetime2(3) NULL,
14 | LastRequestStart datetime2(3) NULL,
15 | LastRequestEnd datetime2(3) NULL,
16 | TransactionCnt int NULL,
17 | Command nvarchar(32) NULL,
18 | WaitTime int NULL,
19 | WaitResource nvarchar(256) NULL,
20 | SqlText nvarchar(max) NULL,
21 | InputBuffer nvarchar(4000) NULL,
22 | SqlStatement nvarchar(max) NULL,
23 | CONSTRAINT PK_Monitor_Blocking PRIMARY KEY CLUSTERED (LogDateTime,LogId )
24 | ) ON [DATA];
25 | END
26 | GO
27 |
28 |
29 |
30 |
--------------------------------------------------------------------------------
/tables/dbo.Numbers.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = object_id('dbo.Numbers'))
2 | BEGIN
3 | CREATE TABLE dbo.Numbers (
4 | Number int identity(1,1),
5 | CONSTRAINT PK_Number PRIMARY KEY CLUSTERED (Number)
6 | );
7 | END;
8 |
9 |
10 | --populate it with exactly 1 million rows. https://goo.gl/VJyNi6
11 | IF (SELECT COUNT(*) FROM dbo.Numbers) <> 1000000
12 | BEGIN
13 | TRUNCATE TABLE dbo.Numbers;
14 | SET IDENTITY_INSERT dbo.Numbers ON;
15 | INSERT INTO dbo.Numbers (Number)
16 | SELECT TOP 1000000 ROW_NUMBER() OVER (ORDER BY o1.object_id)
17 | FROM sys.objects o1, sys.objects o2, sys.objects o3;
18 | SET IDENTITY_INSERT dbo.Numbers OFF;
19 | END;
20 |
21 |
--------------------------------------------------------------------------------
/tables/dbo.TimeZones.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = object_id('dbo.TimeZones'))
2 | BEGIN
3 | CREATE TABLE dbo.TimeZones (
4 | TimeZoneId nvarchar(64),
5 | DisplayName nvarchar(64),
6 | StandardName nvarchar(64),
7 | DaylightName nvarchar(64),
8 | SupportsDaylightSavingTime bit,
9 | CONSTRAINT PK_TimeZones PRIMARY KEY CLUSTERED (TimeZoneId)
10 | );
11 | END;
12 |
13 |
14 |
--------------------------------------------------------------------------------
/views/dbo.CmsGroups.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.CmsGroups'))
2 | EXEC ('CREATE VIEW dbo.CmsGroups AS SELECT stub = ''This is a stub''')
3 | GO
4 | ALTER VIEW dbo.CmsGroups
5 | AS
6 | /*************************************************************************************************
7 | AUTHOR: Andy Mallon
8 | **************************************************************************************************
9 | This code is licensed as part of Andy Mallon's DBA Database.
10 | https://github.com/amtwo/dba-database/blob/master/LICENSE
11 | ©2014-2020 ● Andy Mallon ● am2.co
12 | *************************************************************************************************/
13 | WITH ServerGroups AS (
14 | SELECT GroupID = cms1.server_group_id,
15 | GroupName = cms1.name,
16 | GroupDesc = cms1.description,
17 | ParentID = cms1.parent_id,
18 | GroupPath = CONVERT(nvarchar(1000),cms1.name)
19 | FROM msdb.dbo.sysmanagement_shared_server_groups AS cms1
20 | WHERE cms1.parent_id = 1
21 | UNION ALL
22 | SELECT GroupID = cms2.server_group_id,
23 | GroupName = cms2.name,
24 | GroupDesc = cms2.description,
25 | ParentID = cms2.parent_id,
26 | CONVERT(nvarchar(1000),sg.GroupPath + N'\' + cms2.name)
27 | FROM ServerGroups AS sg
28 | JOIN msdb.dbo.sysmanagement_shared_server_groups AS cms2
29 | ON cms2.parent_id = sg.GroupID
30 | )
31 | SELECT *
32 | FROM ServerGroups;
33 | GO
--------------------------------------------------------------------------------
/views/dbo.CmsServers.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.CmsServers'))
2 | EXEC ('CREATE VIEW dbo.CmsServers AS SELECT Stub = ''This is a stub''')
3 | GO
4 | ALTER VIEW dbo.CmsServers
5 | AS
6 | /*************************************************************************************************
7 | AUTHOR: Andy Mallon
8 | **************************************************************************************************
9 | This code is licensed as part of Andy Mallon's DBA Database.
10 | https://github.com/amtwo/dba-database/blob/master/LICENSE
11 | ©2014-2020 ● Andy Mallon ● am2.co
12 | *************************************************************************************************/
13 | WITH ServerGroups AS (
14 | SELECT GroupID = cms1.server_group_id,
15 | GroupName = cms1.name,
16 | GroupDesc = cms1.description,
17 | ParentID = cms1.parent_id,
18 | GroupPath = CONVERT(nvarchar(1000),cms1.name)
19 | FROM msdb.dbo.sysmanagement_shared_server_groups AS cms1
20 | WHERE cms1.parent_id = 1
21 | UNION ALL
22 | SELECT GroupID = cms2.server_group_id,
23 | GroupName = cms2.name,
24 | GroupDesc = cms2.description,
25 | ParentID = cms2.parent_id,
26 | CONVERT(nvarchar(1000),sg.GroupPath + N'\' + cms2.name)
27 | FROM ServerGroups AS sg
28 | JOIN msdb.dbo.sysmanagement_shared_server_groups AS cms2
29 | ON cms2.parent_id = sg.GroupID
30 | )
31 | SELECT ServerID = rs.server_id,
32 | ServerName = rs.server_name,
33 | DisplayName = rs.name,
34 | ServerDesc = rs.description,
35 | GroupID = rs.server_group_id,
36 | GroupName = sg.GroupName,
37 | GroupDesc = sg.GroupDesc,
38 | ServerPath = sg.GroupPath
39 | FROM ServerGroups AS sg
40 | JOIN msdb.dbo.sysmanagement_shared_registered_servers AS rs
41 | ON sg.GroupID = rs.server_group_id;
42 | GO
--------------------------------------------------------------------------------
/views/dbo.DatabaseProperties.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.DatabaseProperties'))
2 | EXEC ('CREATE VIEW dbo.DatabaseProperties AS SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 | ALTER VIEW dbo.DatabaseProperties
6 | /*************************************************************************************************
7 | AUTHOR: Andy Mallon
8 | CREATED: 2021130
9 | EAV-style view to display all database properties, normally accessed via DATABASEPROPERTYEX().
10 | Includes database properties for all supported versions. If the current server is older or
11 | database at a lower compatibility level, and does not support that server property, the
12 | PropertyValue will be NULL. See the HelpText for an indication of limited version support.
13 |
14 | Returned columns:
15 | * DatabaseName - Name of the database.
16 | * PropertyName - Name of the server property, passed as the argument to the DATABASEPROPERTYEX() function.
17 | * PropertyValue - Value returned by the DATABASEPROPERTYEX() function.
18 | * HelpText - Summary of property definition, and version/edition limitations.
19 |
20 | **************************************************************************************************
21 | This code is licensed as part of Andy Mallon's DBA Database.
22 | https://github.com/amtwo/dba-database/blob/production/LICENSE
23 | ©2014-2022 ● Andy Mallon ● am2.co
24 | *************************************************************************************************/
25 | AS
26 | WITH DbProperties AS (
27 | SELECT *
28 | FROM (
29 | VALUES
30 | ('Collation',
31 | N'Default collation name for the database.'),
32 | ('ComparisonStyle',
33 | N'The Windows comparison style of the collation; See docs.microsoft.com for details.'),
34 | ('Edition',
35 | N'Azure SQLDB; The database edition or service tier.'),
36 | ('IsAnsiNullDefault',
37 | N'Database follows ISO rules for allowing null values.'),
38 | ('IsAnsiNullsEnabled',
39 | N'All comparisons to a null evaluate to unknown.'),
40 | ('IsAnsiPaddingEnabled',
41 | N'Strings are padded to the same length before comparison or insert.'),
42 | ('IsAnsiWarningsEnabled',
43 | N'SQL Server issues error or warning messages when standard error conditions occur.'),
44 | ('IsArithmeticAbortEnabled',
45 | N'Queries end when an overflow or divide-by-zero error occurs during query execution.'),
46 | ('IsAutoClose',
47 | N'This should never be enabled. Database shuts down and frees resources after the last user exits.'),
48 | ('IsAutoCreateStatistics',
49 | N'Query optimizer creates single-column statistics, as required, to improve query performance.'),
50 | ('IsAutoCreateStatisticsIncremental',
51 | N'2014+; Auto-created single column statistics are incremental when possible.'),
52 | ('IsAutoShrink',
53 | N'This should never be enabled. Database files are candidates for automatic periodic shrinking.'),
54 | ('IsAutoUpdateStatistics',
55 | N'When a query uses potentially out-of-date existing statistics, the query optimizer updates those statistics.'),
56 | ('IsClone',
57 | N'2014 SP2+; Database is a schema- and statistics-only copy of a user database created with DBCC CLONEDATABASE.'),
58 | ('IsCloseCursorsOnCommitEnabled',
59 | N'When a transaction commits, all open cursors will close.'),
60 | ('IsFulltextEnabled',
61 | N'Database is enabled for full-text and semantic indexing.'),
62 | ('IsInStandBy',
63 | N'Database is online as read-only, with restore log allowed.'),
64 | ('IsLocalCursorsDefault',
65 | N'Cursor declarations default to LOCAL.'),
66 | ('IsMemoryOptimizedElevateToSnapshotEnabled',
67 | N'2014+; Memory-optimized tables are accessed using SNAPSHOT isolation, when the session setting TRANSACTION ISOLATION LEVEL is set to READ COMMITTED, READ UNCOMMITTED, or a lower isolation level.'),
68 | ('IsMergePublished',
69 | N'SQL Server supports database table publication for merge replication, if replication is installed.'),
70 | ('IsNullConcat',
71 | N'Null concatenation operand yields NULL.'),
72 | ('IsNumericRoundAbortEnabled',
73 | N'Errors are generated when a loss of precision occurs in expressions.'),
74 | ('IsParameterizationForced',
75 | N'PARAMETERIZATION database SET option is FORCED.'),
76 | ('IsQuotedIdentifiersEnabled',
77 | N'Double quotation marks on identifiers are allowed.'),
78 | ('IsPublished',
79 | N'If replication is installed, SQL Server supports database table publication for snapshot or transactional replication.'),
80 | ('IsRecursiveTriggersEnabled',
81 | N'Recursive firing of triggers is enabled.'),
82 | ('IsSubscribed',
83 | N'Database is subscribed to a publication.'),
84 | ('IsSyncWithBackup',
85 | N'The database is either a published database or a distribution database, and it supports a restore that will not disrupt transactional replication.'),
86 | ('IsTornPageDetectionEnabled',
87 | N'The SQL Server Database Engine detects incomplete I/O operations caused by power failures or other system outages.'),
88 | ('IsVerifiedClone',
89 | N'2016SP2+; Database is a schema- and statistics- only copy of a user database, created using the WITH VERIFY_CLONEDB option of DBCC CLONEDATABASE.'),
90 | ('IsXTPSupported',
91 | N'2016+; Indicates whether the database supports In-Memory OLTP, i.e., creation and use of memory-optimized tables and natively compiled modules.'),
92 | ('LastGoodCheckDbTime',
93 | N'The date and time of the last successful DBCC CHECKDB that ran on the specified database. If DBCC CHECKDB has not been run on a database, 1900-01-01 00:00:00.000 is returned.'),
94 | ('LCID',
95 | N'The collation Windows locale identifier (LCID).'),
96 | ('MaxSizeInBytes',
97 | N'Azure SQLDB; Maximum database size, in bytes.'),
98 | ('Recovery',
99 | N'Database recovery model'),
100 | ('ServiceObjective',
101 | N'Azure SQLDB; Describes the performance level of the database.'),
102 | ('ServiceObjectiveId',
103 | N'Azure SQLDB; The guid of the service objective in SQL Database.'),
104 | ('SQLSortOrder',
105 | N'SQL Server sort order ID supported in earlier versions of SQL Server.'),
106 | ('Status',
107 | N'Database status: ONLINE, OFFLINE, RESTORING, RECOVERING, SUSPECT, EMERGENCY'),
108 | ('Updateability',
109 | N'Indicates whether data can be modified.'),
110 | ('UserAccess',
111 | N'Indicates which users can access the database.'),
112 | ('Version',
113 | N'Internal version number of the SQL Server code with which the database was created. Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.')
114 | ) AS x(PropertyName, HelpText)
115 | )
116 | SELECT DbName = d.name,
117 | dbp.*
118 | FROM sys.databases AS d
119 | OUTER APPLY (SELECT p.PropertyName,
120 | PropertyValue = CONVERT(nvarchar(128),
121 | DATABASEPROPERTYEX(d.name, p.PropertyName)),
122 | p.HelpText
123 | FROM DbProperties p) AS dbp(PropertyName, PropertyValue, HelpText);
124 | GO
125 |
--------------------------------------------------------------------------------
/views/dbo.ServerLoginPermissions.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.ServerLoginPermissions'))
2 | EXEC ('CREATE VIEW dbo.ServerLoginPermissions AS SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 | ALTER VIEW dbo.ServerLoginPermissions
6 | /*************************************************************************************************
7 | AUTHOR: Andy Mallon
8 | CREATED: 20210627
9 | View to get basic info for server-level permissions, simplifying/flattening DMVs, to make applying additional
10 | criteria/filters from automation & troubleshooting easier
11 | EXAMPLES:
12 | * Get GRANT/DENY commands for permissions on all enabled users
13 | SELECT p.LoginName, p.PermissionSql
14 | FROM dbo.ServerLoginPermissions AS p
15 | JOIN dbo.ServerLogins AS l ON l.LoginSid = p.LoginSid
16 | WHERE l.IsEnabled = 1;
17 | **************************************************************************************************
18 | This code is licensed as part of Andy Mallon's DBA Database.
19 | https://github.com/amtwo/dba-database/blob/master/LICENSE
20 | ©2014-2020 ● Andy Mallon ● am2.co
21 | *************************************************************************************************/
22 | AS
23 | SELECT
24 | LoginSid = p.sid,
25 | LoginName = p.name,
26 | LoginType = p.type_desc,
27 | DefaultDatabase = p.default_database_name,
28 | LoginIsEnabled = IIF(p.is_disabled = 0,1,0),
29 | CanLogIn = COALESCE((SELECT TOP 1 1 FROM sys.server_permissions AS cosq
30 | WHERE cosq.grantee_principal_id = p.principal_id
31 | AND cosq.type = 'COSQ'
32 | AND cosq.state IN ('G','W')
33 | AND p.is_disabled = 0
34 | ),
35 | 0),
36 | PermissionType = perm.type,
37 | PermissionState = perm.state,
38 | PermissionSql = CONCAT(perm.state_desc, N' ',
39 | perm.permission_name, N' TO ',
40 | QUOTENAME(p.name) COLLATE Latin1_General_CI_AS_KS_WS,
41 | N';'
42 | ),
43 | DateLoginCreated = p.create_date,
44 | DateLoginModified = p.modify_date
45 | FROM sys.server_principals AS p
46 | JOIN sys.server_permissions AS perm
47 | ON perm.grantee_principal_id = p.principal_id
48 | WHERE p.type IN ('S','U','G')
49 | AND p.name <> N'sa'
50 | AND p.name NOT LIKE N'##%##';
51 | GO
52 |
--------------------------------------------------------------------------------
/views/dbo.ServerLogins.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.ServerLogins'))
2 | EXEC ('CREATE VIEW dbo.ServerLogins AS SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 | ALTER VIEW dbo.ServerLogins
6 | /*************************************************************************************************
7 | AUTHOR: Andy Mallon
8 | CREATED: 20210627
9 | View to get basic info for logins, simplifying/flattening DMVs, to make applying additional
10 | criteria/filters from automation & troubleshooting easier
11 | EXAMPLES:
12 | * All logins that can log in (enabled + have CONNECT SQL), modified in the last 7 days:
13 | SELECT LoginName, DateModified, CreateSql
14 | FROM dbo.ServerLogins
15 | WHERE CanLogIn = 1
16 | AND DateModified >= DATEADD(DAY, -7, GETUTCDATE())
17 | **************************************************************************************************
18 | This code is licensed as part of Andy Mallon's DBA Database.
19 | https://github.com/amtwo/dba-database/blob/master/LICENSE
20 | ©2014-2020 ● Andy Mallon ● am2.co
21 | *************************************************************************************************/
22 | AS
23 | SELECT
24 | LoginSid = p.sid,
25 | LoginName = p.name,
26 | LoginType = p.type_desc,
27 | DefaultDatabase = p.default_database_name,
28 | VarbinaryPasswordHash = sl.password_hash,
29 | IsPolicyChecked = IIF(sl.is_policy_checked=1,1,0),
30 | IsExpirationChecked = IIF(sl.is_expiration_checked=1,1,0),
31 | IsEnabled = IIF(p.is_disabled = 0,1,0),
32 | CanLogIn = IIF(perm.state IN ('G','W'),1,0),
33 | CreateSql = CASE
34 | WHEN p.type IN ('U','G')
35 | THEN CONCAT(N'CREATE LOGIN ',
36 | QUOTENAME(p.name),
37 | N' FROM WINDOWS',
38 | N' WITH DEFAULT_DATABASE = ',
39 | QUOTENAME(p.default_database_name),
40 | N';'
41 | )
42 | WHEN p.type = 'S'
43 | THEN CONCAT(N'CREATE LOGIN ',
44 | QUOTENAME(p.name),
45 | N' WITH PASSWORD = ',
46 | CONVERT(varchar(514), sl.password_hash, 1),
47 | N' HASHED, SID = ',
48 | CONVERT(varchar(514), p.sid, 1),
49 | N', DEFAULT_DATABASE = ',
50 | QUOTENAME(p.default_database_name),
51 | N', CHECK_POLICY = ',
52 | IIF(sl.is_policy_checked=1,N'ON','OFF'),
53 | N', CHECK_EXPIRATION = ',
54 | IIF(sl.is_expiration_checked=1,N'ON','OFF'),
55 | N';'
56 | )
57 | END,
58 | EnableSql = CONCAT(N'ALTER LOGIN ',
59 | QUOTENAME(p.name), ' ',
60 | IIF(p.is_disabled = 1,' DISABLE',' ENABLE'),
61 | N';'
62 | ),
63 | DateCreated = p.create_date,
64 | DateModified = p.modify_date
65 | FROM sys.server_principals AS p
66 | LEFT JOIN sys.sql_logins AS sl
67 | ON p.name = sl.name
68 | --Left join here to check to determine if the login is enabled & has connect SQL
69 | LEFT JOIN sys.server_permissions AS perm
70 | ON perm.grantee_principal_id = p.principal_id
71 | AND perm.type = 'COSQ'
72 | AND perm.state IN ('G','W')
73 | AND p.is_disabled = 0
74 | WHERE p.type IN ('S','U','G')
75 | AND p.name <> N'sa'
76 | AND p.name NOT LIKE N'##%##';
77 | GO
78 |
--------------------------------------------------------------------------------
/views/dbo.ServerProperties.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.ServerProperties'))
2 | EXEC ('CREATE VIEW dbo.ServerProperties AS SELECT Result = ''This is a stub'';' )
3 | GO
4 |
5 | ALTER VIEW dbo.ServerProperties
6 | /*************************************************************************************************
7 | AUTHOR: Andy Mallon
8 | CREATED: 2021130
9 | EAV-style view to display all server properties, normally accessed via SERVERPROPERTY().
10 | Includes server properties for all supported versions. If the current server is older
11 | and does not support that server property, the PropertyValue will be NULL. See the HelpText
12 | for an indication of limited version support.
13 |
14 | Returned columns:
15 | * PropertyName - Name of the server property, passed as the argument to the SERVERPROPERTY() function.
16 | * PropertyValue - Value returned by the SERVERPROPERTY() function.
17 | * HelpText - Summary of property definition, and version/edition limitations.
18 |
19 | **************************************************************************************************
20 | This code is licensed as part of Andy Mallon's DBA Database.
21 | https://github.com/amtwo/dba-database/blob/production/LICENSE
22 | ©2014-2022 ● Andy Mallon ● am2.co
23 | *************************************************************************************************/
24 | AS
25 | SELECT
26 | PropertyName,
27 | PropertyValue = CONVERT(nvarchar(128), PropertyValue),
28 | HelpText
29 | FROM (
30 | VALUES
31 | ('BuildClrVersion' , SERVERPROPERTY('BuildClrVersion') ,
32 | 'Version of the Microsoft.NET Framework common language runtime (CLR) that was used while building the instance of SQL Server.'),
33 | ('Collation' , SERVERPROPERTY('Collation') ,
34 | 'Name of the default collation for the server.'),
35 | ('CollationID' , SERVERPROPERTY('CollationID') ,
36 | 'ID of the SQL Server collation.'),
37 | ('ComparisonStyle' , SERVERPROPERTY('ComparisonStyle') ,
38 | 'Windows comparison style of the collation.'),
39 | ('ComputerNamePhysicalNetBIOS' , SERVERPROPERTY('ComputerNamePhysicalNetBIOS') ,
40 | 'NetBIOS name of the local computer on which the instance of SQL Server is currently running; For a failover clustered instance, this value changes as the instance fails over between cluster nodes.'),
41 | ('Edition' , SERVERPROPERTY('Edition') ,
42 | 'Installed product edition of the instance of SQL Server.'),
43 | ('EditionID' , SERVERPROPERTY('EditionID') ,
44 | 'EditionID is a bigint representation of the installed product edition of the instance of SQL Server'),
45 | ('EngineEdition' , SERVERPROPERTY('EngineEdition') ,
46 | 'Database Engine edition of the instance of SQL Server installed on the server.'),
47 | ('FilestreamConfiguredLevel' , SERVERPROPERTY('FilestreamConfiguredLevel') ,
48 | 'The configured level of FILESTREAM access.'),
49 | ('FilestreamEffectiveLevel' , SERVERPROPERTY('FilestreamEffectiveLevel') ,
50 | 'The effective level of FILESTREAM access. This value can be different than the FilestreamConfiguredLevel if the level has changed and either an instance restart or a computer restart is pending.'),
51 | ('FilestreamShareName' , SERVERPROPERTY('FilestreamShareName') ,
52 | 'The name of the share used by FILESTREAM.'),
53 | ('HadrManagerStatus' , SERVERPROPERTY('HadrManagerStatus') ,
54 | '2012+; Indicates whether the Always On availability groups manager has started.'),
55 | ('InstanceDefaultBackupPath' , SERVERPROPERTY('InstanceDefaultBackupPath') ,
56 | '2019+; Name of the default path to the instance backup files.'),
57 | ('InstanceDefaultDataPath' , SERVERPROPERTY('InstanceDefaultDataPath') ,
58 | '2012+; Name of the default path to the instance data files.'),
59 | ('InstanceDefaultLogPath' , SERVERPROPERTY('InstanceDefaultLogPath') ,
60 | '2012+; Name of the default path to the instance log files.'),
61 | ('InstanceName' , SERVERPROPERTY('InstanceName') ,
62 | 'Name of the instance.'),
63 | ('IsAdvancedAnalyticsInstalled' , SERVERPROPERTY('IsAdvancedAnalyticsInstalled') ,
64 | 'Returns 1 if the Advanced Analytics feature was installed during setup; 0 if Advanced Analytics was not installed.'),
65 | ('IsBigDataCluster' , SERVERPROPERTY('IsBigDataCluster') ,
66 | '2019 CU4+; Returns 1 if the instance is SQL Server Big Data Cluster; 0 if not.'),
67 | ('IsClustered' , SERVERPROPERTY('IsClustered') ,
68 | 'Server instance is configured in a failover cluster.'),
69 | ('IsExternalAuthenticationOnly' , SERVERPROPERTY('IsExternalAuthenticationOnly') ,
70 | 'Azure SQLDB & MI only; Returns whether Azure AD-only authentication is enabled.'),
71 | ('IsFullTextInstalled' , SERVERPROPERTY('IsFullTextInstalled') ,
72 | ' The full-text and semantic indexing components are installed on the current instance of SQL Server.'),
73 | ('IsHadrEnabled' , SERVERPROPERTY('IsHadrEnabled') ,
74 | '2012+; Always On availability groups is enabled on this server instance.'),
75 | ('IsIntegratedSecurityOnly' , SERVERPROPERTY('IsIntegratedSecurityOnly') ,
76 | 'Server is in integrated security mode.'),
77 | ('IsLocalDB' , SERVERPROPERTY('IsLocalDB') ,
78 | '2012+; Server is an instance of SQL Server Express LocalDB.'),
79 | ('IsPolyBaseInstalled' , SERVERPROPERTY('IsPolyBaseInstalled') ,
80 | '2016+; Returns whether the server instance has the PolyBase feature installed.'),
81 | ('IsSingleUser' , SERVERPROPERTY('IsSingleUser') ,
82 | 'Server is in single-user mode.'),
83 | ('IsTempDbMetadataMemoryOptimized' , SERVERPROPERTY('IsTempDbMetadataMemoryOptimized') ,
84 | '2019+; Returns 1 if tempdb has been enabled to use memory-optimized tables for metadata; 0 if tempdb is using regular, disk-based tables for metadata.'),
85 | ('IsXTPSupported' , SERVERPROPERTY('IsXTPSupported') ,
86 | '2014+; Server supports In-Memory OLTP.'),
87 | ('LCID' , SERVERPROPERTY('LCID') ,
88 | 'Windows locale identifier (LCID) of the collation.'),
89 | ('LicenseType' , SERVERPROPERTY('LicenseType') ,
90 | 'Unused. License information is not preserved or maintained by the SQL Server product. Always returns DISABLED.'),
91 | ('MachineName' , SERVERPROPERTY('MachineName') ,
92 | 'Windows computer name on which the server instance is running. For a failover clustered instance, this value returns the name of the virtual server.'),
93 | ('NumLicenses' , SERVERPROPERTY('NumLicenses') ,
94 | 'Unused. License information is not preserved or maintained by the SQL Server product. Always returns NULL.'),
95 | ('ProcessID' , SERVERPROPERTY('ProcessID') ,
96 | 'Process ID of the SQL Server service. ProcessID is useful in identifying which Sqlservr.exe belongs to this instance.'),
97 | ('ProductBuild' , SERVERPROPERTY('ProductBuild') ,
98 | '2014+; The build number.'),
99 | ('ProductBuildType' , SERVERPROPERTY('ProductBuildType') ,
100 | 'Type of build of the current build. OD = On Demand release a specific customer. GDR = General Distribution Release released through Windows Update.'),
101 | ('ProductLevel' , SERVERPROPERTY('ProductLevel') ,
102 | 'Level of the version of the instance of SQL Server. RTM = Original release version. SP = Service pack version. CTP = Community Technology Preview version.'),
103 | ('ProductMajorVersion' , SERVERPROPERTY('ProductMajorVersion') ,
104 | '2012+; The major version.'),
105 | ('ProductMinorVersion' , SERVERPROPERTY('ProductMinorVersion') ,
106 | '2012+; The minor version.'),
107 | ('ProductUpdateLevel' , SERVERPROPERTY('ProductUpdateLevel') ,
108 | '2012+; Update level of the current build. CU indicates a cumulative update.'),
109 | ('ProductUpdateReference' , SERVERPROPERTY('ProductUpdateReference') ,
110 | '2012+; KB article for that release.'),
111 | ('ProductVersion' , SERVERPROPERTY('ProductVersion') ,
112 | 'Version of the instance of SQL Server, in the form of [major.minor.build.revision].'),
113 | ('ResourceLastUpdateDateTime' , SERVERPROPERTY('ResourceLastUpdateDateTime') ,
114 | 'Returns the date and time that the Resource database was last updated.'),
115 | ('ResourceVersion' , SERVERPROPERTY('ResourceVersion') ,
116 | 'Returns the version Resource database.'),
117 | ('ServerName' , SERVERPROPERTY('ServerName') ,
118 | 'Both the Windows server and instance information associated with a specified instance of SQL Server.'),
119 | ('SqlCharSet' , SERVERPROPERTY('SqlCharSet') ,
120 | 'The SQL character set ID from the collation ID.'),
121 | ('SqlCharSetName' , SERVERPROPERTY('SqlCharSetName') ,
122 | 'The SQL character set name from the collation.'),
123 | ('SqlSortOrder' , SERVERPROPERTY('SqlSortOrder') ,
124 | 'The SQL sort order ID from the collation'),
125 | ('SqlSortOrderName' , SERVERPROPERTY('SqlSortOrderName') ,
126 | 'The SQL sort order name from the collation.')
127 | ) AS ServerProperties (PropertyName, PropertyValue, HelpText);
128 | GO
129 |
--------------------------------------------------------------------------------
/views/dbo.TimeZoneDetailed.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE type = 'V' AND object_id = object_id('dbo.TimeZoneDetailed'))
2 | EXEC ('CREATE VIEW dbo.TimeZoneDetailed AS SELECT stub = ''This is a stub''')
3 | GO
4 | /*************************************************************************************************
5 | AUTHOR: Andy Mallon
6 | **************************************************************************************************
7 | This code is licensed as part of Andy Mallon's DBA Database.
8 | https://github.com/amtwo/dba-database/blob/master/LICENSE
9 | ©2014-2020 ● Andy Mallon ● am2.co
10 | *************************************************************************************************/
11 | ALTER VIEW dbo.TimeZoneDetailed
12 | AS
13 | SELECT tz.TimeZoneId,
14 | tz.DisplayName,
15 | tz.StandardName,
16 | tz.DaylightName,
17 | tz.SupportsDaylightSavingTime,
18 | IsCurrentlyDst = s.is_currently_dst,
19 | CurrentUtcOffset = s.current_utc_offset,
20 | CurrentName = CASE
21 | WHEN s.is_currently_dst = 1 THEN tz.DaylightName
22 | ELSE tz.StandardName
23 | END
24 | FROM dbo.TimeZones tz
25 | JOIN sys.time_zone_info s ON s.name = tz.TimeZoneId;
26 | GO
--------------------------------------------------------------------------------