├── .gitattributes ├── CreateUsers.bat ├── LICENSE ├── README.md ├── SSMS Project ├── Notes - Database Mail.sql ├── Notes - ExtendedEventsNotes.sql ├── Notes - Hidden properties.sql ├── Notes : Use BCP to copy data from one server to another ├── Open a project when starting SSMS ├── Other Peoples SP I use ├── Query - Blocked Queries from System Health.sql ├── Query - DB IO and IO Wait.sql ├── Query - Database Mail Generate Script.sql ├── Query - Default Trace - Permissions.sql ├── Query - Default Trace - Schema Changes.sql ├── Query - Drive Space.sql ├── Query - Find missing Foreign Keys.sql ├── Query - Foreign Keys and Constraints.sql ├── Query - Identify failed queries XE.sql ├── Query - Index Update Stats.sql ├── Query - Lead Blocker.sql ├── Query - Memory Info.sql ├── Query - MissingIndexByQuery.sql ├── Query - Performance.sql ├── Query - SearchTheLog.sql ├── Query - ShredTheDeadlockGraph.sql ├── Query - Statistics Info.sql ├── Query - Statistics properties.sql ├── Query - TableSizes.sql ├── Query - Track index progress.sql ├── Query - View SysAudit.sql ├── Query - Wait Stats.sql ├── Query - WhatsGoingOn.sql ├── Query - Where is my backup.sql └── Query - WhereIsMyBackup.sql ├── sp_AzSQLDBPermissions.sql ├── sp_AzSYNDBPermissions.sql ├── sp_DBPermissions.sql └── sp_SrvPermissions.sql /.gitattributes: -------------------------------------------------------------------------------- 1 | # Auto detect text files and perform LF normalization 2 | * text=auto 3 | 4 | # Custom for Visual Studio 5 | *.cs diff=csharp 6 | 7 | # Standard to msysgit 8 | *.doc diff=astextplain 9 | *.DOC diff=astextplain 10 | *.docx diff=astextplain 11 | *.DOCX diff=astextplain 12 | *.dot diff=astextplain 13 | *.DOT diff=astextplain 14 | *.pdf diff=astextplain 15 | *.PDF diff=astextplain 16 | *.rtf diff=astextplain 17 | *.RTF diff=astextplain 18 | 19 | # linguist overrides 20 | *.sql linguist-language=TSQL 21 | -------------------------------------------------------------------------------- /CreateUsers.bat: -------------------------------------------------------------------------------- 1 | REM This bat file will create a couple of groups and users to use for testing. 2 | REM Note: The passwords are all the same so you should either change them 3 | REM or only use this on throwaway/test servers/VMs. 4 | 5 | REM https://sqlstudies.com/2015/05/20/adding-new-users-groups-in-windows/ 6 | 7 | NET LOCALGROUP "SevenDwarfs" /ADD 8 | 9 | NET USER "Grumpy" "slkjISJW*#&51s" /ADD 10 | NET USER "Happy" "slkjISJW*#&51s" /ADD 11 | NET USER "Sleepy" "slkjISJW*#&51s" /ADD 12 | NET USER "Bashful" "slkjISJW*#&51s" /ADD 13 | NET USER "Sneezy" "slkjISJW*#&51s" /ADD 14 | NET USER "Dopey" "slkjISJW*#&51s" /ADD 15 | NET USER "Doc" "slkjISJW*#&51s" /ADD 16 | NET LOCALGROUP "SevenDwarfs" "Grumpy" /ADD 17 | NET LOCALGROUP "SevenDwarfs" "Happy" /ADD 18 | NET LOCALGROUP "SevenDwarfs" "Sleepy" /ADD 19 | NET LOCALGROUP "SevenDwarfs" "Bashful" /ADD 20 | NET LOCALGROUP "SevenDwarfs" "Sneezy" /ADD 21 | NET LOCALGROUP "SevenDwarfs" "Dopey" /ADD 22 | NET LOCALGROUP "SevenDwarfs" "Doc" /ADD 23 | 24 | 25 | NET LOCALGROUP "Planets" /ADD 26 | 27 | NET USER "Mercury" "slkjISJW*#&51s" /ADD 28 | NET USER "Venus" "slkjISJW*#&51s" /ADD 29 | NET USER "Earth" "slkjISJW*#&51s" /ADD 30 | NET USER "Mars" "slkjISJW*#&51s" /ADD 31 | NET USER "Ceres" "slkjISJW*#&51s" /ADD 32 | NET USER "Jupiter" "slkjISJW*#&51s" /ADD 33 | NET USER "Saturn" "slkjISJW*#&51s" /ADD 34 | NET USER "Uranus" "slkjISJW*#&51s" /ADD 35 | NET USER "Neptune" "slkjISJW*#&51s" /ADD 36 | NET USER "Pluto" "slkjISJW*#&51s" /ADD 37 | NET USER "Charon" "slkjISJW*#&51s" /ADD 38 | NET USER "2003 UB313" "slkjISJW*#&51s" /ADD 39 | NET LOCALGROUP "Planets" "Mercury" /ADD 40 | NET LOCALGROUP "Planets" "Venus" /ADD 41 | NET LOCALGROUP "Planets" "Earth" /ADD 42 | NET LOCALGROUP "Planets" "Mars" /ADD 43 | NET LOCALGROUP "Planets" "Ceres" /ADD 44 | NET LOCALGROUP "Planets" "Jupiter" /ADD 45 | NET LOCALGROUP "Planets" "Saturn" /ADD 46 | NET LOCALGROUP "Planets" "Uranus" /ADD 47 | NET LOCALGROUP "Planets" "Neptune" /ADD 48 | NET LOCALGROUP "Planets" "Pluto" /ADD 49 | NET LOCALGROUP "Planets" "Charon" /ADD 50 | NET LOCALGROUP "Planets" "2003 UB313" /ADD 51 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2019 sqlstudent144 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL Server Scripts 2 | **Standard disclaimer: You use scripts off of the web at your own risk. 3 | I fully expect this script to work without issue but I've been known to be wrong before.** 4 | 5 | The code under the folder *SSMS Project* is the code that I put in my *SSMS Project* solution in SSMS for my personal work. Feel free to use whatever is there under the MIT license I have listed here. Of course if the code is not mine then all permissions go to the person who wrote it. That said: 6 | 7 | **Note** *Not all of the code here is mine. These are the scripts I use on a regular basis and where I've gotten a script from someone else, if possible, I've included the link at the top of the script. If I didn't write it but can't find/remember where I got it from I'll put a note to that effect.* 8 | 9 | Instruction Video: https://www.youtube.com/watch?v=dQw4w9WgXcQ 10 | 11 | ## Detail on the permissions scripts and how they work. (I did write these.) 12 | 13 | ## sp_SrvPermissions 14 | This stored procedure returns 3 data sets. The first dataset is the list of server 15 | principals, the second is role membership, and the third is server level permissions. 16 | 17 | The final 2 columns of each query are "Un-Do"/"Do" scripts. For example removing a member 18 | from a role or adding them to a role. I am fairly confident in the role scripts, however, 19 | the scripts in the server principals query and server permissions query are works in 20 | progress. In particular certificates and keys are not scripted out. Also while the scripts 21 | have worked flawlessly on the systems I've tested them on, these systems are fairly similar 22 | when it comes to security so I can't say that in a more complicated system there won't be 23 | the odd bug. 24 | 25 | Notes on the create script for server principals: 26 | 1. I have included a hashed version of the password and the sid. 27 | This means that when run on another server the password and the sid will remain the same. 28 | 2. In SQL 2005 the create script on the server principals query DOES NOT WORK. This is 29 | because the conversion of the sid (in varbinary) to character doesn't appear to work 30 | as I expected in SQL 2005. It works fine in SQL 2008 and above. If you want to use 31 | this script in SQL 2005 you can change the CONVERTs in the principal script to 32 | `master.sys.fn_varbintohexstr` 33 | 34 | ``` 35 | Parameters: 36 | @Principal 37 | If NOT NULL then all three queries only pull for that server principal. @Principal 38 | is a pattern check. The queries check for any row where the passed in value exists. 39 | It uses the pattern '%' + @Principal + '%' 40 | @Role 41 | If NOT NULL then the roles query will pull members of the role. If it is NOT NULL and 42 | @Principal is NULL then Server principal and permissions query will pull the principal 43 | row for the role and the permissions for the role. @Role is a pattern check. The 44 | queries check for any row where the passed in value exists. It uses the pattern 45 | '%' + @Role + '%' 46 | @Type 47 | If NOT NULL then all three queries will only pull principals of that type. 48 | S = SQL login 49 | U = Windows login 50 | G = Windows group 51 | R = Server role 52 | C = Login mapped to a certificate 53 | K = Login mapped to an asymmetric key 54 | @DBName 55 | If NOT NULL then only return those principals and information about them where the 56 | principal exists within the DB specified. 57 | @UseLikeSearch 58 | When this is set to 1 (the default) then the search parameters will use LIKE (and 59 | %'s will be added around the @Principal and @Role parameters). 60 | When set to 0 searchs will use =. 61 | @IncludeMSShipped 62 | When this is set to 1 (the default) then all principals will be included. When set 63 | to 0 the fixed server roles and SA and Public principals will be excluded. 64 | @DropTempTables 65 | When this is set to 1 (the default) the temp tables used are dropped. If it's 0 66 | then the tempt ables are kept for references after the code has finished. 67 | The temp tables are: 68 | ##SrvPrincipals 69 | ##SrvRoles 70 | ##SrvPermissions 71 | @Output 72 | What type of output is desired. 73 | Default - Either 'Default' or it doesn't match any of the allowed values then the SP 74 | will return the standard 3 outputs. 75 | None - No output at all. Usually used if you keeping the temp tables to do your own 76 | reporting. 77 | CreateOnly - Only return the create scripts where they aren't NULL. 78 | DropOnly - Only return the drop scripts where they aren't NULL. 79 | ScriptsOnly - Return drop and create scripts where they aren't NULL. 80 | Report - Returns one output with one row per principal and a comma delimited list of 81 | roles the principal is a member of and a comma delimited list of the 82 | individual permissions they have. 83 | @Print 84 | Defaults to 0, but if a 1 is passed in then the queries are not run but printed 85 | out instead. This is primarily for debugging. 86 | 87 | Data is ordered as follows 88 | 1st result set: SrvPrincipal 89 | 2nd result set: RoleName, LoginName if the parameter @Role is used else 90 | LoginName, RoleName 91 | 3rd result set: GranteeName 92 | ``` 93 | 94 | 95 | ## sp_DBPermissions 96 | This stored procedure returns 3 data sets. The first dataset is the list of database 97 | principals, the second is role membership, and the third is object and database level 98 | permissions. 99 | 100 | The final 2 columns of each query are "Un-Do"/"Do" scripts. For example removing a member 101 | from a role or adding them to a role. I am fairly confident in the role scripts, however, 102 | the scripts in the database principals query and database/object permissions query are 103 | works in progress. In particular certificates, keys and column level permissions are not 104 | scripted out. Also while the scripts have worked flawlessly on the systems I've tested 105 | them on, these systems are fairly similar when it comes to security so I can't say that 106 | in a more complicated system there won't be the odd bug. 107 | 108 | ``` 109 | Parameters: 110 | @DBName 111 | If NULL use the current database, otherwise give permissions based on the parameter. 112 | 113 | There is a special case where you pass in ALL to the @DBName. In this case the SP 114 | will loop through (yes I'm using a cursor) all of the DBs in sysdatabases and run 115 | the queries into temp tables before returning the results. WARNINGS: If you use 116 | this option and have a large number of databases it will be SLOW. If you use this 117 | option and don't specify any other parameters (say a specific @Principal) and have 118 | even a medium number of databases it will be SLOW. Also the undo/do scripts do 119 | not have USE statements in them so please take that into account. 120 | @Principal 121 | If NOT NULL then all three queries only pull for that database principal. @Principal 122 | is a pattern check. The queries check for any row where the passed in value exists. 123 | It uses the pattern '%' + @Principal + '%' 124 | @Role 125 | If NOT NULL then the roles query will pull members of the role. If it is NOT NULL and 126 | @DBName is NULL then DB principal and permissions query will pull the principal row for 127 | the role and the permissions for the role. @Role is a pattern check. The queries 128 | check for any row where the passed in value exists. It uses the pattern '%' + @Role + 129 | '%' 130 | @Type 131 | If NOT NULL then all three queries will only pull principals of that type. 132 | S = SQL login 133 | U = Windows login 134 | G = Windows group 135 | R = Server role 136 | C = Login mapped to a certificate 137 | K = Login mapped to an asymmetric key 138 | @ObjectName 139 | If NOT NULL then the third query will display permissions specific to the object 140 | specified and the first two queries will display only those users with those specific 141 | permissions. Unfortunately at this point only objects in sys.all_objects will work. 142 | This parameter uses the pattern '%' + @ObjectName + '%' 143 | @Permission 144 | If NOT NULL then the third query will display only permissions that match what is in 145 | the parameter. The first two queries will display only those users with that specific 146 | permission. 147 | @LoginName 148 | If NOT NULL then each of the queries will only pull back database principals that 149 | have the same SID as a login that matches the pattern '%' + @LoginName + '%' 150 | @UseLikeSearch 151 | When this is set to 1 (the default) then the search parameters will use LIKE (and 152 | %'s will be added around the @Principal, @Role, @ObjectName, and @LoginName parameters). 153 | When set to 0 searchs will use =. 154 | @IncludeMSShipped 155 | When this is set to 1 (the default) then all principals will be included. When set 156 | to 0 the fixed server roles and SA and Public principals will be excluded. 157 | @DropTempTables 158 | When this is set to 1 (the default) the temp tables used are dropped. If it's 0 159 | then the tempt ables are kept for references after the code has finished. 160 | The temp tables are: 161 | ##DBPrincipals 162 | ##DBRoles 163 | ##DBPermissions 164 | @Output 165 | What type of output is desired. 166 | Default - Either 'Default' or it doesn't match any of the allowed values then the SP 167 | will return the standard 3 outputs. 168 | None - No output at all. Usually used if you keeping the temp tables to do your own 169 | reporting. 170 | CreateOnly - Only return the create scripts where they aren't NULL. 171 | DropOnly - Only return the drop scripts where they aren't NULL. 172 | ScriptsOnly - Return drop and create scripts where they aren't NULL. 173 | Report - Returns one output with one row per principal and a comma delimited list of 174 | roles the principal is a member of and a comma delimited list of the 175 | individual permissions they have. 176 | @Print 177 | Defaults to 0, but if a 1 is passed in then the queries are not run but printed 178 | out instead. This is primarily for debugging. 179 | 180 | Data is ordered as follows 181 | 1st result set: DBPrincipal 182 | 2nd result set: RoleName, UserName if the parameter @Role is used else 183 | UserName, RoleName 184 | 3rd result set: ObjectName then Grantee_Name if the parameter @ObjectName 185 | is used otherwise Grantee_Name, ObjectName 186 | ``` 187 | -------------------------------------------------------------------------------- /SSMS Project/Notes - Database Mail.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/sqlstudent144/SQL-Server-Scripts/947f690079c019ce0c984901198c39f20af6d3ad/SSMS Project/Notes - Database Mail.sql -------------------------------------------------------------------------------- /SSMS Project/Notes - ExtendedEventsNotes.sql: -------------------------------------------------------------------------------- 1 | /* 2 | https://technet.microsoft.com/en-us/library/dd822788%28v=sql.100%29.aspx?f=255&MSPPError=-2147217396 3 | */ 4 | ---- Events 5 | SELECT p.name AS package, c.event, k.keyword, c.channel, c.description 6 | FROM 7 | ( 8 | SELECT event_package=o.package_guid, o.description, 9 | event=c.object_name, channel=v.map_value 10 | FROM sys.dm_xe_objects o 11 | LEFT JOIN sys.dm_xe_object_columns c ON o.name = c.object_name 12 | INNER JOIN sys.dm_xe_map_values v ON c.type_name = v.name 13 | AND c.column_value = cast(v.map_key AS nvarchar) 14 | WHERE object_type='event' AND (c.name = 'channel' OR c.name IS NULL) 15 | ) c left join 16 | ( 17 | SELECT event_package=c.object_package_guid, event=c.object_name, 18 | keyword=v.map_value 19 | FROM sys.dm_xe_object_columns c INNER JOIN sys.dm_xe_map_values v 20 | ON c.type_name = v.name AND c.column_value = v.map_key 21 | AND c.type_package_guid = v.object_package_guid 22 | INNER JOIN sys.dm_xe_objects o ON o.name = c.object_name 23 | AND o.package_guid=c.object_package_guid 24 | WHERE object_type='event' AND c.name = 'keyword' 25 | ) k 26 | ON 27 | k.event_package = c.event_package AND (k.event = c.event OR k.event IS NULL) 28 | INNER JOIN sys.dm_xe_packages p ON p.guid=c.event_package 29 | WHERE (p.capabilities IS NULL OR p.capabilities & 1 = 0) 30 | --and c.event like '%database%' 31 | ORDER BY channel, keyword, event 32 | ---- Actions 33 | SELECT p.name AS PackageName, 34 | o.name AS ActionName, 35 | o.description AS ActionDescription 36 | FROM sys.dm_xe_objects o 37 | INNER JOIN sys.dm_xe_packages p 38 | ON o.package_guid = p.guid 39 | WHERE o.object_type = 'action' 40 | AND (p.capabilities IS NULL OR p.capabilities & 1 = 0) 41 | ORDER BY PackageName, ActionName; 42 | ---- Targets 43 | 44 | ---- Drop an event session 45 | DROP EVENT SESSION [HIPAA TPA EE] ON SERVER 46 | ---- Create an event session 47 | CREATE EVENT SESSION [HIPAA TPA EE] ON SERVER 48 | ADD EVENT sqlserver.error_reported( 49 | ACTION(sqlserver.database_id,sqlserver.nt_username,sqlserver.sql_text,sqlserver.username) 50 | WHERE ([sqlserver].[database_id]=14)), 51 | ADD EVENT sqlserver.database_stopped( 52 | ACTION(sqlserver.nt_username) 53 | WHERE ([sqlserver].[database_id]=14)), 54 | ADD EVENT sqlserver.database_started( 55 | ACTION(sqlserver.nt_username) 56 | WHERE ([sqlserver].[database_id]=14)) 57 | ADD TARGET package0.asynchronous_file_target( 58 | SET filename='H:\MSSQL10_50.WEBTEST\MSSQL\Audit Files\HIPAA TPA EE.etl', metadatafile='H:\MSSQL10_50.WEBTEST\MSSQL\Audit Files\HIPAA TPA EE.mta') 59 | 60 | GO 61 | 62 | ALTER EVENT SESSION [HIPAA TPA EE] ON SERVER 63 | DROP EVENT sqlserver.database_stopped, 64 | DROP EVENT sqlserver.database_started 65 | 66 | ---- Start an event session 67 | ALTER EVENT SESSION [HIPAA TPA EE] 68 | ON SERVER 69 | STATE=START 70 | 71 | ---- Information about existing session 72 | select * from sys.server_event_sessions 73 | select * from sys.server_event_session_events where event_session_id = 65540 74 | SELECT * FROM sys.server_event_session_actions where event_session_id = 65540 75 | 76 | 77 | ---- Read an EE file 78 | SELECT top 100 *, cast(event_data as xml) as targetdata 79 | FROM sys.fn_xe_file_target_read_file('H:\MSSQL10_50.WEBTEST\MSSQL\Audit Files\HIPAA TPA EE*etl', 'H:\MSSQL10_50.WEBTEST\MSSQL\Audit Files\HIPAA TPA EE*mta', null, null) 80 | 81 | ---- Read from the ring buffer 82 | SELECT CAST(target_data as xml) AS targetdata 83 | INTO #capture_waits_data 84 | FROM sys.dm_xe_session_targets xet 85 | JOIN sys.dm_xe_sessions xes 86 | ON xes.address = xet.event_session_address 87 | WHERE xes.name = 'Ring Buffer - Track Waits' 88 | AND xet.target_name = 'ring_buffer'; 89 | 90 | ---- Interpret data 91 | ---- http://www.brentozar.com/archive/2015/01/query-extended-events-target-xml/ 92 | SELECT xed.event_data.value('(@timestamp)[1]', 'datetime2') AS [timestamp], 93 | xed.event_data.value('(data[@name="error"]/value)[1]', 'int') AS error, 94 | xed.event_data.value('(data[@name="severity"]/value)[1]', 'int') AS severity, 95 | xed.event_data.value('(data[@name="state"]/value)[1]', 'int') AS state, 96 | xed.event_data.value('(data[@name="message"]/value)[1]', 'varchar(200)') AS message, 97 | xed.event_data.value('(action[@name="nt_username"]/value)[1]', 'varchar(200)') AS nt_username, 98 | xed.event_data.value('(action[@name="username"]/value)[1]', 'varchar(200)') AS username, 99 | xed.event_data.value('(action[@name="sql_text"]/value)[1]', 'varchar(max)') AS sql_text 100 | FROM sys.fn_xe_file_target_read_file('H:\MSSQL10_50.WEBTEST\MSSQL\Audit Files\HIPAA TPA EE*etl', 'H:\MSSQL10_50.WEBTEST\MSSQL\Audit Files\HIPAA TPA EE*mta', null, null) 101 | --file 102 | CROSS APPLY (VALUES (CAST(event_data AS XML))) vals(targetdata) 103 | CROSS APPLY targetdata.nodes('//event') AS xed (event_data); 104 | --ring buffer 105 | -- CROSS APPLY targetdata.nodes('//RingBufferTarget/event') AS xed (event_data); 106 | 107 | 108 | 109 | ----- Parse xel file 110 | SELECT 111 | [XML Data], 112 | [XML Data].value('(/event/@timestamp)[1]', 'datetime2') AS [timestamp], 113 | [XML Data].value('(/event/action[@name=''database_name'']/value)[1]','varchar(max)') AS [Database], 114 | [XML Data].value('(/event/data[@name=''duration'']/value)[1]','int') AS [Duration], 115 | [XML Data].value('(/event/action[@name=''session_id'']/value)[1]','int') AS [session_id], 116 | [XML Data].value('(/event/data[@name=''object_name'']/value)[1]','varchar(max)') AS [object_name], 117 | [XML Data].value('(/event/action[@name=''sql_text'']/value)[1]','varchar(max)') AS [sql_text] 118 | INTO #temp 119 | FROM 120 | (SELECT 121 | OBJECT_NAME AS [Event], 122 | CONVERT(XML, event_data) AS [XML Data] 123 | FROM sys.fn_xe_file_target_read_file 124 | ('C:\temp\WhatsGoingOn*.xel',NULL,NULL,NULL) 125 | where event_data like '%sql_text%') as x; 126 | -------------------------------------------------------------------------------- /SSMS Project/Notes - Hidden properties.sql: -------------------------------------------------------------------------------- 1 | SET NOEXEC ON 2 | -- SET NOEXEC OFF 3 | select @@version 4 | 5 | instancedefaultpath, iscatalogupdateallowed, masterfile 6 | errorlogfilename, instancedefaultdatapath, instancedefaultlogpath 7 | SELECT SERVERPROPERTY('iscatalogupdateallowed' ) AS iscatalogupdateallowed 8 | ,SERVERPROPERTY('masterfile' ) AS masterfile 9 | ,SERVERPROPERTY('errorlogfilename' ) AS errorlogfilename 10 | ,SERVERPROPERTY('instancedefaultpath' ) AS instancedefaultpath 11 | ,SERVERPROPERTY('instancedefaultdatapath') AS instancedefaultdatapath 12 | ,SERVERPROPERTY('instancedefaultlogpath' ) AS instancedefaultlogpath 13 | 14 | -------------------------------------------------------------------------------- /SSMS Project/Notes : Use BCP to copy data from one server to another: -------------------------------------------------------------------------------- 1 | ----------------------------------------------------------------- 2 | --- Obviously this isn't SQL code. These are the BCP comamnds 3 | --- needed to copy a table from one instance to another. 4 | --- Run them in a cmdshell with an account that has access to 5 | --- both instances. 6 | ----------------------------------------------------------------- 7 | 8 | -- Create the output file 9 | bcp "dbo.SourceTableName" out "C:\temp\DataFile.out" -S "SourceServer\SourceInstance" -d SourceDB -n -T 10 | 11 | -- Create the format file. 12 | bcp DBName.dbo.SourceTableName format nul -f c:\temp\FormatFile.fmt -T -n -S "SourceServer\SourceInstance" 13 | 14 | ----------------------------------------------------------------- 15 | --- If needed script out the table and create in the new location 16 | ----------------------------------------------------------------- 17 | 18 | -- Import the data. The new table has to already exist. 19 | -- Add -E to include the identiy values 20 | bcp DBName.dbo.DestTableName IN "C:\temp\DataFile.out" -S "DestServer\DestInstance" -T -f c:\temp\FormatFile.fmt 21 | -------------------------------------------------------------------------------- /SSMS Project/Open a project when starting SSMS: -------------------------------------------------------------------------------- 1 | "C:\Program Files (x86)\Microsoft SQL Server Management Studio 18\Common7\IDE\Ssms.exe" "\\plndfs\home\uf9a94\SQL Server Management Studio\SQL Server Scripts1\SQL Server Scripts1.ssmssqlproj" 2 | -------------------------------------------------------------------------------- /SSMS Project/Other Peoples SP I use: -------------------------------------------------------------------------------- 1 | sp_BlitzFirst 2 | sp_BlitzIndex 3 | sp_help_revlogin 4 | sp_HumanEvents 5 | sp_RestoreGene 6 | sp_SQLSkills_SQL2008_helpindex 7 | sp_SQLSkills_SQL2012_helpindex 8 | sp_WhoIsActive 9 | -------------------------------------------------------------------------------- /SSMS Project/Query - Blocked Queries from System Health.sql: -------------------------------------------------------------------------------- 1 | -- Don't think this is mine but I can't remember where I got it from. 2 | SELECT 3 | xed.event_data.value('(@timestamp)[1]', 'datetime2') AS [timestamp], 4 | xed.event_data.value('(data[@name="wait_type"]/text)[1]', 'varchar(25)') AS wait_type, 5 | xed.event_data.value('(data[@name="duration"]/value)[1]', 'int')/1000/60.0 AS wait_time_in_min, 6 | xed.event_data.value('(action[@name="sql_text"]/value)[1]', 'varchar(max)') AS sql_text, 7 | xed.event_data.value('(action[@name="session_id"]/value)[1]', 'varchar(25)') AS session_id, 8 | xData.Event_Data, 9 | fx.object_name 10 | FROM sys.fn_xe_file_target_read_file ('system_health*.xel','system_health*.xem',null,null) fx 11 | CROSS APPLY (SELECT CAST(fx.event_data AS XML) AS Event_Data) AS xData 12 | CROSS APPLY xData.Event_Data.nodes('//event') AS xed (event_data) 13 | WHERE fx.object_name = 'wait_info'; 14 | -------------------------------------------------------------------------------- /SSMS Project/Query - DB IO and IO Wait.sql: -------------------------------------------------------------------------------- 1 | -- I think I got this from sqlskills but not certain. 2 | SELECT DB_NAME(fs.database_id) DBName, 3 | -- DB Values 4 | SUM(vals.num_of_mb_read) AS DB_Reads, 5 | CASE WHEN SUM(fs.num_of_reads) > 0 THEN 6 | SUM(fs.io_stall_read_ms) / SUM(fs.num_of_reads) ELSE 0 END 7 | AS DB_Read_Wait, 8 | SUM(vals.num_of_mb_written) AS DB_Writes, 9 | CASE WHEN SUM(fs.num_of_writes) > 0 THEN 10 | SUM(fs.io_stall_write_ms) / SUM(fs.num_of_writes) ELSE 0 END 11 | AS DB_Write_Wait, 12 | SUM(vals.size_on_disk_mb) AS DB_Size, 13 | -- Data file only values 14 | SUM(CASE WHEN mf.type = 0 THEN vals.num_of_mb_read ELSE 0 END) AS Data_Reads, 15 | CASE WHEN SUM(vals.num_of_reads_data) > 0 THEN 16 | SUM(vals.io_stall_read_ms_data) / SUM(vals.num_of_reads_data) ELSE 0 END 17 | AS Data_Read_Wait, 18 | SUM(CASE WHEN mf.type = 0 THEN vals.num_of_mb_written ELSE 0 END) AS Data_Writes, 19 | CASE WHEN SUM(vals.num_of_writes_data) > 0 THEN 20 | SUM(vals.io_stall_writes_ms_data) / SUM(vals.num_of_writes_data) ELSE 0 END 21 | AS Data_Write_Wait, 22 | SUM(CASE WHEN mf.type = 0 THEN vals.size_on_disk_mb ELSE 0 END) AS Data_Size, 23 | -- Log file only values 24 | SUM(CASE WHEN mf.type = 1 THEN vals.num_of_mb_read ELSE 0 END) AS Log_Reads, 25 | CASE WHEN SUM(vals.num_of_reads_log) > 0 THEN 26 | SUM(vals.io_stall_read_ms_log) / SUM(vals.num_of_reads_log) ELSE 0 END 27 | AS Log_Read_Wait, 28 | SUM(CASE WHEN mf.type = 1 THEN vals.num_of_mb_written ELSE 0 END) AS Log_Writes, 29 | CASE WHEN SUM(vals.num_of_writes_log) > 0 THEN 30 | SUM(vals.io_stall_writes_ms_log) / SUM(vals.num_of_writes_log) ELSE 0 END 31 | AS Log_Write_Wait, 32 | SUM(CASE WHEN mf.type = 1 THEN vals.size_on_disk_mb ELSE 0 END) AS Log_Size 33 | FROM sys.dm_io_virtual_file_stats(null,null) fs 34 | JOIN sys.master_files mf 35 | ON fs.database_id = mf.database_id 36 | AND fs.file_id = mf.file_id 37 | CROSS APPLY (SELECT CAST(fs.num_of_bytes_read/1024/1024.0 AS Decimal(18,2)), 38 | CAST(fs.num_of_bytes_written/1024/1024.0 AS Decimal(18,2)), 39 | CAST(fs.size_on_disk_bytes/1024/1024.0 AS Decimal(18,2)), 40 | CASE WHEN mf.type = 0 THEN fs.num_of_reads ELSE 0 END, 41 | CASE WHEN mf.type = 0 THEN fs.io_stall_read_ms ELSE 0 END, 42 | CASE WHEN mf.type = 0 THEN fs.num_of_writes ELSE 0 END, 43 | CASE WHEN mf.type = 0 THEN fs.io_stall_write_ms ELSE 0 END, 44 | CASE WHEN mf.type = 1 THEN fs.num_of_reads ELSE 0 END, 45 | CASE WHEN mf.type = 1 THEN fs.io_stall_read_ms ELSE 0 END, 46 | CASE WHEN mf.type = 1 THEN fs.num_of_writes ELSE 0 END, 47 | CASE WHEN mf.type = 1 THEN fs.io_stall_write_ms ELSE 0 END 48 | ) AS vals(num_of_mb_read, num_of_mb_written, size_on_disk_mb, 49 | num_of_reads_data, io_stall_read_ms_data, 50 | num_of_writes_data, io_stall_writes_ms_data, 51 | num_of_reads_log, io_stall_read_ms_log, 52 | num_of_writes_log, io_stall_writes_ms_log ) 53 | GROUP BY fs.database_id 54 | ORDER BY 1 55 | -------------------------------------------------------------------------------- /SSMS Project/Query - Database Mail Generate Script.sql: -------------------------------------------------------------------------------- 1 | -- http://www.sqlservercentral.com/scripts/Mail+Profile/171566/ 2 | USE msdb 3 | GO 4 | 5 | Declare @TheResults varchar(max), 6 | @vbCrLf CHAR(2) 7 | SET @vbCrLf = CHAR(13) + CHAR(10) 8 | SET @TheResults = ' 9 | use master 10 | go 11 | sp_configure ''show advanced options'',1 12 | go 13 | reconfigure with override 14 | go 15 | sp_configure ''Database Mail XPs'',1 16 | --go 17 | --sp_configure ''SQL Mail XPs'',0 18 | go 19 | reconfigure 20 | go 21 | ' 22 | SELECT @TheResults = @TheResults + ' 23 | -------------------------------------------------------------------------------------------------- 24 | -- BEGIN Mail Settings ' + p.name + ' 25 | -------------------------------------------------------------------------------------------------- 26 | IF NOT EXISTS(SELECT * FROM msdb.dbo.sysmail_profile WHERE name = ''' + p.name + ''') 27 | BEGIN 28 | --CREATE Profile [' + p.name + '] 29 | EXECUTE msdb.dbo.sysmail_add_profile_sp 30 | @profile_name = ''' + p.name + ''', 31 | @description = ''' + ISNULL(p.description,'') + '''; 32 | END --IF EXISTS profile 33 | ' 34 | + 35 | ' 36 | IF NOT EXISTS(SELECT * FROM msdb.dbo.sysmail_account WHERE name = ''' + a.name + ''') 37 | BEGIN 38 | --CREATE Account [' + a.name + '] 39 | EXECUTE msdb.dbo.sysmail_add_account_sp 40 | @account_name = ' + CASE WHEN a.name IS NULL THEN ' NULL ' ELSE + '''' + a.name + '''' END + ', 41 | @email_address = ' + CASE WHEN a.email_address IS NULL THEN ' NULL ' ELSE + '''' + a.email_address + '''' END + ', 42 | @display_name = ' + CASE WHEN a.display_name IS NULL THEN ' NULL ' ELSE + '''' + a.display_name + '''' END + ', 43 | @replyto_address = ' + CASE WHEN a.replyto_address IS NULL THEN ' NULL ' ELSE + '''' + a.replyto_address + '''' END + ', 44 | @description = ' + CASE WHEN a.description IS NULL THEN ' NULL ' ELSE + '''' + a.description + '''' END + ', 45 | @mailserver_name = ' + CASE WHEN s.servername IS NULL THEN ' NULL ' ELSE + '''' + s.servername + '''' END + ', 46 | @mailserver_type = ' + CASE WHEN s.servertype IS NULL THEN ' NULL ' ELSE + '''' + s.servertype + '''' END + ', 47 | @port = ' + CASE WHEN s.port IS NULL THEN ' NULL ' ELSE + '''' + CONVERT(VARCHAR,s.port) + '''' END + ', 48 | @username = ' + CASE WHEN c.credential_identity IS NULL THEN ' NULL ' ELSE + '''' + c.credential_identity + '''' END + ', 49 | @password = ' + CASE WHEN c.credential_identity IS NULL THEN ' NULL ' ELSE + '''NotTheRealPassword''' END + ', 50 | @use_default_credentials = ' + CASE WHEN s.use_default_credentials = 1 THEN ' 1 ' ELSE ' 0 ' END + ', 51 | @enable_ssl = ' + CASE WHEN s.enable_ssl = 1 THEN ' 1 ' ELSE ' 0 ' END + '; 52 | END --IF EXISTS account 53 | ' 54 | + ' 55 | IF NOT EXISTS(SELECT * 56 | FROM msdb.dbo.sysmail_profileaccount pa 57 | INNER JOIN msdb.dbo.sysmail_profile p ON pa.profile_id = p.profile_id 58 | INNER JOIN msdb.dbo.sysmail_account a ON pa.account_id = a.account_id 59 | WHERE p.name = ''' + p.name + ''' 60 | AND a.name = ''' + a.name + ''') 61 | BEGIN 62 | -- Associate Account [' + a.name + '] to Profile [' + p.name + '] 63 | EXECUTE msdb.dbo.sysmail_add_profileaccount_sp 64 | @profile_name = ''' + p.name + ''', 65 | @account_name = ''' + a.name + ''', 66 | @sequence_number = ' + CONVERT(VARCHAR,pa.sequence_number) + ' ; 67 | END 68 | --IF EXISTS associate accounts to profiles 69 | --------------------------------------------------------------------------------------------------- 70 | -- Drop Settings For ' + p.name + ' 71 | -------------------------------------------------------------------------------------------------- 72 | /* 73 | IF EXISTS(SELECT * 74 | FROM msdb.dbo.sysmail_profileaccount pa 75 | INNER JOIN msdb.dbo.sysmail_profile p ON pa.profile_id = p.profile_id 76 | INNER JOIN msdb.dbo.sysmail_account a ON pa.account_id = a.account_id 77 | WHERE p.name = ''' + p.name + ''' 78 | AND a.name = ''' + a.name + ''') 79 | BEGIN 80 | EXECUTE msdb.dbo.sysmail_delete_profileaccount_sp @profile_name = ''' + p.name + ''',@account_name = ''' + a.name + ''' 81 | END 82 | IF EXISTS(SELECT * FROM msdb.dbo.sysmail_account WHERE name = ''' + a.name + ''') 83 | BEGIN 84 | EXECUTE msdb.dbo.sysmail_delete_account_sp @account_name = ''' + a.name + ''' 85 | END 86 | IF EXISTS(SELECT * FROM msdb.dbo.sysmail_profile WHERE name = ''' + p.name + ''') 87 | BEGIN 88 | EXECUTE msdb.dbo.sysmail_delete_profile_sp @profile_name = ''' + p.name + ''' 89 | END 90 | */ 91 | ' 92 | FROM msdb.dbo.sysmail_profile p 93 | INNER JOIN msdb.dbo.sysmail_profileaccount pa ON p.profile_id = pa.profile_id 94 | INNER JOIN msdb.dbo.sysmail_account a ON pa.account_id = a.account_id 95 | LEFT OUTER JOIN msdb.dbo.sysmail_server s ON a.account_id = s.account_id 96 | LEFT OUTER JOIN sys.credentials c ON s.credential_id = c.credential_id 97 | 98 | ;WITH E01(N) AS (SELECT 1 UNION ALL SELECT 1 UNION ALL 99 | SELECT 1 UNION ALL SELECT 1 UNION ALL 100 | SELECT 1 UNION ALL SELECT 1 UNION ALL 101 | SELECT 1 UNION ALL SELECT 1 UNION ALL 102 | SELECT 1 UNION ALL SELECT 1), -- 10 or 10E01 rows 103 | E02(N) AS (SELECT 1 FROM E01 a, E01 b), -- 100 or 10E02 rows 104 | E04(N) AS (SELECT 1 FROM E02 a, E02 b), -- 10,000 or 10E04 rows 105 | E08(N) AS (SELECT 1 FROM E04 a, E04 b), --100,000,000 or 10E08 rows 106 | --E16(N) AS (SELECT 1 FROM E08 a, E08 b), --10E16 or more rows than you'll EVER need, 107 | Tally(N) AS (SELECT ROW_NUMBER() OVER (ORDER BY N) FROM E08), 108 | ItemSplit( 109 | ItemOrder, 110 | Item 111 | ) as ( 112 | SELECT N, 113 | SUBSTRING(@vbCrLf + @TheResults + @vbCrLf,N + DATALENGTH(@vbCrLf),CHARINDEX(@vbCrLf,@vbCrLf + @TheResults + @vbCrLf,N + DATALENGTH(@vbCrLf)) - N - DATALENGTH(@vbCrLf)) 114 | FROM Tally 115 | WHERE N < DATALENGTH(@vbCrLf + @TheResults) 116 | --WHERE N < DATALENGTH(@vbCrLf + @INPUT) -- REMOVED added @vbCrLf 117 | AND SUBSTRING(@vbCrLf + @TheResults + @vbCrLf,N,DATALENGTH(@vbCrLf)) = @vbCrLf --Notice how we find the delimiter 118 | ) 119 | select 120 | row_number() over (order by ItemOrder) as ItemID, 121 | Item 122 | from ItemSplit 123 | -------------------------------------------------------------------------------- /SSMS Project/Query - Default Trace - Permissions.sql: -------------------------------------------------------------------------------- 1 | -- Gotten from here: https://www.sqlservercentral.com/articles/find-permission-changes-in-the-default-trace 2 | 3 | DECLARE @tracefile VARCHAR(500) 4 | -- Get path of default trace file 5 | SELECT @tracefile = CAST(value AS VARCHAR(500)) 6 | FROM ::fn_trace_getinfo(DEFAULT) 7 | WHERE traceid = 1 8 | AND property = 2 9 | 10 | -- Get security changes from the default trace 11 | SELECT * 12 | FROM ::fn_trace_gettable(@tracefile, DEFAULT) trcdata -- DEFAULT means all trace files will be read 13 | INNER JOIN sys.trace_events evt ON trcdata.EventClass = evt.trace_event_id 14 | WHERE trcdata.EventClass IN (102, 103, 104, 105, 106, 108, 109, 110, 111) 15 | ORDER BY trcdata.StartTime 16 | --trcdata.DatabaseID 17 | --trcdata.TargetLoginName 18 | -------------------------------------------------------------------------------- /SSMS Project/Query - Default Trace - Schema Changes.sql: -------------------------------------------------------------------------------- 1 | -- https://blog.sqlterritory.com/2018/11/20/5-ways-to-track-database-schema-changes-part-1-default-trace/ 2 | 3 | DECLARE @file varchar(255); 4 | SELECT @file = path FROM sys.traces WHERE is_default = 1; 5 | 6 | WITH TraceCTE AS ( 7 | SELECT DatabaseID, 8 | DatabaseName, 9 | LoginName, 10 | HostName, 11 | ApplicationName, 12 | SPID, 13 | StartTime, 14 | LEAD(StartTime) OVER (PARTITION BY XactSequence ORDER BY EventSequence) AS EndTime, 15 | EventClass, 16 | CASE EventClass 17 | WHEN 46 THEN 'Object:Created' 18 | WHEN 47 THEN 'Object:Deleted' 19 | WHEN 164 THEN 'Object:Altered' 20 | ELSE CAST(EventClass AS VARCHAR(max)) 21 | END AS EventClassDesc, 22 | ObjectType, 23 | CASE ObjectType 24 | WHEN 8259 THEN 'Check Constraint' 25 | WHEN 8260 THEN 'Default (constraint or standalone)' 26 | WHEN 8262 THEN 'Foreign-key Constraint' 27 | WHEN 8272 THEN 'Stored Procedure' 28 | WHEN 8274 THEN 'Rule' 29 | WHEN 8275 THEN 'System Table' 30 | WHEN 8276 THEN 'Trigger on Server' 31 | WHEN 8277 THEN '(User-defined) Table' 32 | WHEN 8278 THEN 'View' 33 | WHEN 8280 THEN 'Extended Stored Procedure' 34 | WHEN 16724 THEN 'CLR Trigger' 35 | WHEN 16964 THEN 'Database' 36 | WHEN 16975 THEN 'Object' 37 | WHEN 17222 THEN 'FullText Catalog' 38 | WHEN 17232 THEN 'CLR Stored Procedure' 39 | WHEN 17235 THEN 'Schema' 40 | WHEN 17475 THEN 'Credential' 41 | WHEN 17491 THEN 'DDL Event' 42 | WHEN 17741 THEN 'Management Event' 43 | WHEN 17747 THEN 'Security Event' 44 | WHEN 17749 THEN 'User Event' 45 | WHEN 17985 THEN 'CLR Aggregate Function' 46 | WHEN 17993 THEN 'Inline Table-valued SQL Function' 47 | WHEN 18000 THEN 'Partition Function' 48 | WHEN 18002 THEN 'Replication Filter Procedure' 49 | WHEN 18004 THEN 'Table-valued SQL Function' 50 | WHEN 18259 THEN 'Server Role' 51 | WHEN 18263 THEN 'Microsoft Windows Group' 52 | WHEN 19265 THEN 'Asymmetric Key' 53 | WHEN 19277 THEN 'Master Key' 54 | WHEN 19280 THEN 'Primary Key' 55 | WHEN 19283 THEN 'ObfusKey' 56 | WHEN 19521 THEN 'Asymmetric Key Login' 57 | WHEN 19523 THEN 'Certificate Login' 58 | WHEN 19538 THEN 'Role' 59 | WHEN 19539 THEN 'SQL Login' 60 | WHEN 19543 THEN 'Windows Login' 61 | WHEN 20034 THEN 'Remote Service Binding' 62 | WHEN 20036 THEN 'Event Notification on Database' 63 | WHEN 20037 THEN 'Event Notification' 64 | WHEN 20038 THEN 'Scalar SQL Function' 65 | WHEN 20047 THEN 'Event Notification on Object' 66 | WHEN 20051 THEN 'Synonym' 67 | WHEN 20307 THEN 'Sequence' 68 | WHEN 20549 THEN 'End Point' 69 | WHEN 20801 THEN 'Adhoc Queries which may be cached' 70 | WHEN 20816 THEN 'Prepared Queries which may be cached' 71 | WHEN 20819 THEN 'Service Broker Service Queue' 72 | WHEN 20821 THEN 'Unique Constraint' 73 | WHEN 21057 THEN 'Application Role' 74 | WHEN 21059 THEN 'Certificate' 75 | WHEN 21075 THEN 'Server' 76 | WHEN 21076 THEN 'Transact-SQL Trigger' 77 | WHEN 21313 THEN 'Assembly' 78 | WHEN 21318 THEN 'CLR Scalar Function' 79 | WHEN 21321 THEN 'Inline scalar SQL Function' 80 | WHEN 21328 THEN 'Partition Scheme' 81 | WHEN 21333 THEN 'User' 82 | WHEN 21571 THEN 'Service Broker Service Contract' 83 | WHEN 21572 THEN 'Trigger on Database' 84 | WHEN 21574 THEN 'CLR Table-valued Function' 85 | WHEN 21577 THEN 'Internal Table (For example, XML Node Table, Queue Table.)' 86 | WHEN 21581 THEN 'Service Broker Message Type' 87 | WHEN 21586 THEN 'Service Broker Route' 88 | WHEN 21587 THEN 'Statistics' 89 | WHEN 21825 THEN 'User' 90 | WHEN 21827 THEN 'User' 91 | WHEN 21831 THEN 'User' 92 | WHEN 21843 THEN 'User' 93 | WHEN 21847 THEN 'User' 94 | WHEN 22099 THEN 'Service Broker Service' 95 | WHEN 22601 THEN 'Index' 96 | WHEN 22604 THEN 'Certificate Login' 97 | WHEN 22611 THEN 'XMLSchema' 98 | WHEN 22868 THEN 'Type' 99 | ELSE CAST(ObjectType AS VARCHAR(max)) 100 | END AS ObjectTypeDesc, 101 | ObjectID, 102 | ObjectName, 103 | EventSubClass 104 | FROM sys.fn_trace_gettable(@file, DEFAULT) 105 | WHERE EventClass IN (46,47,164) 106 | AND ApplicationName <> 'SQLServerCEIP' --Telemetry 107 | ) 108 | SELECT * FROM TraceCTE 109 | WHERE EventSubClass = 0 110 | -- Last 24 hours 111 | -- AND StartTime BETWEEN DATEADD(day,-1,GetDate()) AND GetDate() 112 | -- Yesterday 113 | -- AND StartTime > CAST(CAST(DATEADD(day,-1,GetDate()) AS date) AS datetime) AND StartTime < CAST(CAST(GetDate() AS date) AS datetime) 114 | -- Last hour 115 | -- AND StartTime > DATEADD(hour,-1,GetDate()) 116 | -- Previous hour 117 | AND StartTime < dateadd(hour, datediff(hour, 0, GETDATE()), 0) AND StartTime >= dateadd(hour, datediff(hour, 0, DATEADD(HOUR, -1, GETDATE())), 0) 118 | -- Specific Database 119 | -- AND DatabaseName = 'Pegasys2' 120 | ORDER BY StartTime; -------------------------------------------------------------------------------- /SSMS Project/Query - Drive Space.sql: -------------------------------------------------------------------------------- 1 | -- Get-Volume 2 | -- Found here: https://sqlsanctum.wordpress.com/2016/02/05/get-drive-sizes-using-sql-or-powershell/ 3 | SELECT 4 | [Drive] = volume_mount_point 5 | ,[FreeSpaceGB] = available_bytes/1024/1024/1024.0 6 | ,[SizeGB] = total_bytes/1024/1024/1024.0 7 | ,[PercentFree] = CONVERT(INT,CONVERT(DECIMAL(15,2),available_bytes) / total_bytes * 100) 8 | FROM sys.master_files mf 9 | CROSS APPLY sys.dm_os_volume_stats(mf.database_id,mf.file_id) 10 | --Optional where clause filters drives with more than 20% free space 11 | -- WHERE CONVERT(INT,CONVERT(DECIMAL(15,2),available_bytes) / total_bytes * 100) < 20 12 | GROUP BY 13 | volume_mount_point 14 | ,total_bytes/1024/1024 --/1024 15 | ,available_bytes/1024/1024 --/1024 16 | ,CONVERT(INT,CONVERT(DECIMAL(15,2),available_bytes) / total_bytes * 100) 17 | ORDER BY [Drive] 18 | 19 | 20 | exec xp_fixeddrives 21 | -------------------------------------------------------------------------------- /SSMS Project/Query - Find missing Foreign Keys.sql: -------------------------------------------------------------------------------- 1 | -- Don't think this is mine but I can't remember where I got it from. 2 | WITH pkColumns AS 3 | (SELECT o.name AS TableName, i.name AS IndexName, c.name AS ColumnName 4 | FROM sys.indexes i 5 | JOIN sys.index_columns ic 6 | ON i.object_id = ic.object_id 7 | AND i.index_id = ic.index_id 8 | JOIN sys.columns c 9 | ON ic.object_id = c.object_id 10 | AND ic.column_id = c.column_id 11 | JOIN sys.objects o 12 | ON i.object_id = o.object_id 13 | WHERE i.is_primary_key = 1), 14 | nonpkColumns AS 15 | (SELECT o.name AS TableName, c.name AS ColumnName 16 | FROM sys.objects o 17 | JOIN sys.columns c 18 | ON o.object_id = c.object_id 19 | JOIN pkColumns pk 20 | ON pk.TableName <> o.name 21 | AND pk.ColumnName = c.name 22 | ), 23 | fkColumns AS 24 | (SELECT name AS ForeignKey_Name, 25 | object_schema_name(referenced_object_id) Parent_Schema_Name, 26 | object_name(referenced_object_id) Parent_Object_Name, 27 | object_schema_name(parent_object_id) Child_Schema_Name, 28 | object_name(parent_object_id) Child_Object_Name, 29 | is_disabled, is_not_trusted, 30 | 'ALTER TABLE ' + quotename(object_schema_name(parent_object_id)) + '.' + 31 | quotename(object_name(parent_object_id)) + ' NOCHECK CONSTRAINT ' + 32 | object_name(object_id) + '; ' AS Disable, 33 | 'ALTER TABLE ' + quotename(object_schema_name(parent_object_id)) + '.' + 34 | quotename(object_name(parent_object_id)) + ' WITH CHECK CHECK CONSTRAINT ' + 35 | object_name(object_id) + '; ' AS Enable 36 | FROM sys.foreign_keys ) 37 | SELECT nPK.*, PK.TableName, 38 | 'ALTER TABLE ' + nPK.TableName + ' ADD CONSTRAINT fk_' +nPK.TableName + '_' + nPK.ColumnName + ' FOREIGN KEY (' + nPK.ColumnName+') REFERENCES '+PK.TableName+'('+nPK.ColumnName+')' 39 | 40 | FROM nonpkColumns nPK 41 | JOIN pkColumns PK 42 | ON nPK.ColumnName = PK.ColumnName 43 | WHERE --PK.ColumnName = 'CaseId' AND 44 | NOT EXISTS (SELECT * FROM fkColumns fkC 45 | WHERE PK.TableName = fkC.Parent_Object_Name 46 | AND nPK.TableName = fkC.Child_Object_Name) 47 | AND PK.TableName <> 'dtproperties' 48 | 49 | -------------------------------------------------------------------------------- /SSMS Project/Query - Foreign Keys and Constraints.sql: -------------------------------------------------------------------------------- 1 | SELECT 'ALTER TABLE ' + QUOTENAME(OBJECT_SCHEMA_NAME(parent_object_id)) + '.' + QUOTENAME(OBJECT_NAME(parent_object_id)) + 2 | ' WITH CHECK CHECK CONSTRAINT ' + quotename(name) 3 | FROM sys.foreign_keys 4 | WHERE is_not_trusted = 1 5 | 6 | 7 | SELECT 8 | 'ALTER TABLE ' 9 | + QUOTENAME(cs.name) + '.' + QUOTENAME(ct.name) 10 | + ' DROP CONSTRAINT ' + QUOTENAME(fk.name) 11 | FROM sys.foreign_keys AS fk 12 | INNER JOIN sys.tables AS rt -- referenced table 13 | ON fk.referenced_object_id = rt.[object_id] 14 | INNER JOIN sys.schemas AS rs 15 | ON rt.[schema_id] = rs.[schema_id] 16 | INNER JOIN sys.tables AS ct -- constraint table 17 | ON fk.parent_object_id = ct.[object_id] 18 | INNER JOIN sys.schemas AS cs 19 | ON ct.[schema_id] = cs.[schema_id] 20 | WHERE rt.is_ms_shipped = 0 AND ct.is_ms_shipped = 0; 21 | 22 | 23 | SELECT 24 | 'ALTER TABLE ' 25 | + QUOTENAME(cs.name) + '.' + QUOTENAME(ct.name) 26 | + ' ADD CONSTRAINT ' + QUOTENAME(fk.name) 27 | + ' FOREIGN KEY (' + STUFF((SELECT ',' + QUOTENAME(c.name) 28 | -- get all the columns in the constraint table 29 | FROM sys.columns AS c 30 | INNER JOIN sys.foreign_key_columns AS fkc 31 | ON fkc.parent_column_id = c.column_id 32 | AND fkc.parent_object_id = c.[object_id] 33 | WHERE fkc.constraint_object_id = fk.[object_id] 34 | ORDER BY fkc.constraint_column_id 35 | FOR XML PATH(N''), TYPE).value(N'.[1]', N'nvarchar(max)'), 1, 1, N'') 36 | + ') REFERENCES ' + QUOTENAME(rs.name) + '.' + QUOTENAME(rt.name) 37 | + '(' + STUFF((SELECT ',' + QUOTENAME(c.name) 38 | -- get all the referenced columns 39 | FROM sys.columns AS c 40 | INNER JOIN sys.foreign_key_columns AS fkc 41 | ON fkc.referenced_column_id = c.column_id 42 | AND fkc.referenced_object_id = c.[object_id] 43 | WHERE fkc.constraint_object_id = fk.[object_id] 44 | ORDER BY fkc.constraint_column_id 45 | FOR XML PATH(N''), TYPE).value(N'.[1]', N'nvarchar(max)'), 1, 1, N'') + '); '+char(13)++char(10)+'GO' 46 | FROM sys.foreign_keys AS fk 47 | INNER JOIN sys.tables AS rt -- referenced table 48 | ON fk.referenced_object_id = rt.[object_id] 49 | INNER JOIN sys.schemas AS rs 50 | ON rt.[schema_id] = rs.[schema_id] 51 | INNER JOIN sys.tables AS ct -- constraint table 52 | ON fk.parent_object_id = ct.[object_id] 53 | INNER JOIN sys.schemas AS cs 54 | ON ct.[schema_id] = cs.[schema_id] 55 | WHERE rt.is_ms_shipped = 0 AND ct.is_ms_shipped = 0; 56 | 57 | 58 | 59 | 60 | SELECT 61 | QUOTENAME(cs.name) Schema_Name 62 | , QUOTENAME(ct.name) Table_Name 63 | , QUOTENAME(fk.name) Constraint_Name 64 | , STUFF((SELECT ',' + QUOTENAME(c.name) 65 | -- get all the columns in the constraint table 66 | FROM sys.columns AS c 67 | INNER JOIN sys.foreign_key_columns AS fkc 68 | ON fkc.parent_column_id = c.column_id 69 | AND fkc.parent_object_id = c.[object_id] 70 | WHERE fkc.constraint_object_id = fk.[object_id] 71 | ORDER BY fkc.constraint_column_id 72 | FOR XML PATH(N''), TYPE).value(N'.[1]', N'nvarchar(max)'), 1, 1, N'') Column_List 73 | , QUOTENAME(rs.name) Ref_Schema_Name 74 | , QUOTENAME(rt.name) Ref_Table_Name 75 | , STUFF((SELECT ',' + QUOTENAME(c.name) 76 | -- get all the referenced columns 77 | FROM sys.columns AS c 78 | INNER JOIN sys.foreign_key_columns AS fkc 79 | ON fkc.referenced_column_id = c.column_id 80 | AND fkc.referenced_object_id = c.[object_id] 81 | WHERE fkc.constraint_object_id = fk.[object_id] 82 | ORDER BY fkc.constraint_column_id 83 | FOR XML PATH(N''), TYPE).value(N'.[1]', N'nvarchar(max)'), 1, 1, N'') Ref_Column_list 84 | FROM sys.foreign_keys AS fk 85 | INNER JOIN sys.tables AS rt -- referenced table 86 | ON fk.referenced_object_id = rt.[object_id] 87 | INNER JOIN sys.schemas AS rs 88 | ON rt.[schema_id] = rs.[schema_id] 89 | INNER JOIN sys.tables AS ct -- constraint table 90 | ON fk.parent_object_id = ct.[object_id] 91 | INNER JOIN sys.schemas AS cs 92 | ON ct.[schema_id] = cs.[schema_id] 93 | WHERE rt.is_ms_shipped = 0 AND ct.is_ms_shipped = 0 94 | AND (ct.name = 'triggers' or rt.name = 'triggers') 95 | -------------------------------------------------------------------------------- /SSMS Project/Query - Identify failed queries XE.sql: -------------------------------------------------------------------------------- 1 | -- Source: https://www.sqlservercentral.com/blogs/identifying-failed-queries-with-extended-events 2 | -- See also: https://straightforwardsql.com/posts/investigating-errors-with-extended-events/ 3 | --- Create Xevent 4 | ------ Be sure to change the filename and metadatafile 5 | CREATE EVENT SESSION [FailedQueries] ON SERVER 6 | ADD EVENT sqlserver.error_reported 7 | (ACTION(sqlserver.client_app_name, sqlserver.client_hostname, 8 | sqlserver.database_name, sqlserver.sql_text, sqlserver.username) 9 | WHERE ([package0].[greater_than_int64]([severity], (10)))) 10 | ADD TARGET package0.event_file (SET 11 | filename = N'C:\SQLServer\XEvents\FailedQueries.xel' 12 | ,metadatafile = N'C:\SQLServer\XEvents\FailedQueries.xem' 13 | ,max_file_size = (5) 14 | ,max_rollover_files = (10)) 15 | WITH (STARTUP_STATE = OFF) -- Change to ON if you want this to start when SQL starts. 16 | GO 17 | --- Start Xevent 18 | ALTER EVENT SESSION [FailedQueries] ON SERVER 19 | STATE = START; 20 | GO 21 | --- Stop Xevent 22 | ALTER EVENT SESSION [FailedQueries] ON SERVER 23 | STATE = STOP; 24 | GO 25 | ----------------------------------------- 26 | -- Read data 27 | ------ Be sure to change the filename 28 | SELECT 29 | [XML Data], 30 | [XML Data].value('(/event[@name=''error_reported'']/@timestamp)[1]','DATETIME')AS [Timestamp], 31 | [XML Data].value('(/event/action[@name=''database_name'']/value)[1]','varchar(max)')AS [Database], 32 | [XML Data].value('(/event/data[@name=''message'']/value)[1]','varchar(max)')AS [Message], 33 | [XML Data].value('(/event/action[@name=''sql_text'']/value)[1]','varchar(max)')AS [Statement] 34 | FROM 35 | (SELECT 36 | OBJECT_NAME AS [Event], 37 | CONVERT(XML, event_data) AS [XML Data] 38 | FROM sys.fn_xe_file_target_read_file 39 | ('C:\SQLServer\XEvents\FailedQueries*.xel',NULL,NULL,NULL) 40 | ) as FailedQueries; 41 | GO 42 | -------------------------------------------------------------------------------- /SSMS Project/Query - Index Update Stats.sql: -------------------------------------------------------------------------------- 1 | -- http://www.sqlskills.com/blogs/erin/new-statistics-dmf-in-sql-server-2008r2-sp2/ 2 | 3 | SELECT 4 | sch.name + '.' + so.name AS 'Table', 5 | ss.name AS 'Statistic', 6 | CASE 7 | WHEN ss.auto_Created = 0 AND ss.user_created = 0 THEN 'Index Statistic' 8 | WHEN ss.auto_created = 0 AND ss.user_created = 1 THEN 'User Created' 9 | WHEN ss.auto_created = 1 AND ss.user_created = 0 THEN 'Auto Created' 10 | WHEN ss.AUTO_created = 1 AND ss.user_created = 1 THEN 'Not Possible?' 11 | END AS 'Statistic Type', 12 | CASE 13 | WHEN ss.has_filter = 1 THEN 'Filtered Index' 14 | WHEN ss.has_filter = 0 THEN 'No Filter' 15 | END AS 'Filtered?', 16 | CASE 17 | WHEN ss.filter_definition IS NULL THEN '' 18 | WHEN ss.filter_definition IS NOT NULL THEN ss.filter_definition 19 | END AS 'Filter Definition', 20 | sp.last_updated AS 'Stats Last Updated', 21 | sp.rows AS 'Rows', 22 | sp.rows_sampled AS 'Rows Sampled', 23 | sp.unfiltered_rows AS 'Unfiltered Rows', 24 | sp.modification_counter AS 'Row Modifications', 25 | sp.steps AS 'Histogram Steps' 26 | FROM sys.stats ss 27 | JOIN sys.objects so ON ss.object_id = so.object_id 28 | JOIN sys.schemas sch ON so.schema_id = sch.schema_id 29 | OUTER APPLY sys.dm_db_stats_properties(so.object_id, ss.stats_id) AS sp 30 | WHERE so.TYPE = 'U' 31 | AND sp.last_updated < getdate() - 30 32 | ORDER BY sp.last_updated 33 | DESC; -------------------------------------------------------------------------------- /SSMS Project/Query - Lead Blocker.sql: -------------------------------------------------------------------------------- 1 | WITH Blocked_Sessions AS ( 2 | -- Collect lead blockers 3 | -- Pull all blocking IDs & check which ones are not being blocked themselves 4 | SELECT sys.dm_exec_requests.blocking_session_id AS lead_session_id, 5 | sys.dm_exec_requests.blocking_session_id AS blocking_session_id , 0 Cnt 6 | FROM sys.dm_exec_requests 7 | WHERE blocking_session_id <> 0 8 | AND blocking_session_id NOT IN (SELECT session_id FROM sys.dm_exec_requests 9 | WHERE sys.dm_exec_requests.blocking_session_id <> 0) 10 | UNION ALL 11 | -- Recurse through list of blocked sessions 12 | SELECT Blocked_Sessions.lead_session_id, sys.dm_exec_requests.session_id, 1 Cnt 13 | FROM sys.dm_exec_requests 14 | JOIN Blocked_Sessions 15 | ON Blocked_Sessions.blocking_session_id = sys.dm_exec_requests.blocking_session_id 16 | ), 17 | Blocked AS ( 18 | -- Add up all sessions blocked for the lead blocker 19 | SELECT lead_session_id, SUM(cnt) AS sessions_blocked 20 | FROM Blocked_Sessions 21 | GROUP BY lead_session_id ) 22 | SELECT Blocked.*, DATEDIFF(s, Sess.last_request_start_time, getdate()) seconds_blocking, 23 | ISNULL(Req.status,'sleeping') [status], SqlText.text [sql_text], 24 | STUFF((SELECT DISTINCT ISNULL(', ' + db.name,'') 25 | FROM sys.databases db 26 | JOIN sys.dm_tran_locks lcks 27 | ON db.database_id = lcks.resource_database_id 28 | WHERE lcks.request_session_id = Sess.session_id 29 | ORDER BY ISNULL(', ' + db.name,'') 30 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)') 31 | ,1,2,'') AS database_list 32 | , Conn.client_net_address, Sess.login_name 33 | FROM sys.dm_exec_connections Conn 34 | LEFT OUTER JOIN sys.dm_exec_sessions Sess 35 | ON Conn.session_id = Sess.session_id 36 | JOIN Blocked 37 | ON Blocked.lead_session_id = Sess.session_id 38 | CROSS APPLY sys.dm_exec_sql_text(Conn.most_recent_sql_handle) SqlText 39 | LEFT JOIN sys.dm_exec_requests Req 40 | ON Req.session_id = Sess.session_id 41 | WHERE Blocked.sessions_blocked >= 1 42 | AND DATEDIFF(s, Sess.last_request_start_time, getdate()) > 30 43 | -------------------------------------------------------------------------------- /SSMS Project/Query - Memory Info.sql: -------------------------------------------------------------------------------- 1 | select * from sys.dm_os_sys_info 2 | select * from sys.dm_os_sys_memory 3 | 4 | --From the checked answer here: 5 | --https://social.msdn.microsoft.com/Forums/sqlserver/en-US/60195ce5-0d60-45d3-97c0-012f2afd59d4/how-much-memory-sql-server-is-actually-using?forum=sqldatabaseengine 6 | select 7 | (physical_memory_in_use_kb/1024) AS Memory_usedby_Sqlserver_MB, 8 | (locked_page_allocations_kb/1024) AS Locked_pages_used_Sqlserver_MB, 9 | (total_virtual_address_space_kb/1024) AS Total_VAS_in_MB, 10 | process_physical_memory_low, 11 | process_virtual_memory_low 12 | from sys.dm_os_process_memory 13 | 14 | 15 | -- Steve Hood 16 | -- https://wordpress.com/read/post/feed/10898398/897024187 17 | 18 | IF OBJECT_ID('TempDB..#BufferSummary') IS NOT NULL BEGIN 19 | DROP TABLE #BufferSummary 20 | END 21 | 22 | IF OBJECT_ID('TempDB..#BufferPool') IS NOT NULL BEGIN 23 | DROP TABLE #BufferPool 24 | END 25 | 26 | CREATE TABLE #BufferPool 27 | ( 28 | Cached_MB Int 29 | , Database_Name SysName 30 | , Schema_Name SysName NULL 31 | , Object_Name SysName NULL 32 | , Index_ID Int NULL 33 | , Index_Name SysName NULL 34 | , Used_MB Int NULL 35 | , Used_InRow_MB Int NULL 36 | , Row_Count BigInt NULL 37 | ) 38 | 39 | SELECT Pages = COUNT(1) 40 | , allocation_unit_id 41 | , database_id 42 | INTO #BufferSummary 43 | FROM sys.dm_os_buffer_descriptors 44 | GROUP BY allocation_unit_id, database_id 45 | 46 | DECLARE @DateAdded SmallDateTime 47 | SELECT @DateAdded = GETDATE() 48 | 49 | DECLARE @SQL NVarChar(4000) 50 | SELECT @SQL = ' USE [?] 51 | INSERT INTO #BufferPool ( 52 | Cached_MB 53 | , Database_Name 54 | , Schema_Name 55 | , Object_Name 56 | , Index_ID 57 | , Index_Name 58 | , Used_MB 59 | , Used_InRow_MB 60 | , Row_Count 61 | ) 62 | SELECT sum(bd.Pages)/128 63 | , DB_Name(bd.database_id) 64 | , Schema_Name(o.schema_id) 65 | , o.name 66 | , p.index_id 67 | , ix.Name 68 | , i.Used_MB 69 | , i.Used_InRow_MB 70 | , i.Row_Count 71 | FROM #BufferSummary AS bd 72 | LEFT JOIN sys.allocation_units au ON bd.allocation_unit_id = au.allocation_unit_id 73 | LEFT JOIN sys.partitions p ON (au.container_id = p.hobt_id AND au.type in (1,3)) OR (au.container_id = p.partition_id and au.type = 2) 74 | LEFT JOIN ( 75 | SELECT PS.object_id 76 | , PS.index_id 77 | , Used_MB = SUM(PS.used_page_count) / 128 78 | , Used_InRow_MB = SUM(PS.in_row_used_page_count) / 128 79 | , Used_LOB_MB = SUM(PS.lob_used_page_count) / 128 80 | , Reserved_MB = SUM(PS.reserved_page_count) / 128 81 | , row_count = SUM(row_count) 82 | FROM sys.dm_db_partition_stats PS 83 | GROUP BY PS.object_id 84 | , PS.index_id 85 | ) i ON p.object_id = i.object_id AND p.index_id = i.index_id 86 | LEFT JOIN sys.indexes ix ON i.object_id = ix.object_id AND i.index_id = ix.index_id 87 | LEFT JOIN sys.objects o ON p.object_id = o.object_id 88 | WHERE database_id = db_id() 89 | GROUP BY bd.database_id 90 | , o.schema_id 91 | , o.name 92 | , p.index_id 93 | , ix.Name 94 | , i.Used_MB 95 | , i.Used_InRow_MB 96 | , i.Row_Count 97 | HAVING SUM(bd.pages) > 128 98 | ORDER BY 1 DESC;' 99 | 100 | EXEC sp_MSforeachdb @SQL 101 | 102 | SELECT Cached_MB 103 | , Pct_of_Cache = CAST(Cached_MB * 100.0 / SUM(Cached_MB) OVER () as Dec(20,3)) 104 | , Pct_Index_in_Cache = CAST(Cached_MB * 100.0 / CASE Used_MB WHEN 0 THEN 0.001 ELSE Used_MB END as DEC(20,3)) 105 | , Database_Name 106 | , Schema_Name 107 | , Object_Name 108 | , Index_ID 109 | , Index_Name 110 | , Used_MB 111 | , Used_InRow_MB 112 | , Row_Count 113 | FROM #BufferPool 114 | ORDER BY Database_Name, Cached_MB DESC -------------------------------------------------------------------------------- /SSMS Project/Query - MissingIndexByQuery.sql: -------------------------------------------------------------------------------- 1 | --http://sqlstudies.com/2013/11/11/a-better-way-to-find-missing-indexes/ 2 | 3 | WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' 4 | AS sp) 5 | 6 | SELECT DB_NAME(CAST(pa.value AS INT)) QueryDatabase 7 | ,s.sql_handle 8 | ,OBJECT_SCHEMA_NAME(st.objectid, CAST(pa.value AS INT)) AS ObjectSchemaName 9 | ,OBJECT_NAME(st.objectid, CAST(pa.value AS INT)) AS ObjectName 10 | ,SUBSTRING(st.text,s.statement_start_offset/2+1, 11 | ((CASE WHEN s.statement_end_offset = -1 THEN DATALENGTH(st.text) 12 | ELSE s.statement_end_offset END) - s.statement_start_offset)/2 + 1) AS SqlText 13 | ,s.total_elapsed_time 14 | ,s.last_execution_time 15 | ,s.execution_count 16 | ,s.total_logical_writes 17 | ,s.total_logical_reads 18 | ,s.min_elapsed_time 19 | ,s.max_elapsed_time 20 | -- query_hash is useful for grouping similar queries with different parameters 21 | --,s.query_hash 22 | --,cast (p.query_plan as varchar(max)) query_plan 23 | ,p.query_plan 24 | ,mi.MissingIndex.value(N'(./@Database)[1]', 'NVARCHAR(256)') AS TableDatabase 25 | ,mi.MissingIndex.value(N'(./@Table)[1]', 'NVARCHAR(256)') AS TableName 26 | ,mi.MissingIndex.value(N'(./@Schema)[1]', 'NVARCHAR(256)') AS TableSchema 27 | ,mi.MissingIndex.value(N'(../@Impact)[1]', 'DECIMAL(6,4)') AS ProjectedImpact 28 | ,ic.IndexColumns 29 | ,inc.IncludedColumns 30 | FROM ( -- Uncomment the TOP & ORDER BY clauses to restrict the data and 31 | -- reduce the query run time. 32 | SELECT --TOP 200 33 | s.sql_handle 34 | ,s.plan_handle 35 | ,s.total_elapsed_time 36 | ,s.last_execution_time 37 | ,s.execution_count 38 | ,s.total_logical_writes 39 | ,s.total_logical_reads 40 | ,s.min_elapsed_time 41 | ,s.max_elapsed_time 42 | ,s.statement_start_offset 43 | ,s.statement_end_offset 44 | --,s.query_hash 45 | FROM sys.dm_exec_query_stats s 46 | -- ORDER BY s.total_elapsed_time DESC 47 | ) AS s 48 | CROSS APPLY sys.dm_exec_text_query_plan(s.plan_handle,statement_start_offset,statement_end_offset) AS pp 49 | CROSS APPLY (SELECT CAST(pp.query_plan AS XML) AS query_plan ) AS p 50 | CROSS APPLY p.query_plan.nodes('/sp:ShowPlanXML/sp:BatchSequence/sp:Batch/sp:Statements/sp:StmtSimple/sp:QueryPlan/sp:MissingIndexes/sp:MissingIndexGroup/sp:MissingIndex') 51 | AS mi (MissingIndex) 52 | CROSS APPLY (SELECT STUFF((SELECT ', ' + ColumnGroupColumn.value('./@Name', 'NVARCHAR(256)') 53 | FROM mi.MissingIndex.nodes('./sp:ColumnGroup') 54 | AS t1 (ColumnGroup) 55 | CROSS APPLY t1.ColumnGroup.nodes('./sp:Column') AS t2 (ColumnGroupColumn) 56 | WHERE t1.ColumnGroup.value('./@Usage', 'NVARCHAR(256)') <> 'INCLUDE' 57 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)'), 1, 2, '') AS IndexColumns ) AS ic 58 | CROSS APPLY (SELECT STUFF((SELECT ', ' + ColumnGroupColumn.value('./@Name', 'NVARCHAR(256)') 59 | FROM mi.MissingIndex.nodes('./sp:ColumnGroup') 60 | AS t1 (ColumnGroup) 61 | CROSS APPLY t1.ColumnGroup.nodes('./sp:Column') AS t2 (ColumnGroupColumn) 62 | WHERE t1.ColumnGroup.value('./@Usage', 'NVARCHAR(256)') = 'INCLUDE' 63 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)'), 1, 2, '') AS IncludedColumns ) AS inc 64 | CROSS APPLY sys.dm_exec_plan_attributes(s.plan_handle) pa 65 | CROSS APPLY sys.dm_exec_sql_text (s.sql_handle) st 66 | WHERE pp.query_plan LIKE '%MissingIndexes%' 67 | AND pa.attribute = 'dbid' -------------------------------------------------------------------------------- /SSMS Project/Query - Performance.sql: -------------------------------------------------------------------------------- 1 | /* 2 | --- Procedure stats 3 | -- View the statistics at the SP level 4 | SELECT db_name(database_id), object_name(object_id,database_id), * 5 | FROM sys.dm_exec_procedure_stats ps 6 | OUTER APPLY sys.dm_exec_query_plan (ps.plan_handle) 7 | WHERE object_name(object_id,database_id) LIKE '%spName1%' 8 | ORDER BY total_elapsed_time/execution_count DESC 9 | */ 10 | --- Query stats 11 | -- View the stats for all queries. 12 | -- WHERE clause to pick out a specific SP or DB. 13 | SELECT TOP 1000 14 | DB_NAME(st.dbid) AS DB_Name, 15 | ISNULL(object_name(qp.objectid, qp.dbid),'*** Ad-Hoc ***') AS SPName, qs.*, 16 | CAST(qp.query_plan AS XML) AS XML_Plan, 17 | SUBSTRING(st.text,qs.statement_start_offset/2+1, 18 | ((CASE WHEN qs.statement_end_offset = -1 THEN DATALENGTH(st.text) 19 | ELSE qs.statement_end_offset END) - qs.statement_start_offset)/2 + 1) AS SqlText, 20 | st.text AS FullQuery 21 | FROM sys.dm_exec_query_stats qs 22 | OUTER APPLY sys.dm_exec_sql_text(qs.sql_handle) st 23 | OUTER APPLY sys.dm_exec_text_query_plan(qs.plan_handle, 24 | qs.statement_start_offset, qs.statement_end_offset) qp 25 | --WHERE st.dbid = DB_ID('TRSIOS') 26 | WHERE object_name(st.objectid, st.dbid) LIKE '%spName1%' 27 | -- OR object_name(st.objectid, st.dbid) LIKE '%spName2%' 28 | --ORDER BY total_elapsed_time/execution_count DESC 29 | ORDER BY total_elapsed_time DESC 30 | --ORDER BY max_grant_kb DESC 31 | -------------------------------------------------------------------------------- /SSMS Project/Query - SearchTheLog.sql: -------------------------------------------------------------------------------- 1 | IF OBJECT_ID('tempdb.dbo.#LogInfo') IS NOT NULL 2 | DROP TABLE #LogInfo; 3 | 4 | 5 | DECLARE @searchstring1 nvarchar(500) = ''; 6 | DECLARE @searchstring2 nvarchar(500) = ''; 7 | DECLARE @Limit int = 99; 8 | 9 | ---------------------------------------------------------------------- 10 | -- This part of the code was found here: 11 | -- https://ask.sqlservercentral.com/questions/99484/number-of-error-log-files.html 12 | 13 | DECLARE @FileList AS TABLE ( 14 | subdirectory NVARCHAR(4000) NOT NULL 15 | ,DEPTH BIGINT NOT NULL 16 | ,[FILE] BIGINT NOT NULL 17 | ); 18 | 19 | DECLARE @ErrorLog NVARCHAR(4000), @ErrorLogPath NVARCHAR(4000); 20 | SELECT @ErrorLog = CAST(SERVERPROPERTY(N'errorlogfilename') AS NVARCHAR(4000)); 21 | SELECT @ErrorLogPath = SUBSTRING(@ErrorLog, 1, LEN(@ErrorLog) - CHARINDEX(N'\', REVERSE(@ErrorLog))) + N'\'; 22 | 23 | 24 | INSERT INTO @FileList 25 | EXEC xp_dirtree @ErrorLogPath, 0, 1; 26 | 27 | DECLARE @NumberOfLogfiles INT; 28 | SET @NumberOfLogfiles = (SELECT COUNT(*) FROM @FileList WHERE [@FileList].subdirectory LIKE N'ERRORLOG%'); 29 | -- SELECT @NumberOfLogfiles; 30 | If @Limit IS NOT NULL AND @NumberOfLogfiles > @Limit 31 | SET @NumberOfLogfiles = @Limit 32 | ---------------------------------------------------------------------- 33 | 34 | CREATE TABLE #LogInfo ( 35 | LogDate datetime, 36 | ProcessInfo nvarchar(500), 37 | ErrorText nvarchar(max)) 38 | 39 | DECLARE @p1 INT = 0 40 | 41 | WHILE @p1 < @NumberOfLogfiles 42 | BEGIN 43 | -- P1 is the file number starting at 0 44 | DECLARE 45 | @p2 INT = 1, 46 | -- P2 1 for SQL logs, 2 for SQL Agent logs 47 | @p3 NVARCHAR(255) = @searchstring1, 48 | -- P3 is a value to search on 49 | @p4 NVARCHAR(255) = @searchstring2 50 | -- P4 is another search value 51 | 52 | BEGIN TRY 53 | INSERT INTO #LogInfo 54 | EXEC sys.xp_readerrorlog @p1,@p2,@p3,@p4 55 | END TRY 56 | BEGIN CATCH 57 | PRINT 'Error occurred processing file ' + cast(@p1 as varchar(10)) 58 | END CATCH 59 | 60 | SET @p1 = @p1 + 1 61 | END 62 | 63 | SELECT * FROM #LogInfo 64 | WHERE ProcessInfo NOT IN ('Backup') 65 | -- and errortext not like '%succeeded%' 66 | and errortext like '%%' 67 | -- and errortext <> 'Error: 18456, Severity: 14, State: 78.' 68 | -- and logdate between '2022-01-12 17:00' and '2022-01-12 17:30' 69 | ORDER BY LogDate DESC 70 | 71 | /* 72 | ---------------------------------------------------------------------------- 73 | ---- Last login success/failure for each id. 74 | SELECT UserList.UserName, 75 | MAX(CASE WHEN #LogInfo.ErrorText LIKE '%succeeded%' THEN LogDate ELSE NULL END) AS LatestSuccess, 76 | MAX(CASE WHEN #LogInfo.ErrorText LIKE '%failed%' THEN LogDate ELSE NULL END) AS LatestFailure 77 | INTO #Logins 78 | FROM #LogInfo 79 | CROSS APPLY (SELECT REPLACE(REPLACE(ErrorText,'Login succeeded for user ''',''),'Login failed for user ''','')) RemoveFront(ErrorText) 80 | CROSS APPLY (SELECT SUBSTRING(RemoveFront.ErrorText,1,CHARINDEX('''', RemoveFront.ErrorText)-1)) AS UserList(UserName) 81 | WHERE #LogInfo.ProcessInfo = 'Logon' 82 | and #LogInfo.ErrorText like 'Login%' 83 | and #LogInfo.ErrorText NOT LIKE '%untrusted domain%' 84 | GROUP BY UserList.UserName; 85 | 86 | ---------------------------------------------------------------------------- 87 | -- Connections by username, host 88 | SELECT UserList.UserName, UserList.Host, COUNT(1) 89 | FROM #LogInfo 90 | CROSS APPLY (SELECT REPLACE(REPLACE(ErrorText,'Login succeeded for user ''',''),'Login failed for user ''','')) RemoveFront(ErrorText) 91 | CROSS APPLY (SELECT SUBSTRING(RemoveFront.ErrorText,1,CHARINDEX('''', RemoveFront.ErrorText)-1), 92 | REPLACE(substring(#LogInfo.ErrorText,patindex('%CLIENT:%',#LogInfo.ErrorText)+8,50),']','')) AS UserList(UserName, Host) 93 | WHERE #LogInfo.ProcessInfo = 'Logon' 94 | and #LogInfo.ErrorText like 'Login%' 95 | --and LogDate < '3/1/2021' 96 | and #LogInfo.ErrorText LIKE '%succeeded%' 97 | and #LogInfo.errortext like '%SPTLATRSDOTCOM%' 98 | GROUP BY UserList.UserName, UserList.Host 99 | ORDER BY 1,2 100 | */ 101 | /* 102 | -- Unlock a user 103 | IF LOGINPROPERTY('SQLID','islocked') = 1 104 | BEGIN 105 | ALTER LOGIN SQLID WITH CHECK_POLICY=OFF; 106 | ALTER LOGIN SQLID WITH CHECK_POLICY=ON; 107 | END 108 | */ 109 | 110 | --select * from #logins 111 | --where username in (select name from TRS_BI_Pre_Staging.sys.database_principals) 112 | 113 | -------------------------------------------------------------------------------- /SSMS Project/Query - ShredTheDeadlockGraph.sql: -------------------------------------------------------------------------------- 1 | -- http://blog.waynesheffield.com/wayne/code-library/deadlocks/shred-deadlock-graph/ 2 | 3 | -- REFERENCES: 4 | -- see http://msdn.microsoft.com/en-us/library/ms188246.aspx 5 | -- (MS BOL Analyzing Deadlocks with SQL Server Profiler) 6 | -- see http://msdn.microsoft.com/en-us/library/ms175519.aspx 7 | -- (MS BOL Lock Modes) 8 | -- http://blogs.msdn.com/bartd/archive/2006/09/09/Deadlock-Troubleshooting_2C00_-Part-1.aspx 9 | -- http://blogs.msdn.com/b/bartd/archive/2008/09/24/today-s-annoyingly-unwieldy-term-intra-query-parallel-thread-deadlocks.aspx 10 | -- Shred XML Deadlock Graphs, showing in tabular format as much information as possible. 11 | -- Insert the XML Deadlock Graph into the @deadlock table. 12 | -- Author: Wayne Sheffield 13 | -- Modification History: 14 | -- Version - Date - Description 15 | -- 2 2010-10-10 - Added individual items in the Execution Stack node. 16 | -- - Converted from using an XML variable to a table variable with an XML variable 17 | -- - to allow seeing multiple deadlocks simultaneously. 18 | -- 3 2010-10-11 - Added KPID to Process CTE and final results. 19 | -- - Expanded LockMode to varchar(10). 20 | -- 4 2011-05-11 - Added Waits. 21 | -- 5 2011-05-15 - Revamped to minimize calls to the root of the deadlock xml nodes. 22 | -- Modified InputBuffer to be XML. 23 | -- Modified Execution Stack to return XML (vs. one row for each item, which 24 | -- was causing duplication of other data). 25 | -- 6 2012-02-01 - Add loading deadlock info from fn_trace_gettable. 26 | -- - Get the InputBuffer from .query vs. trying to build XML. 27 | -- - Add number of processes involved in the deadlock. 28 | -- - Add the Query Statement being run. 29 | -- 7 2012-09-01 - Corrected typo in ObjNode in both the Locks and Waits CTEs. 30 | -- - Added DENSE_RANK for each process. 31 | -- - Added support for exchangeEvent, threadpool, resourceWait events. 32 | -- - (threadpool and resourceWait events are not tested - need to find a deadlock with them to test) 33 | -- - Simplified xpath queries 34 | -- 8 2012-09-04 - Greatly simplified locks and waits CTEs based on feedback from Mark Cowne. 35 | -- - Added database_id and AssociatedObjectId per feedback from Gianluca Sartori. 36 | -- - Combined the Locks and Waits CTEs into one. 37 | -- 9 2012-10-26 - Handle deadlock graphs from the system_health xe (has a victim-list node for multi-victim deadlocks). 38 | -- 10 2013-07-29 - Added ability to load in a deadlock file (.xdl). 39 | -- - Added QueryStatement to output. 40 | -- - Switched from clause order from "Locks JOIN Process" to "Process LEFT JOIN Locks" 41 | -- 11 2013-12-26 - Read in deadlocks from the system_health XE file target 42 | -- 12 2014-05-06 - Read in deadlocks from the system_health XE ring buffer 43 | -- 13 2014-07-01 - Read in deadlocks from SQL Sentry 44 | 45 | DECLARE @deadlock TABLE ( 46 | DeadlockID INT IDENTITY PRIMARY KEY CLUSTERED, 47 | DeadlockGraph XML 48 | ); 49 | -- use below to load a deadlock trace file 50 | /* 51 | DECLARE @file VARCHAR(500); 52 | SELECT @file = REVERSE(SUBSTRING(REVERSE([PATH]), CHARINDEX('\', REVERSE([path])), 260)) + N'LOG.trc' 53 | FROM sys.traces 54 | WHERE is_default = 1; -- get the system default trace, use different # for other active traces. 55 | 56 | -- or just SET @file = 'your trace file to load'; 57 | 58 | INSERT INTO @deadlock (DeadlockGraph) 59 | SELECT TextData 60 | FROM ::FN_TRACE_GETTABLE(@file, DEFAULT) 61 | WHERE TextData LIKE '%'; 62 | */ 63 | 64 | -- or read in a deadlock file - doesn't have to have a "xdl" extension. 65 | /* 66 | INSERT INTO @deadlock (DeadlockGraph) 67 | SELECT * 68 | FROM OPENROWSET(BULK 'Deadlock.xdl', SINGLE_BLOB) UselessAlias; 69 | */ 70 | 71 | 72 | -- or read in the deadlock from the system_health XE file target 73 | /* 74 | WITH cte1 AS 75 | ( 76 | SELECT target_data = convert(XML, target_data) 77 | FROM sys.dm_xe_session_targets t 78 | JOIN sys.dm_xe_sessions s 79 | ON t.event_session_address = s.address 80 | WHERE t.target_name = 'event_file' 81 | AND s.name = 'system_health' 82 | ), cte2 AS 83 | ( 84 | SELECT [FileName] = FileEvent.FileTarget.value('@name', 'varchar(1000)') 85 | FROM cte1 86 | CROSS APPLY cte1.target_data.nodes('//EventFileTarget/File') FileEvent(FileTarget) 87 | ), cte3 AS 88 | ( 89 | SELECT event_data = CONVERT(XML, t2.event_data) 90 | FROM cte2 91 | CROSS APPLY sys.fn_xe_file_target_read_file(cte2.[FileName], NULL, NULL, NULL) t2 92 | WHERE t2.object_name = 'xml_deadlock_report' 93 | ) 94 | INSERT INTO @deadlock(DeadlockGraph) 95 | SELECT Deadlock = Deadlock.Report.query('.') 96 | FROM cte3 97 | CROSS APPLY cte3.event_data.nodes('//event/data/value/deadlock') Deadlock(Report); 98 | */ 99 | 100 | -- or read in the deadlock from the system_health XE ring buffer 101 | INSERT INTO @deadlock(DeadlockGraph) 102 | SELECT --XEventData.XEvent.value('@timestamp', 'datetime') AS DeadlockDateTime, 103 | CONVERT(XML, XEventData.XEvent.value('(data/value)[1]', 'varchar(max)')) AS DeadlockGraph 104 | FROM (SELECT CAST(target_data AS XML) AS TargetData 105 | FROM sys.dm_xe_session_targets st WITH (NOLOCK) 106 | JOIN sys.dm_xe_sessions s WITH (NOLOCK) 107 | ON s.address = st.event_session_address 108 | WHERE name = 'system_health' 109 | ) AS Data 110 | CROSS APPLY TargetData.nodes('//RingBufferTarget/event') AS XEventData (XEvent) 111 | WHERE XEventData.XEvent.value('@name', 'varchar(4000)') = 'xml_deadlock_report'; 112 | 113 | /* 114 | -- or read in the deadlock from SQL Sentry deadlock collection 115 | INSERT INTO @deadlock(DeadlockGraph) 116 | SELECT deadlockxml 117 | FROM dbo.PerformanceAnalysisTraceDeadlock 118 | */ 119 | 120 | -- use below to load individual deadlocks. 121 | -- INSERT INTO @deadlock VALUES ('Put your deadlock here'); 122 | -- Insert the deadlock XML in the above line! 123 | -- Duplicate as necessary for additional graphs. 124 | 125 | WITH CTE AS 126 | ( 127 | SELECT DeadlockID, 128 | DeadlockGraph 129 | FROM @deadlock 130 | ), Victims AS 131 | ( 132 | SELECT ID = Victims.List.value('@id', 'varchar(50)') 133 | FROM CTE 134 | CROSS APPLY CTE.DeadlockGraph.nodes('//deadlock/victim-list/victimProcess') AS Victims (List) 135 | ), Locks AS 136 | ( 137 | -- Merge all of the lock information together. 138 | SELECT CTE.DeadlockID, 139 | MainLock.Process.value('@id', 'varchar(100)') AS LockID, 140 | OwnerList.Owner.value('@id', 'varchar(200)') AS LockProcessId, 141 | REPLACE(MainLock.Process.value('local-name(.)', 'varchar(100)'), 'lock', '') AS LockEvent, 142 | MainLock.Process.value('@objectname', 'sysname') AS ObjectName, 143 | OwnerList.Owner.value('@mode', 'varchar(10)') AS LockMode, 144 | MainLock.Process.value('@dbid', 'INTEGER') AS Database_id, 145 | MainLock.Process.value('@associatedObjectId', 'BIGINT') AS AssociatedObjectId, 146 | MainLock.Process.value('@WaitType', 'varchar(100)') AS WaitType, 147 | WaiterList.Owner.value('@id', 'varchar(200)') AS WaitProcessId, 148 | WaiterList.Owner.value('@mode', 'varchar(10)') AS WaitMode 149 | FROM CTE 150 | CROSS APPLY CTE.DeadlockGraph.nodes('//deadlock/resource-list') AS Lock (list) 151 | CROSS APPLY Lock.list.nodes('*') AS MainLock (Process) 152 | OUTER APPLY MainLock.Process.nodes('owner-list/owner') AS OwnerList (Owner) 153 | CROSS APPLY MainLock.Process.nodes('waiter-list/waiter') AS WaiterList (Owner) 154 | ), Process AS 155 | ( 156 | -- get the data from the process node 157 | SELECT CTE.DeadlockID, 158 | [Victim] = CONVERT(BIT, CASE WHEN Deadlock.Process.value('@id', 'varchar(50)') = ISNULL(Deadlock.Process.value('../../@victim', 'varchar(50)'), v.ID) 159 | THEN 1 160 | ELSE 0 161 | END), 162 | [LockMode] = Deadlock.Process.value('@lockMode', 'varchar(10)'), -- how is this different from in the resource-list section? 163 | [ProcessID] = Process.ID, --Deadlock.Process.value('@id', 'varchar(50)'), 164 | [KPID] = Deadlock.Process.value('@kpid', 'int'), -- kernel-process id / thread ID number 165 | [SPID] = Deadlock.Process.value('@spid', 'int'), -- system process id (connection to sql) 166 | [SBID] = Deadlock.Process.value('@sbid', 'int'), -- system batch id / request_id (a query that a SPID is running) 167 | [ECID] = Deadlock.Process.value('@ecid', 'int'), -- execution context ID (a worker thread running part of a query) 168 | [IsolationLevel] = Deadlock.Process.value('@isolationlevel', 'varchar(200)'), 169 | [WaitResource] = Deadlock.Process.value('@waitresource', 'varchar(200)'), 170 | [LogUsed] = Deadlock.Process.value('@logused', 'int'), 171 | [ClientApp] = Deadlock.Process.value('@clientapp', 'varchar(100)'), 172 | [HostName] = Deadlock.Process.value('@hostname', 'varchar(20)'), 173 | [LoginName] = Deadlock.Process.value('@loginname', 'varchar(20)'), 174 | [TransactionTime] = Deadlock.Process.value('@lasttranstarted', 'datetime'), 175 | [BatchStarted] = Deadlock.Process.value('@lastbatchstarted', 'datetime'), 176 | [BatchCompleted] = Deadlock.Process.value('@lastbatchcompleted', 'datetime'), 177 | [InputBuffer] = Input.Buffer.query('.'), 178 | CTE.[DeadlockGraph], 179 | es.ExecutionStack, 180 | [SQLHandle] = ExecStack.Stack.value('@sqlhandle', 'varchar(64)'), 181 | [QueryStatement] = NULLIF(ExecStack.Stack.value('.', 'varchar(max)'), ''), 182 | --[QueryStatement] = Execution.Frame.value('.', 'varchar(max)'), 183 | [ProcessQty] = SUM(1) OVER (PARTITION BY CTE.DeadlockID), 184 | [TranCount] = Deadlock.Process.value('@trancount', 'int') 185 | FROM CTE 186 | CROSS APPLY CTE.DeadlockGraph.nodes('//deadlock/process-list/process') AS Deadlock (Process) 187 | CROSS APPLY (SELECT Deadlock.Process.value('@id', 'varchar(50)') ) AS Process (ID) 188 | LEFT JOIN Victims v ON Process.ID = v.ID 189 | CROSS APPLY Deadlock.Process.nodes('inputbuf') AS Input (Buffer) 190 | CROSS APPLY Deadlock.Process.nodes('executionStack') AS Execution (Frame) 191 | -- get the data from the executionStack node as XML 192 | CROSS APPLY (SELECT ExecutionStack = (SELECT ProcNumber = ROW_NUMBER() 193 | OVER (PARTITION BY CTE.DeadlockID, 194 | Deadlock.Process.value('@id', 'varchar(50)'), 195 | Execution.Stack.value('@procname', 'sysname'), 196 | Execution.Stack.value('@code', 'varchar(MAX)') 197 | ORDER BY (SELECT 1)), 198 | ProcName = Execution.Stack.value('@procname', 'sysname'), 199 | Line = Execution.Stack.value('@line', 'int'), 200 | SQLHandle = Execution.Stack.value('@sqlhandle', 'varchar(64)'), 201 | Code = LTRIM(RTRIM(Execution.Stack.value('.', 'varchar(MAX)'))) 202 | FROM Execution.Frame.nodes('frame') AS Execution (Stack) 203 | ORDER BY ProcNumber 204 | FOR XML PATH('frame'), ROOT('executionStack'), TYPE ) 205 | ) es 206 | CROSS APPLY Execution.Frame.nodes('frame') AS ExecStack (Stack) 207 | ) 208 | -- get the columns in the desired order 209 | --SELECT * FROM Locks 210 | 211 | SELECT p.DeadlockID, 212 | p.Victim, 213 | p.ProcessQty, 214 | ProcessNbr = DENSE_RANK() 215 | OVER (PARTITION BY p.DeadlockId 216 | ORDER BY p.ProcessID), 217 | p.LockMode, 218 | LockedObject = NULLIF(l.ObjectName, ''), 219 | l.database_id, 220 | l.AssociatedObjectId, 221 | LockProcess = p.ProcessID, 222 | p.KPID, 223 | p.SPID, 224 | p.SBID, 225 | p.ECID, 226 | p.TranCount, 227 | l.LockEvent, 228 | LockedMode = l.LockMode, 229 | l.WaitProcessID, 230 | l.WaitMode, 231 | p.WaitResource, 232 | l.WaitType, 233 | p.IsolationLevel, 234 | p.LogUsed, 235 | p.ClientApp, 236 | p.HostName, 237 | p.LoginName, 238 | p.TransactionTime, 239 | p.BatchStarted, 240 | p.BatchCompleted, 241 | p.QueryStatement, 242 | p.SQLHandle, 243 | p.InputBuffer, 244 | p.DeadlockGraph, 245 | p.ExecutionStack 246 | FROM Process p 247 | LEFT JOIN Locks l 248 | --JOIN Process p 249 | ON p.DeadlockID = l.DeadlockID 250 | AND p.ProcessID = l.LockProcessID 251 | ORDER BY p.DeadlockId, 252 | p.Victim DESC, 253 | p.ProcessId; -------------------------------------------------------------------------------- /SSMS Project/Query - Statistics Info.sql: -------------------------------------------------------------------------------- 1 | -- Initial query taken from here: "https://blogs.msdn.microsoft.com/sql_server_team/persisting-statistics-sampling-rate/" then modified. 2 | 3 | SELECT o.name AS object_name, ss.stats_id, ss.name as stat_name, 4 | ss.filter_definition, shr.last_updated, 5 | shr.persisted_sample_percent, 6 | (shr.rows_sampled * 100)/shr.rows AS sample_percent, 7 | shr.rows, shr.rows_sampled, 8 | shr.steps, shr.unfiltered_rows, shr.modification_counter 9 | FROM sys.stats ss 10 | INNER JOIN sys.objects o 11 | ON o.object_id = ss.object_id 12 | CROSS APPLY sys.dm_db_stats_properties(ss.object_id, ss.stats_id) shr 13 | WHERE o.is_ms_shipped = 0 14 | ORDER BY o.name, ss.stats_id; 15 | -------------------------------------------------------------------------------- /SSMS Project/Query - Statistics properties.sql: -------------------------------------------------------------------------------- 1 | -- Gotten from here: https://dba.stackexchange.com/questions/154283/stats-date-is-null 2 | -- Answer by Nic. 3 | 4 | SELECT t.name , 5 | s.object_id , 6 | s.stats_id , 7 | c.name , 8 | sc.stats_column_id , 9 | s.name , 10 | sp.last_updated , 11 | p.rows as total_rows , 12 | sp.rows_sampled , 13 | sp.modification_counter , 14 | sp.steps , 15 | sp.rows 16 | FROM [sys].[stats] AS [s] 17 | INNER JOIN sys.stats_columns sc ON s.stats_id = sc.stats_id 18 | AND s.object_id = sc.object_id 19 | INNER JOIN sys.columns c ON c.object_id = sc.object_id 20 | AND c.column_id = sc.column_id 21 | INNER JOIN sys.tables t ON c.object_id = t.object_id 22 | INNER JOIN sys.partitions p ON c.object_id = p.object_id 23 | AND p.index_id IN (0,1) 24 | OUTER APPLY sys.dm_db_stats_properties([s].[object_id], 25 | [s].[stats_id]) AS [sp] 26 | WHERE t.name LIKE '%' 27 | --WHERE p.rows > 0 28 | ORDER BY sp.last_updated ASC 29 | 30 | --update statistics agOnlineHierarchy1 31 | -------------------------------------------------------------------------------- /SSMS Project/Query - TableSizes.sql: -------------------------------------------------------------------------------- 1 | -- SET NOEXEC ON 2 | -- SET NOEXEC OFF 3 | 4 | IF object_id('tempdb.dbo.#TableSizes') <> 0 5 | DROP TABLE #TableSizes 6 | GO 7 | CREATE TABLE #TableSizes ( 8 | DBName varchar(255), 9 | SchemaName varchar(255), 10 | TableName varchar(255), 11 | Rows int, 12 | TotalSpaceKB int, 13 | UsedSpaceKB int, 14 | UnusedSpaceKB int 15 | ) 16 | 17 | EXEC sp_msforeachdb 18 | 'USE [?] ; 19 | INSERT INTO #TableSizes 20 | SELECT 21 | db_name() AS DBName, 22 | s.Name AS SchemaName, 23 | t.NAME AS TableName, 24 | p.rows AS RowCounts, 25 | SUM(a.total_pages) * 8 AS TotalSpaceKB, 26 | SUM(a.used_pages) * 8 AS UsedSpaceKB, 27 | (SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB 28 | FROM sys.tables t 29 | INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id 30 | INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id 31 | INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id 32 | LEFT OUTER JOIN sys.schemas s ON t.schema_id = s.schema_id 33 | WHERE t.is_ms_shipped = 0 34 | AND i.OBJECT_ID > 255 35 | GROUP BY t.Name, s.Name, p.Rows 36 | ORDER BY t.Name;' 37 | 38 | SELECT * FROM #TableSizes 39 | WHERE DBName NOT IN ('tempdb','master','model','msdb'); 40 | -------------------------------------------------------------------------------- /SSMS Project/Query - Track index progress.sql: -------------------------------------------------------------------------------- 1 | -- From : https://dba.stackexchange.com/questions/139191/sql-server-how-to-track-progress-of-create-index-command 2 | 3 | DECLARE @SPID INT = 51; 4 | 5 | ;WITH agg AS 6 | ( 7 | SELECT SUM(qp.[row_count]) AS [RowsProcessed], 8 | SUM(qp.[estimate_row_count]) AS [TotalRows], 9 | MAX(qp.last_active_time) - MIN(qp.first_active_time) AS [ElapsedMS], 10 | MAX(IIF(qp.[close_time] = 0 AND qp.[first_row_time] > 0, 11 | [physical_operator_name], 12 | N'')) AS [CurrentStep] 13 | FROM sys.dm_exec_query_profiles qp 14 | WHERE qp.[physical_operator_name] IN (N'Table Scan', N'Clustered Index Scan', 15 | N'Index Scan', N'Sort') 16 | AND qp.[session_id] = @SPID 17 | ), comp AS 18 | ( 19 | SELECT *, 20 | ([TotalRows] - [RowsProcessed]) AS [RowsLeft], 21 | ([ElapsedMS] / 1000.0) AS [ElapsedSeconds] 22 | FROM agg 23 | ) 24 | SELECT [CurrentStep], 25 | [TotalRows], 26 | [RowsProcessed], 27 | [RowsLeft], 28 | CONVERT(DECIMAL(5, 2), 29 | (([RowsProcessed] * 1.0) / [TotalRows]) * 100) AS [PercentComplete], 30 | [ElapsedSeconds], 31 | (([ElapsedSeconds] / [RowsProcessed]) * [RowsLeft]) AS [EstimatedSecondsLeft], 32 | DATEADD(SECOND, 33 | (([ElapsedSeconds] / [RowsProcessed]) * [RowsLeft]), 34 | GETDATE()) AS [EstimatedCompletionTime] 35 | FROM comp; 36 | -------------------------------------------------------------------------------- /SSMS Project/Query - View SysAudit.sql: -------------------------------------------------------------------------------- 1 | DECLARE @AuFiPa nvarchar(256), @today nvarchar(15), @last24hrs datetime, @offset int 2 | 3 | SELECT @offset = DateDiff(hour, getutcdate(), getdate()) 4 | SELECT @last24hrs = dateadd(day,-21,getdate()) -- dateadd(hour,-24,getdate()) 5 | SELECT @today = convert(nvarchar(10),getdate(),102) 6 | SELECT @AuFiPa = audit_file_path FROM sys.dm_server_audit_status WHERE name='SysAudit' AND status=1 7 | 8 | SELECT convert(nvarchar(30),dateadd(hour,@offset,event_time),120) AS [Event_time], 9 | action_id, succeeded, session_server_principal_name, target_server_principal_name, 10 | server_instance_name, database_name, statement 11 | FROM sys.fn_get_audit_file(@AuFiPa, default, default) 12 | -- where action_id in ('LGIF') 13 | WHERE 1=1 14 | AND action_id NOT IN ('VSST', 'BA', 'BAL') --,'ALSS','BA') 15 | -- and dateadd(hour,@offset,event_time) > @today 16 | AND event_time > @last24hrs 17 | -- and event_time > @today 18 | -- and convert(nvarchar(10),event_time,102) = @today 19 | ORDER BY event_time DESC 20 | 21 | 22 | 23 | -------------------------------------------------------------------------------- /SSMS Project/Query - Wait Stats.sql: -------------------------------------------------------------------------------- 1 | -- http://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/ 2 | 3 | WITH [Waits] AS 4 | (SELECT 5 | [wait_type], 6 | [wait_time_ms] / 1000.0 AS [WaitS], 7 | ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS], 8 | [signal_wait_time_ms] / 1000.0 AS [SignalS], 9 | [waiting_tasks_count] AS [WaitCount], 10 | 100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage], 11 | ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum] 12 | FROM sys.dm_os_wait_stats 13 | WHERE [wait_type] NOT IN ( 14 | N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', 15 | N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', 16 | N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', 17 | N'CHKPT', N'CLR_AUTO_EVENT', 18 | N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', 19 | 20 | -- Maybe uncomment these four if you have mirroring issues 21 | N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', 22 | N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', 23 | 24 | N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', 25 | N'EXECSYNC', N'FSAGENT', 26 | N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', 27 | 28 | -- Maybe uncomment these six if you have AG issues 29 | N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 30 | N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', 31 | N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', 32 | 33 | N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', 34 | N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT', 35 | N'ONDEMAND_TASK_QUEUE', 36 | N'PREEMPTIVE_XE_GETTARGETSTATE', 37 | N'PWAIT_ALL_COMPONENTS_INITIALIZED', 38 | N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', 39 | N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_ASYNC_QUEUE', 40 | N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', 41 | N'QDS_SHUTDOWN_QUEUE', N'REDO_THREAD_PENDING_WORK', 42 | N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE', 43 | N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', 44 | N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', 45 | N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', 46 | N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', 47 | N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', 48 | N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', 49 | N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', 50 | N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 51 | N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS', 52 | N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', 53 | N'WAIT_XTP_RECOVERY', 54 | N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', 55 | N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN', 56 | N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT') 57 | AND [waiting_tasks_count] > 0 58 | ) 59 | SELECT 60 | MAX ([W1].[wait_type]) AS [WaitType], 61 | CAST (MAX ([W1].[WaitS]) AS DECIMAL (16,2)) AS [Wait_S], 62 | CAST (MAX ([W1].[ResourceS]) AS DECIMAL (16,2)) AS [Resource_S], 63 | CAST (MAX ([W1].[SignalS]) AS DECIMAL (16,2)) AS [Signal_S], 64 | MAX ([W1].[WaitCount]) AS [WaitCount], 65 | CAST (MAX ([W1].[Percentage]) AS DECIMAL (5,2)) AS [Percentage], 66 | CAST ((MAX ([W1].[WaitS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgWait_S], 67 | CAST ((MAX ([W1].[ResourceS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgRes_S], 68 | CAST ((MAX ([W1].[SignalS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgSig_S], 69 | CAST ('https://www.sqlskills.com/help/waits/' + MAX ([W1].[wait_type]) as XML) AS [Help/Info URL] 70 | FROM [Waits] AS [W1] 71 | INNER JOIN [Waits] AS [W2] 72 | ON [W2].[RowNum] <= [W1].[RowNum] 73 | GROUP BY [W1].[RowNum] 74 | HAVING SUM ([W2].[Percentage]) - MAX( [W1].[Percentage] ) < 95; -- percentage threshold 75 | GO -------------------------------------------------------------------------------- /SSMS Project/Query - WhatsGoingOn.sql: -------------------------------------------------------------------------------- 1 | USE master 2 | GO 3 | --kill 88 4 | --select * from sys.dm_exec_connections where session_id IN (608) 5 | --select * from sys.dm_exec_sessions where session_id IN (608) 6 | --select * from sys.dm_exec_requests where session_id IN (608) 7 | 8 | -- DBCC Inputbuffer() 9 | --SELECT session_id, sum(granted_memory_kb)/1024.0 AS Memory_mb 10 | --FROM sys.dm_exec_query_memory_grants 11 | --GROUP BY session_id 12 | --select * from sys.dm_exec_query_memory_grants 13 | --- What's happening with Active requests 14 | SELECT DB_NAME(er.database_id) AS DB_Name 15 | ,er.command 16 | ,es.host_name 17 | ,es.login_name 18 | ,datediff(minute,start_time,getdate()) AS RunTimeInMinutes 19 | ,blocking_session_id 20 | ,ISNULL(object_name(qp.objectid, qp.dbid),'*** Ad-Hoc ***') AS RunningCode 21 | ,er.* 22 | ,qp.objectid 23 | ,qp.dbid 24 | ,CAST(qp.query_plan AS XML) AS XML_Plan 25 | ,CAST('' AS XML) AS SqlText 28 | FROM sys.dm_exec_requests er 29 | LEFT OUTER JOIN sys.dm_exec_sessions es 30 | ON er.session_id = es.session_id 31 | OUTER APPLY sys.dm_exec_sql_text(er.sql_handle) st 32 | OUTER APPLY sys.dm_exec_text_query_plan(er.plan_handle, 33 | statement_start_offset, statement_end_offset) qp 34 | WHERE es.is_user_process = 1 35 | ORDER BY er.session_id desc 36 | 37 | -- Find idle sessions that have open transactions 38 | SELECT db_name(st.dbid), DATEDIFF(minute,s.last_request_end_time,getdate()) AS minutes_since_last_Request, 39 | s.*, st.* 40 | FROM sys.dm_exec_sessions AS s 41 | JOIN sys.dm_exec_connections AS c 42 | ON s.session_id = c.session_id 43 | OUTER APPLY sys.dm_exec_sql_text(c.most_recent_sql_handle) st 44 | WHERE EXISTS 45 | ( 46 | SELECT * 47 | FROM sys.dm_tran_session_transactions AS t 48 | WHERE t.session_id = s.session_id 49 | ) 50 | AND NOT EXISTS 51 | ( 52 | SELECT * 53 | FROM sys.dm_exec_requests AS r 54 | WHERE r.session_id = s.session_id 55 | ); 56 | 57 | DBCC SQLPERF(LOGSPACE); 58 | 59 | --kill 174 60 | --kill 140 61 | -- select * from sys.dm_os_sys_info 62 | -- select * from sys.dm_os_performance_counters 63 | /* 64 | --- What's happening with waiting tasks 65 | SELECT * FROM sys.dm_os_waiting_tasks 66 | ORDER BY session_id DESC 67 | */ 68 | --select * from sys.dm_Exec_connections 69 | --OUTER APPLY sys.dm_exec_sql_text(most_recent_sql_handle) st 70 | --where session_id IN (72,81) 71 | --select * from sys.dm_exec_sessions 72 | --where session_id = 233 73 | --select * from sys.dm_tran_locks where request_session_id = 150 74 | --select db_name(17) 75 | /* 76 | SELECT * 77 | FROM sys.dm_tran_session_transactions stran 78 | JOIN sys.dm_exec_sessions sess 79 | ON stran.session_id = sess.session_id 80 | JOIN sys.dm_exec_connections conn 81 | ON stran.session_id = conn.session_id 82 | OUTER APPLY sys.dm_exec_sql_text(most_recent_sql_handle) st 83 | WHERE stran.session_id NOT IN (SELECT session_id FROM sys.dm_exec_requests) 84 | */ 85 | /* 86 | --- What's happening with locks 87 | ---- No DB locks 88 | SELECT db_name(resource_database_id) AS DB_Name, * FROM sys.dm_tran_locks 89 | WHERE resource_type <> 'DATABASE' 90 | ORDER BY db_name(resource_database_id) 91 | ---- DB lock counts 92 | SELECT db_name(resource_database_id) AS DB_Name, count(1) FROM sys.dm_tran_locks 93 | WHERE resource_type = 'DATABASE' 94 | GROUP BY resource_database_id 95 | WITH ROLLUP 96 | -- List of database locks 97 | SELECT db_name(resource_database_id) AS DB_Name, request_session_id, * 98 | FROM sys.dm_tran_locks 99 | WHERE resource_type = 'DATABASE' 100 | and resource_database_id = db_id('Products') 101 | */ 102 | /* 103 | -- SQL Server memory & CPU usage 104 | declare @ts_now bigint 105 | --select @ts_now = cpu_ticks / convert(float, cpu_ticks_in_ms) from sys.dm_os_sys_info 106 | -- 2008 107 | select @ts_now = cpu_ticks / (cpu_ticks/ms_ticks) from sys.dm_os_sys_info; 108 | 109 | select record_id, 110 | dateadd(ms, -1 * (@ts_now - [timestamp]), GetDate()) as EventTime, 111 | SQLProcessUtilization, 112 | SystemIdle, 113 | 100 - SystemIdle - SQLProcessUtilization as OtherProcessUtilization 114 | from ( 115 | select 116 | record.value('(./Record/@id)[1]', 'int') as record_id, 117 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') as SystemIdle, 118 | record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int') as SQLProcessUtilization, 119 | timestamp 120 | from ( 121 | select timestamp, convert(xml, record) as record 122 | from sys.dm_os_ring_buffers 123 | where ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' 124 | and record like '%%') as x 125 | ) as y 126 | order by record_id desc 127 | 128 | */ 129 | /* 130 | --- What's happening with database locks 131 | SELECT db_name(resource_database_id) AS DB_Name, count(1) 132 | FROM sys.dm_tran_locks 133 | WHERE resource_type = 'DATABASE' 134 | GROUP BY db_name(resource_database_id) 135 | 136 | --- Who has locks on a given database 137 | SELECT sys.dm_exec_sessions.* 138 | FROM sys.dm_tran_locks 139 | JOIN sys.dm_exec_sessions 140 | ON sys.dm_tran_locks.request_session_id = sys.dm_exec_sessions.session_id 141 | WHERE resource_type = 'DATABASE' 142 | AND resource_database_id = db_id('Medpoint') 143 | 144 | */ 145 | /* 146 | --- Look at connections & sessions 147 | SELECT * FROM sys.dm_exec_sessions 148 | SELECT * FROM sys.dm_exec_connections 149 | */ 150 | /* 151 | --- Stats for a stored procedure 152 | SELECT CAST(qp.query_plan AS XML) AS XML_Plan, 153 | SUBSTRING(st.text,qs.statement_start_offset/2+1, 154 | ((CASE WHEN qs.statement_end_offset = -1 THEN DATALENGTH(st.text) 155 | ELSE qs.statement_end_offset END) - qs.statement_start_offset)/2 + 1) AS SqlText, 156 | qs.total_elapsed_time/qs.execution_count as avg_elapsed_time, 157 | qs.* 158 | FROM sys.dm_exec_query_stats qs 159 | JOIN sys.dm_exec_procedure_stats ps 160 | ON qs.sql_handle = ps.sql_handle 161 | CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) st 162 | CROSS APPLY sys.dm_exec_text_query_plan(qs.plan_handle, 163 | statement_start_offset, statement_end_offset) qp 164 | WHERE PS.object_id = object_id('Brass.dbo.RecalculateReconFileDetails'); 165 | */ 166 | 167 | /* 168 | ---- Check latch stats 169 | -- Baseline 170 | IF EXISTS (SELECT * FROM [tempdb].[sys].[objects] 171 | WHERE [name] = N'##TempLatchStats1') 172 | DROP TABLE [##TemplatchStats1]; 173 | GO 174 | SELECT * INTO [##TemplatchStats1] 175 | FROM sys.dm_os_latch_stats 176 | ORDER BY [latch_class]; 177 | GO 178 | 179 | -- Capture updated stats 180 | IF EXISTS (SELECT * FROM [tempdb].[sys].[objects] 181 | WHERE [name] = N'##TemplatchStats2') 182 | DROP TABLE [##TemplatchStats2]; 183 | GO 184 | SELECT * INTO [##TemplatchStats2] 185 | FROM sys.dm_os_latch_stats 186 | ORDER BY [latch_class]; 187 | GO 188 | 189 | -- Diff them 190 | SELECT 191 | '***' AS [New], 192 | [ts2].[latch_class] AS [latch], 193 | [ts2].[waiting_requests_count] AS [Diff_waiting_requests_count], 194 | [ts2].[wait_time_ms] AS [Diff_wait_time_ms], 195 | [ts2].[max_wait_time_ms] AS [max_wait_time_ms] 196 | FROM [##TemplatchStats2] [ts2] 197 | LEFT OUTER JOIN [##TemplatchStats1] [ts1] 198 | ON [ts2].[latch_class] = [ts1].[latch_class] 199 | WHERE [ts1].[latch_class] IS NULL 200 | UNION 201 | SELECT 202 | '' AS [New], 203 | [ts2].[latch_class] AS [latch], 204 | [ts2].[waiting_requests_count] - [ts1].[waiting_requests_count] AS [Diff_waiting_requests_count], 205 | [ts2].[wait_time_ms] - [ts1].[wait_time_ms] AS [Diff_wait_time_ms], 206 | [ts2].[max_wait_time_ms] AS [max_wait_time_ms] 207 | 208 | FROM [##TemplatchStats2] [ts2] 209 | LEFT OUTER JOIN [##TemplatchStats1] [ts1] 210 | ON [ts2].[latch_class] = [ts1].[latch_class] 211 | WHERE [ts1].[latch_class] IS NOT NULL 212 | ORDER BY [Diff_wait_time_ms] desc 213 | GO 214 | */ 215 | 216 | /* 217 | ----- Check spinlock waits 218 | -- Baseline 219 | IF EXISTS (SELECT * FROM [tempdb].[sys].[objects] 220 | WHERE [name] = N'##TempSpinlockStats1') 221 | DROP TABLE [##TempSpinlockStats1]; 222 | GO 223 | SELECT * INTO [##TempSpinlockStats1] 224 | FROM sys.dm_os_spinlock_stats 225 | WHERE [collisions] > 0 226 | ORDER BY [name]; 227 | GO 228 | 229 | -- Capture updated stats 230 | IF EXISTS (SELECT * FROM [tempdb].[sys].[objects] 231 | WHERE [name] = N'##TempSpinlockStats2') 232 | DROP TABLE [##TempSpinlockStats2]; 233 | GO 234 | SELECT * INTO [##TempSpinlockStats2] 235 | FROM sys.dm_os_spinlock_stats 236 | WHERE [collisions] > 0 237 | ORDER BY [name]; 238 | GO 239 | 240 | -- Diff them 241 | SELECT 242 | '***' AS [New], 243 | [ts2].[name] AS [Spinlock], 244 | [ts2].[collisions] AS [DiffCollisions], 245 | [ts2].[spins] AS [DiffSpins], 246 | [ts2].[spins_per_collision] AS [SpinsPerCollision], 247 | [ts2].[sleep_time] AS [DiffSleepTime], 248 | [ts2].[backoffs] AS [DiffBackoffs] 249 | FROM [##TempSpinlockStats2] [ts2] 250 | LEFT OUTER JOIN [##TempSpinlockStats1] [ts1] 251 | ON [ts2].[name] = [ts1].[name] 252 | WHERE [ts1].[name] IS NULL 253 | UNION 254 | SELECT 255 | '' AS [New], 256 | [ts2].[name] AS [Spinlock], 257 | [ts2].[collisions] - [ts1].[collisions] AS [DiffCollisions], 258 | [ts2].[spins] - [ts1].[spins] AS [DiffSpins], 259 | CASE ([ts2].[spins] - [ts1].[spins]) WHEN 0 THEN 0 260 | ELSE ([ts2].[spins] - [ts1].[spins]) / 261 | ([ts2].[collisions] - [ts1].[collisions]) END 262 | AS [SpinsPerCollision], 263 | [ts2].[sleep_time] - [ts1].[sleep_time] AS [DiffSleepTime], 264 | [ts2].[backoffs] - [ts1].[backoffs] AS [DiffBackoffs] 265 | FROM [##TempSpinlockStats2] [ts2] 266 | LEFT OUTER JOIN [##TempSpinlockStats1] [ts1] 267 | ON [ts2].[name] = [ts1].[name] 268 | WHERE [ts1].[name] IS NOT NULL 269 | AND [ts2].[collisions] - [ts1].[collisions] > 0 270 | ORDER BY diffcollisions desc 271 | GO 272 | */ 273 | /* 274 | ----- Wait stats 275 | WITH [Waits] AS 276 | (SELECT 277 | [wait_type], 278 | [wait_time_ms] / 1000.0 AS [WaitS], 279 | ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS], 280 | [signal_wait_time_ms] / 1000.0 AS [SignalS], 281 | [waiting_tasks_count] AS [WaitCount], 282 | 100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage], 283 | ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum] 284 | FROM sys.dm_os_wait_stats 285 | WHERE [wait_type] NOT IN ( 286 | N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', 287 | N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', 288 | N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', 289 | N'CHKPT', N'CLR_AUTO_EVENT', 290 | N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', 291 | N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', 292 | N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', 293 | N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', 294 | N'EXECSYNC', N'FSAGENT', 295 | N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', 296 | N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 297 | N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', 298 | N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', 299 | N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', 300 | N'LOGMGR_QUEUE', N'ONDEMAND_TASK_QUEUE', 301 | N'PWAIT_ALL_COMPONENTS_INITIALIZED', 302 | N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', 303 | N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', 304 | N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE', 305 | N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', 306 | N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', 307 | N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', 308 | N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', 309 | N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', 310 | N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', 311 | N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', 312 | N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 313 | N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS', 314 | N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', 315 | N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', 316 | N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN', 317 | N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT') 318 | AND [waiting_tasks_count] > 0 319 | ) 320 | SELECT 321 | MAX ([W1].[wait_type]) AS [WaitType], 322 | CAST (MAX ([W1].[WaitS]) AS DECIMAL (16,2)) AS [Wait_S], 323 | CAST (MAX ([W1].[ResourceS]) AS DECIMAL (16,2)) AS [Resource_S], 324 | CAST (MAX ([W1].[SignalS]) AS DECIMAL (16,2)) AS [Signal_S], 325 | MAX ([W1].[WaitCount]) AS [WaitCount], 326 | CAST (MAX ([W1].[Percentage]) AS DECIMAL (5,2)) AS [Percentage], 327 | CAST ((MAX ([W1].[WaitS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgWait_S], 328 | CAST ((MAX ([W1].[ResourceS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgRes_S], 329 | CAST ((MAX ([W1].[SignalS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgSig_S] 330 | FROM [Waits] AS [W1] 331 | INNER JOIN [Waits] AS [W2] 332 | ON [W2].[RowNum] <= [W1].[RowNum] 333 | GROUP BY [W1].[RowNum] 334 | HAVING SUM ([W2].[Percentage]) - MAX ([W1].[Percentage]) < 95; -- percentage threshold 335 | GO 336 | */ 337 | /* 338 | -- Kill negative session 339 | SELECT DISTINCT request_owner_guid, request_session_id 340 | FROM sys.dm_tran_locks 341 | WHERE request_session_id < 0 342 | KILL '1B9772FD-3022-4833-AEF6-2A26DCC406A5' 343 | KILL 'FC0C7B2D-C788-4763-9D48-1DFC02576B23' 344 | */ 345 | 346 | -------------------------------------------------------------------------------- /SSMS Project/Query - Where is my backup.sql: -------------------------------------------------------------------------------- 1 | -- BACKUP DATABASE MyDB TO DISK = 'X:\backups\MyDB_20190114000100_CO.bak' WITH COMPRESSION, COPY_ONLY, STATS = 10 2 | 3 | /* 4 | RESTORE DATABASE MyDB FROM 5 | DISK = 'X:\MyDB_2016_06_13_1430_CO.BAK' 6 | WITH MOVE 'MyDB' TO 'E:\Program Files\Microsoft SQL Server\MSSQL10_50\MSSQL\DATA\MyDB.mdf' 7 | ,MOVE 'MyDB' TO 'E:\Program Files\Microsoft SQL Server\MSSQL10_50\MSSQL\DATA\MyDB.ldf' 8 | ,STATS = 10 9 | */ 10 | /* 11 | SELECT r.session_id,r.command,CONVERT(NUMERIC(6,2),r.percent_complete) AS [Percent Complete], 12 | CONVERT(VARCHAR(20),DATEADD(ms,r.estimated_completion_time,GetDate()),20) AS [ETA Completion Time], 13 | CONVERT(NUMERIC(10,2),r.total_elapsed_time/1000.0/60.0) AS [Elapsed Min], 14 | CONVERT(NUMERIC(10,2),r.estimated_completion_time/1000.0/60.0) AS [ETA Min], 15 | CONVERT(NUMERIC(10,2),r.estimated_completion_time/1000.0/60.0/60.0) AS [ETA Hours], 16 | CONVERT(VARCHAR(1000),(SELECT SUBSTRING(text,r.statement_start_offset/2, 17 | CASE WHEN r.statement_end_offset = -1 THEN 1000 18 | ELSE (r.statement_end_offset-r.statement_start_offset)/2 END) 19 | FROM sys.dm_exec_sql_text(sql_handle))) 20 | FROM sys.dm_exec_requests r WHERE command IN ('RESTORE DATABASE','BACKUP DATABASE') 21 | */ 22 | 23 | USE msdb 24 | GO 25 | SELECT TOP 1000 backupset.database_name, backupset.type, 26 | backupset.name, backupmediafamily.physical_device_name, backupset.backup_finish_date, 27 | backupmediafamily.logical_device_name, backupmediafamily.device_type, 28 | CAST(backupset.backup_size/1024/1024 as int) AS Size_in_MB, 29 | datediff(minute,backupset.backup_start_date,backupset.backup_finish_date) backuptime_minutes, is_copy_only 30 | FROM backupset 31 | JOIN backupmediafamily 32 | ON backupset.media_set_id = backupmediafamily.media_set_id 33 | WHERE 1=1 34 | AND backupset.type in ('D') -- Full (D), Differential (I) or Log (L) 35 | -- AND physical_device_name NOT LIKE 'VNB%' -- Ignore backups going to tape 36 | -- AND backupset.database_name like 'MyDB%' -- Only backups for a specific DB or group of DBs 37 | ORDER BY backupset.backup_finish_date DESC, backupset.database_name DESC 38 | -------------------------------------------------------------------------------- /SSMS Project/Query - WhereIsMyBackup.sql: -------------------------------------------------------------------------------- 1 | /* 2 | ------ Sample backup command (default is copy_only) 3 | BACKUP DATABASE SVSWeb TO DISK = '\\sdsstore\tempstore\AGTDBAs\WREL-19919\SVSWeb_20220805_CO.bak' WITH COMPRESSION, COPY_ONLY, STATS = 10 4 | ------ Sample restore command 5 | RESTORE DATABASE WFGOnlineCMSRedesign FROM 6 | DISK = '\\crdgasqlbu\wfgmodcompass_sql_dump\crdbwfgomod\\WFGOnlineCMSStage\WFGOnlineCMSStage_backup_2016_06_13_1430_CO.BAK' 7 | WITH MOVE 'Orchard_AlphaMyWFG' TO 'E:\Program Files\Microsoft SQL Server\CRDBWFGOM\MSSQL10_50.CRDBWFGOMOD\MSSQL\DATA\WFGOnlineCMSRedesign.mdf' 8 | ,MOVE 'Orchard_AlphaMyWFG_log' TO 'E:\Program Files\Microsoft SQL Server\CRDBWFGOM\MSSQL10_50.CRDBWFGOMOD\MSSQL\DATA\WFGOnlineCMSRedesign_0.ldf' 9 | ,STATS = 10 10 | */ 11 | /* 12 | ------ Backup/Restore progress 13 | SELECT r.session_id,r.command,CONVERT(NUMERIC(6,2),r.percent_complete) AS [Percent Complete], 14 | CONVERT(VARCHAR(20),DATEADD(ms,r.estimated_completion_time,GetDate()),20) AS [ETA Completion Time], 15 | CONVERT(NUMERIC(10,2),r.total_elapsed_time/1000.0/60.0) AS [Elapsed Min], 16 | CONVERT(NUMERIC(10,2),r.estimated_completion_time/1000.0/60.0) AS [ETA Min], 17 | CONVERT(NUMERIC(10,2),r.estimated_completion_time/1000.0/60.0/60.0) AS [ETA Hours], 18 | CONVERT(VARCHAR(1000),(SELECT SUBSTRING(text,r.statement_start_offset/2, 19 | CASE WHEN r.statement_end_offset = -1 THEN 1000 20 | ELSE (r.statement_end_offset-r.statement_start_offset)/2 END) 21 | FROM sys.dm_exec_sql_text(sql_handle))) 22 | FROM sys.dm_exec_requests r WHERE command IN ('RESTORE DATABASE','BACKUP DATABASE') 23 | */ 24 | /* 25 | ------ Restore information 26 | SELECT rh.restore_date, rh.destination_database_name, rh.user_name AS restore_user_name, 27 | bus.name AS backup_name, bus.user_name AS backup_user_name, bus.backup_finish_date, 28 | bus.type AS backup_type, bus.server_name, bmf.physical_device_name 29 | FROM restorehistory rh 30 | JOIN backupset bus 31 | ON rh.backup_set_id = bus.backup_set_id 32 | JOIN backupmediaset bms 33 | ON bms.media_set_id = bus.media_set_id 34 | JOIN backupmediafamily bmf 35 | ON bmf.media_set_id = bus.media_set_id 36 | WHERE 1=1 37 | AND rh.destination_database_name = 'bi_admin' 38 | */ 39 | 40 | USE msdb 41 | GO 42 | SELECT TOP 1000 backupset.database_name, backupset.type, 43 | backupset.name, backupmediafamily.physical_device_name, backupset.backup_finish_date, 44 | backupmediafamily.logical_device_name, backupmediafamily.device_type, 45 | CAST(backupset.backup_size/1024/1024 as int) AS Size_in_MB, 46 | datediff(minute,backupset.backup_start_date,backupset.backup_finish_date) backuptime_minutes, is_copy_only 47 | FROM backupset 48 | JOIN backupmediafamily 49 | ON backupset.media_set_id = backupmediafamily.media_set_id 50 | WHERE 1=1 51 | AND backupset.type in ('D') -- Full (D), Differential (I) or Log (L) 52 | --AND physical_device_name NOT LIKE 'VNB%' -- Ignore backups going to tape 53 | -- AND backupset.database_name like 'pegasys%' -- Only backups for a specific DB or group of DBs 54 | ORDER BY backupset.backup_finish_date DESC, backupset.database_name DESC 55 | 56 | 57 | -------------------------------------------------------------------------------- /sp_AzSQLDBPermissions.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************* 2 | sp_AzSQLDBPermissions V1.0 3 | Kenneth Fisher 4 | 5 | http://www.sqlstudies.com 6 | 7 | This stored procedure returns 3 data sets. The first dataset is the list of database 8 | principals, the second is role membership, and the third is object and database level 9 | permissions. 10 | 11 | The final 2 columns of each query are "Un-Do"/"Do" scripts. For example removing a member 12 | from a role or adding them to a role. I am fairly confident in the role scripts, however, 13 | the scripts in the database principals query and database/object permissions query are 14 | works in progress. In particular certificates, keys and column level permissions are not 15 | scripted out. Also while the scripts have worked flawlessly on the systems I've tested 16 | them on, these systems are fairly similar when it comes to security so I can't say that 17 | in a more complicated system there won't be the odd bug. 18 | 19 | Standard disclaimer: You use scripts off of the web at your own risk. I fully expect this 20 | script to work without issue but I've been known to be wrong before. 21 | 22 | 23 | Removed Parameters: 24 | @DBName 25 | Because this is Azure SQL DB it's not possible to run this on any database but the current one. 26 | @LoginName 27 | The sysem views sys.server_xxxxxx aren't available so I've removed this. 28 | 29 | Parameters: 30 | @Principal 31 | If NOT NULL then all three queries only pull for that database principal. @Principal 32 | is a pattern check. The queries check for any row where the passed in value exists. 33 | It uses the pattern '%' + @Principal + '%' 34 | @Role 35 | If NOT NULL then the roles query will pull members of the role. If it is NOT NULL 36 | then DB principal and permissions query will pull the principal row for the role 37 | and the permissions for the role. @Role is a pattern check. The queries check 38 | for any row where the passed in value exists. It uses the pattern '%' + @Role + 39 | '%' 40 | @Type 41 | If NOT NULL then all three queries will only pull principals of that type. 42 | S = SQL login 43 | U = Windows login 44 | G = Windows group 45 | R = Server role 46 | C = Login mapped to a certificate 47 | K = Login mapped to an asymmetric key 48 | @ObjectName 49 | If NOT NULL then the third query will display permissions specific to the object 50 | specified and the first two queries will display only those users with those specific 51 | permissions. Unfortunately at this point only objects in sys.all_objects will work. 52 | This parameter uses the pattern '%' + @ObjectName + '%' 53 | @Permission 54 | If NOT NULL then the third query will display only permissions that match what is in 55 | the parameter. The first two queries will display only those users with that specific 56 | permission. 57 | @UseLikeSearch 58 | When this is set to 1 (the default) then the search parameters will use LIKE (and 59 | %'s will be added around the @Principal, @Role, @ObjectName, and @LoginName parameters). 60 | When set to 0 searchs will use =. 61 | @IncludeMSShipped 62 | When this is set to 1 (the default) then all principals will be included. When set 63 | to 0 the fixed server roles and SA and Public principals will be excluded. 64 | @DropTempTables 65 | When this is set to 1 (the default) the temp tables used are dropped. If it's 0 66 | then the tempt ables are kept for references after the code has finished. 67 | The temp tables are: 68 | ##DBPrincipals 69 | ##DBRoles 70 | ##DBPermissions 71 | @Output 72 | What type of output is desired. 73 | Default - Either 'Default' or it doesn't match any of the allowed values then the SP 74 | will return the standard 3 outputs. 75 | None - No output at all. Usually used if you keeping the temp tables to do your own 76 | reporting. 77 | CreateOnly - Only return the create scripts where they aren't NULL. 78 | DropOnly - Only return the drop scripts where they aren't NULL. 79 | ScriptOnly - Return drop and create scripts where they aren't NULL. 80 | Report - Returns one output with one row per principal and a comma delimited list of 81 | roles the principal is a member of and a comma delimited list of the 82 | individual permissions they have. 83 | @Print 84 | Defaults to 0, but if a 1 is passed in then the queries are not run but printed 85 | out instead. This is primarily for debugging. 86 | 87 | Data is ordered as follows 88 | 1st result set: DBPrincipal 89 | 2nd result set: RoleName, UserName if the parameter @Role is used else 90 | UserName, RoleName 91 | 3rd result set: ObjectName then Grantee_Name if the parameter @ObjectName 92 | is used otherwise Grantee_Name, ObjectName 93 | 94 | -- V1.0 95 | -- 5/14/2019 – Copy sp_DBPermissions to sp_AzSQLDBPermissions 96 | -- 7/12/2019 - Add a GUID to the default password on the create script for SQL Ids because I don't trust you (or myself). 97 | *********************************************************************************************/ 98 | 99 | CREATE OR ALTER PROCEDURE dbo.sp_AzSQLDBPermissions 100 | ( 101 | @Principal sysname = NULL, 102 | @Role sysname = NULL, 103 | @Type nvarchar(30) = NULL, 104 | @ObjectName sysname = NULL, 105 | @Permission sysname = NULL, 106 | @UseLikeSearch bit = 1, 107 | @IncludeMSShipped bit = 1, 108 | @DropTempTables bit = 1, 109 | @Output varchar(30) = 'Default', 110 | @Print bit = 0 111 | ) 112 | AS 113 | 114 | SET NOCOUNT ON 115 | 116 | DECLARE @Collation nvarchar(75) 117 | SET @Collation = N' COLLATE ' + CAST(SERVERPROPERTY('Collation') AS nvarchar(50)) 118 | 119 | DECLARE @sql nvarchar(max) 120 | DECLARE @sql2 nvarchar(max) 121 | DECLARE @ObjectList nvarchar(max) 122 | 123 | DECLARE @LikeOperator nvarchar(4) 124 | 125 | IF @UseLikeSearch = 1 126 | SET @LikeOperator = N'LIKE' 127 | ELSE 128 | SET @LikeOperator = N'=' 129 | 130 | IF @UseLikeSearch = 1 131 | BEGIN 132 | IF LEN(ISNULL(@Principal,'')) > 0 133 | SET @Principal = N'%' + @Principal + N'%' 134 | 135 | IF LEN(ISNULL(@Role,'')) > 0 136 | SET @Role = N'%' + @Role + N'%' 137 | 138 | IF LEN(ISNULL(@ObjectName,'')) > 0 139 | SET @ObjectName = N'%' + @ObjectName + N'%' 140 | 141 | END 142 | 143 | --========================================================================= 144 | -- Database Principals 145 | SET @sql = 146 | N'SELECT DBPrincipals.principal_id AS DBPrincipalId, DBPrincipals.name AS DBPrincipal, DBPrincipals.type, 147 | DBPrincipals.type_desc, DBPrincipals.default_schema_name, DBPrincipals.create_date, 148 | DBPrincipals.modify_date, DBPrincipals.is_fixed_role, 149 | Authorizations.name AS RoleAuthorization, DBPrincipals.sid, 150 | CASE WHEN DBPrincipals.is_fixed_role = 0 AND DBPrincipals.name NOT IN (''dbo'',''guest'', ''INFORMATION_SCHEMA'', ''public'', ''sys'') THEN 151 | ''IF DATABASE_PRINCIPAL_ID('''''' + DBPrincipals.name + '''''') IS NOT NULL '' + 152 | ''DROP '' + CASE DBPrincipals.[type] WHEN ''C'' THEN NULL 153 | WHEN ''K'' THEN NULL 154 | WHEN ''R'' THEN ''ROLE'' 155 | WHEN ''A'' THEN ''APPLICATION ROLE'' 156 | ELSE ''USER'' END + 157 | '' ''+QUOTENAME(DBPrincipals.name' + @Collation + N') + '';'' ELSE NULL END AS DropScript, 158 | CASE WHEN DBPrincipals.is_fixed_role = 0 AND DBPrincipals.name NOT IN (''dbo'',''guest'', ''INFORMATION_SCHEMA'', ''public'', ''sys'') THEN 159 | ''IF DATABASE_PRINCIPAL_ID('''''' + DBPrincipals.name + '''''') IS NULL '' + 160 | ''CREATE '' + CASE DBPrincipals.[type] WHEN ''C'' THEN NULL 161 | WHEN ''K'' THEN NULL 162 | WHEN ''R'' THEN ''ROLE'' 163 | WHEN ''A'' THEN ''APPLICATION ROLE'' 164 | ELSE ''USER'' END + 165 | '' ''+QUOTENAME(DBPrincipals.name' + @Collation + N') END + 166 | CASE WHEN DBPrincipals.[type] = ''R'' THEN 167 | ISNULL('' AUTHORIZATION ''+QUOTENAME(Authorizations.name' + @Collation + N'),'''') 168 | WHEN DBPrincipals.[type] = ''X'' THEN '' FROM EXTERNAL PROVIDER'' 169 | WHEN DBPrincipals.[type] = ''A'' THEN 170 | '''' 171 | WHEN DBPrincipals.[type] NOT IN (''C'',''K'') THEN 172 | ISNULL('' WITH DEFAULT_SCHEMA = ''+ 173 | QUOTENAME(DBPrincipals.default_schema_name' + @Collation + N'),'''') 174 | ELSE '''' END + 175 | CASE WHEN DBPrincipals.[type] = ''S'' 176 | THEN '', PASSWORD = '''''''' '' ELSE '''' END + 177 | '';'' 178 | AS CreateScript 179 | FROM sys.database_principals DBPrincipals 180 | LEFT OUTER JOIN sys.database_principals Authorizations 181 | ON DBPrincipals.owning_principal_id = Authorizations.principal_id 182 | WHERE 1=1 183 | AND DBPrincipals.sid NOT IN (0x00, 0x01) ' 184 | 185 | IF LEN(ISNULL(@Principal,@Role)) > 0 186 | IF @Print = 1 187 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.name ' + @LikeOperator + N' ' + 188 | ISNULL(QUOTENAME(@Principal,N''''),QUOTENAME(@Role,'''')) 189 | ELSE 190 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.name ' + @LikeOperator + N' ISNULL(@Principal,@Role) ' 191 | 192 | IF LEN(@Type) > 0 193 | IF @Print = 1 194 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.type ' + @LikeOperator + N' ' + QUOTENAME(@Type,'''') 195 | ELSE 196 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.type ' + @LikeOperator + N' @Type' 197 | 198 | IF LEN(@ObjectName) > 0 199 | BEGIN 200 | SET @sql = @sql + NCHAR(13) + 201 | N' AND EXISTS (SELECT 1 202 | FROM sys.all_objects [Objects] 203 | INNER JOIN sys.database_permissions Permission 204 | ON Permission.major_id = [Objects].object_id 205 | WHERE Permission.major_id = [Objects].object_id 206 | AND Permission.grantee_principal_id = DBPrincipals.principal_id ' + NCHAR(13) 207 | 208 | IF @Print = 1 209 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' ' + QUOTENAME(@ObjectName,'''') 210 | ELSE 211 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' @ObjectName' 212 | 213 | SET @sql = @sql + N')' 214 | END 215 | 216 | IF LEN(@Permission) > 0 217 | BEGIN 218 | SET @sql = @sql + NCHAR(13) + 219 | N' AND EXISTS (SELECT 1 220 | FROM sys.database_permissions Permission 221 | WHERE Permission.grantee_principal_id = DBPrincipals.principal_id ' + NCHAR(13) 222 | 223 | IF @Print = 1 224 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' ' + QUOTENAME(@Permission,'''') 225 | ELSE 226 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' @Permission' 227 | 228 | SET @sql = @sql + N')' 229 | END 230 | 231 | IF @IncludeMSShipped = 0 232 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.is_fixed_role = 0 ' + NCHAR(13) + 233 | ' AND DBPrincipals.name NOT IN (''dbo'',''public'',''INFORMATION_SCHEMA'',''guest'',''sys'') ' 234 | 235 | IF @Print = 1 236 | BEGIN 237 | PRINT N'-- Database Principals' 238 | PRINT CAST(@sql AS nvarchar(max)) 239 | PRINT '' -- Spacing before the next print 240 | PRINT '' 241 | END 242 | ELSE 243 | BEGIN 244 | IF object_id('tempdb..##DBPrincipals') IS NOT NULL 245 | DROP TABLE ##DBPrincipals 246 | 247 | -- Create temp table to store the data in 248 | CREATE TABLE ##DBPrincipals ( 249 | DBPrincipalId int NULL, 250 | DBPrincipal sysname NULL, 251 | type char(1) NULL, 252 | type_desc nchar(60) NULL, 253 | default_schema_name sysname NULL, 254 | create_date datetime NULL, 255 | modify_date datetime NULL, 256 | is_fixed_role bit NULL, 257 | RoleAuthorization sysname NULL, 258 | sid varbinary(85) NULL, 259 | DropScript nvarchar(max) NULL, 260 | CreateScript nvarchar(max) NULL 261 | ) 262 | 263 | SET @sql = N'INSERT INTO ##DBPrincipals ' + NCHAR(13) + @sql 264 | 265 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30), 266 | @ObjectName sysname, @Permission sysname', 267 | @Principal, @Role, @Type, @ObjectName, @Permission 268 | END 269 | --========================================================================= 270 | -- Database Role Members 271 | SET @sql = 272 | N'SELECT Users.principal_id AS UserPrincipalId, Users.name AS UserName, Roles.name AS RoleName, 273 | CASE WHEN Users.is_fixed_role = 0 AND Users.name <> ''dbo'' THEN 274 | ''EXEC sp_droprolemember @rolename = ''+QUOTENAME(Roles.name' + @Collation + 275 | N','''''''')+'', @membername = ''+QUOTENAME(CASE WHEN Users.name = ''dbo'' THEN NULL 276 | ELSE Users.name END' + @Collation + 277 | N','''''''')+'';'' END AS DropScript, 278 | CASE WHEN Users.is_fixed_role = 0 AND Users.name <> ''dbo'' THEN 279 | ''EXEC sp_addrolemember @rolename = ''+QUOTENAME(Roles.name' + @Collation + 280 | N','''''''')+'', @membername = ''+QUOTENAME(CASE WHEN Users.name = ''dbo'' THEN NULL 281 | ELSE Users.name END' + @Collation + 282 | N','''''''')+'';'' END AS AddScript 283 | FROM sys.database_role_members RoleMembers 284 | JOIN sys.database_principals Users 285 | ON RoleMembers.member_principal_id = Users.principal_id 286 | JOIN sys.database_principals Roles 287 | ON RoleMembers.role_principal_id = Roles.principal_id 288 | WHERE 1=1 ' 289 | 290 | IF LEN(ISNULL(@Principal,'')) > 0 291 | IF @Print = 1 292 | SET @sql = @sql + NCHAR(13) + N' AND Users.name ' + @LikeOperator + N' '+QUOTENAME(@Principal,'''') 293 | ELSE 294 | SET @sql = @sql + NCHAR(13) + N' AND Users.name ' + @LikeOperator + N' @Principal' 295 | 296 | IF LEN(ISNULL(@Role,'')) > 0 297 | IF @Print = 1 298 | SET @sql = @sql + NCHAR(13) + N' AND Roles.name ' + @LikeOperator + N' '+QUOTENAME(@Role,'''') 299 | ELSE 300 | SET @sql = @sql + NCHAR(13) + N' AND Roles.name ' + @LikeOperator + N' @Role' 301 | 302 | IF LEN(@Type) > 0 303 | IF @Print = 1 304 | SET @sql = @sql + NCHAR(13) + N' AND Users.type ' + @LikeOperator + N' ' + QUOTENAME(@Type,'''') 305 | ELSE 306 | SET @sql = @sql + NCHAR(13) + N' AND Users.type ' + @LikeOperator + N' @Type' 307 | 308 | IF LEN(@ObjectName) > 0 309 | BEGIN 310 | SET @sql = @sql + NCHAR(13) + 311 | N' AND EXISTS (SELECT 1 312 | FROM sys.all_objects [Objects] 313 | INNER JOIN sys.database_permissions Permission 314 | ON Permission.major_id = [Objects].object_id 315 | WHERE Permission.major_id = [Objects].object_id 316 | AND Permission.grantee_principal_id = Users.principal_id ' + NCHAR(13) 317 | 318 | IF @Print = 1 319 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' ' + QUOTENAME(@ObjectName,'''') 320 | ELSE 321 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' @ObjectName' 322 | 323 | SET @sql = @sql + N')' 324 | END 325 | 326 | IF LEN(@Permission) > 0 327 | BEGIN 328 | SET @sql = @sql + NCHAR(13) + 329 | N' AND EXISTS (SELECT 1 330 | FROM sys.database_permissions Permission 331 | WHERE Permission.grantee_principal_id = Users.principal_id ' + NCHAR(13) 332 | 333 | IF @Print = 1 334 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' ' + QUOTENAME(@Permission,'''') 335 | ELSE 336 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' @Permission' 337 | 338 | SET @sql = @sql + N')' 339 | END 340 | 341 | IF @IncludeMSShipped = 0 342 | SET @sql = @sql + NCHAR(13) + N' AND Users.is_fixed_role = 0 ' + NCHAR(13) + 343 | ' AND Users.name NOT IN (''dbo'',''public'',''INFORMATION_SCHEMA'',''guest'',''sys'') ' 344 | 345 | IF @Print = 1 346 | BEGIN 347 | PRINT N'-- Database Role Members' 348 | PRINT CAST(@sql AS nvarchar(max)) 349 | PRINT '' -- Spacing before the next print 350 | PRINT '' 351 | END 352 | ELSE 353 | BEGIN 354 | IF object_id('tempdb..##DBRoles') IS NOT NULL 355 | DROP TABLE ##DBRoles 356 | 357 | -- Create temp table to store the data in 358 | CREATE TABLE ##DBRoles ( 359 | UserPrincipalId int NULL, 360 | UserName sysname NULL, 361 | RoleName sysname NULL, 362 | DropScript nvarchar(max) NULL, 363 | AddScript nvarchar(max) NULL 364 | ) 365 | 366 | SET @sql = 'INSERT INTO ##DBRoles ' + NCHAR(13) + @sql 367 | 368 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30), 369 | @ObjectName sysname, @Permission sysname', 370 | @Principal, @Role, @Type, @ObjectName, @Permission 371 | END 372 | 373 | --========================================================================= 374 | -- Database & object Permissions 375 | SET @ObjectList = 376 | N'; WITH ObjectList AS ( 377 | SELECT SCHEMA_NAME(sys.all_objects.schema_id) ' + @Collation + N' AS SchemaName, 378 | name ' + @Collation + N' AS name, 379 | object_id AS id, 380 | ''OBJECT_OR_COLUMN'' AS class_desc, 381 | ''OBJECT'' AS class 382 | FROM sys.all_objects 383 | UNION ALL 384 | SELECT name ' + @Collation + N' AS SchemaName, 385 | NULL AS name, 386 | schema_id AS id, 387 | ''SCHEMA'' AS class_desc, 388 | ''SCHEMA'' AS class 389 | FROM sys.schemas 390 | UNION ALL 391 | SELECT NULL AS SchemaName, 392 | name ' + @Collation + N' AS name, 393 | principal_id AS id, 394 | ''DATABASE_PRINCIPAL'' AS class_desc, 395 | CASE type_desc 396 | WHEN ''APPLICATION_ROLE'' THEN ''APPLICATION ROLE'' 397 | WHEN ''DATABASE_ROLE'' THEN ''ROLE'' 398 | ELSE ''USER'' END AS class 399 | FROM sys.database_principals 400 | UNION ALL 401 | SELECT NULL AS SchemaName, 402 | name ' + @Collation + N' AS name, 403 | assembly_id AS id, 404 | ''ASSEMBLY'' AS class_desc, 405 | ''ASSEMBLY'' AS class 406 | FROM sys.assemblies 407 | UNION ALL' + NCHAR(13) 408 | 409 | SET @ObjectList = @ObjectList + 410 | N' SELECT SCHEMA_NAME(sys.types.schema_id) ' + @Collation + N' AS SchemaName, 411 | name ' + @Collation + N' AS name, 412 | user_type_id AS id, 413 | ''TYPE'' AS class_desc, 414 | ''TYPE'' AS class 415 | FROM sys.types 416 | UNION ALL 417 | SELECT SCHEMA_NAME(schema_id) ' + @Collation + N' AS SchemaName, 418 | name ' + @Collation + N' AS name, 419 | xml_collection_id AS id, 420 | ''XML_SCHEMA_COLLECTION'' AS class_desc, 421 | ''XML SCHEMA COLLECTION'' AS class 422 | FROM sys.xml_schema_collections 423 | UNION ALL 424 | SELECT NULL AS SchemaName, 425 | name ' + @Collation + N' AS name, 426 | message_type_id AS id, 427 | ''MESSAGE_TYPE'' AS class_desc, 428 | ''MESSAGE TYPE'' AS class 429 | FROM sys.service_message_types 430 | UNION ALL 431 | SELECT NULL AS SchemaName, 432 | name ' + @Collation + N' AS name, 433 | service_contract_id AS id, 434 | ''SERVICE_CONTRACT'' AS class_desc, 435 | ''CONTRACT'' AS class 436 | FROM sys.service_contracts 437 | UNION ALL 438 | SELECT NULL AS SchemaName, 439 | name ' + @Collation + N' AS name, 440 | service_id AS id, 441 | ''SERVICE'' AS class_desc, 442 | ''SERVICE'' AS class 443 | FROM sys.services 444 | UNION ALL 445 | SELECT NULL AS SchemaName, 446 | name ' + @Collation + N' AS name, 447 | remote_service_binding_id AS id, 448 | ''REMOTE_SERVICE_BINDING'' AS class_desc, 449 | ''REMOTE SERVICE BINDING'' AS class 450 | FROM sys.remote_service_bindings 451 | UNION ALL 452 | SELECT NULL AS SchemaName, 453 | name ' + @Collation + N' AS name, 454 | route_id AS id, 455 | ''ROUTE'' AS class_desc, 456 | ''ROUTE'' AS class 457 | FROM sys.routes 458 | UNION ALL 459 | SELECT NULL AS SchemaName, 460 | name ' + @Collation + N' AS name, 461 | fulltext_catalog_id AS id, 462 | ''FULLTEXT_CATALOG'' AS class_desc, 463 | ''FULLTEXT CATALOG'' AS class 464 | FROM sys.fulltext_catalogs 465 | UNION ALL 466 | SELECT NULL AS SchemaName, 467 | name ' + @Collation + N' AS name, 468 | symmetric_key_id AS id, 469 | ''SYMMETRIC_KEYS'' AS class_desc, 470 | ''SYMMETRIC KEY'' AS class 471 | FROM sys.symmetric_keys 472 | UNION ALL 473 | SELECT NULL AS SchemaName, 474 | name ' + @Collation + N' AS name, 475 | certificate_id AS id, 476 | ''CERTIFICATE'' AS class_desc, 477 | ''CERTIFICATE'' AS class 478 | FROM sys.certificates 479 | UNION ALL 480 | SELECT NULL AS SchemaName, 481 | name ' + @Collation + N' AS name, 482 | asymmetric_key_id AS id, 483 | ''ASYMMETRIC_KEY'' AS class_desc, 484 | ''ASYMMETRIC KEY'' AS class 485 | FROM sys.asymmetric_keys 486 | ) ' + NCHAR(13) 487 | 488 | SET @sql = 489 | N'SELECT Grantee.principal_id AS GranteePrincipalId, Grantee.name AS GranteeName, Grantor.name AS GrantorName, 490 | Permission.class_desc, Permission.permission_name, 491 | ObjectList.name AS ObjectName, 492 | ObjectList.SchemaName, 493 | Permission.state_desc, 494 | CASE WHEN Grantee.is_fixed_role = 0 AND Grantee.name <> ''dbo'' THEN 495 | ''REVOKE '' + 496 | CASE WHEN Permission.[state] = ''W'' THEN ''GRANT OPTION FOR '' ELSE '''' END + 497 | '' '' + Permission.permission_name' + @Collation + N' + 498 | CASE WHEN Permission.major_id <> 0 THEN '' ON '' + 499 | ObjectList.class + ''::'' + 500 | ISNULL(QUOTENAME(ObjectList.SchemaName),'''') + 501 | CASE WHEN ObjectList.SchemaName + ObjectList.name IS NULL THEN '''' ELSE ''.'' END + 502 | ISNULL(QUOTENAME(ObjectList.name),'''') 503 | ' + @Collation + ' + '' '' ELSE '''' END + 504 | '' FROM '' + QUOTENAME(Grantee.name' + @Collation + N') + ''; '' END AS RevokeScript, 505 | CASE WHEN Grantee.is_fixed_role = 0 AND Grantee.name <> ''dbo'' THEN 506 | CASE WHEN Permission.[state] = ''W'' THEN ''GRANT'' ELSE Permission.state_desc' + @Collation + N' END + 507 | '' '' + Permission.permission_name' + @Collation + N' + 508 | CASE WHEN Permission.major_id <> 0 THEN '' ON '' + 509 | ObjectList.class + ''::'' + 510 | ISNULL(QUOTENAME(ObjectList.SchemaName),'''') + 511 | CASE WHEN ObjectList.SchemaName + ObjectList.name IS NULL THEN '''' ELSE ''.'' END + 512 | ISNULL(QUOTENAME(ObjectList.name),'''') 513 | ' + @Collation + N' + '' '' ELSE '''' END + 514 | '' TO '' + QUOTENAME(Grantee.name' + @Collation + N') + '' '' + 515 | CASE WHEN Permission.[state] = ''W'' THEN '' WITH GRANT OPTION '' ELSE '''' END + 516 | '' AS ''+ QUOTENAME(Grantor.name' + @Collation + N')+'';'' END AS GrantScript 517 | FROM sys.database_permissions Permission 518 | JOIN sys.database_principals Grantee 519 | ON Permission.grantee_principal_id = Grantee.principal_id 520 | JOIN sys.database_principals Grantor 521 | ON Permission.grantor_principal_id = Grantor.principal_id 522 | LEFT OUTER JOIN ObjectList 523 | ON Permission.major_id = ObjectList.id 524 | AND Permission.class_desc = ObjectList.class_desc 525 | WHERE 1=1 ' 526 | 527 | IF LEN(ISNULL(@Principal,@Role)) > 0 528 | IF @Print = 1 529 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.name ' + @LikeOperator + N' ' + ISNULL(QUOTENAME(@Principal,''''),QUOTENAME(@Role,'''')) 530 | ELSE 531 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.name ' + @LikeOperator + N' ISNULL(@Principal,@Role) ' 532 | 533 | IF LEN(@Type) > 0 534 | IF @Print = 1 535 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.type ' + @LikeOperator + N' ' + QUOTENAME(@Type,'''') 536 | ELSE 537 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.type ' + @LikeOperator + N' @Type' 538 | 539 | IF LEN(@ObjectName) > 0 540 | IF @Print = 1 541 | SET @sql = @sql + NCHAR(13) + N' AND ObjectList.name ' + @LikeOperator + N' ' + QUOTENAME(@ObjectName,'''') 542 | ELSE 543 | SET @sql = @sql + NCHAR(13) + N' AND ObjectList.name ' + @LikeOperator + N' @ObjectName ' 544 | 545 | IF LEN(@Permission) > 0 546 | IF @Print = 1 547 | SET @sql = @sql + NCHAR(13) + N' AND Permission.permission_name ' + @LikeOperator + N' ' + QUOTENAME(@Permission,'''') 548 | ELSE 549 | SET @sql = @sql + NCHAR(13) + N' AND Permission.permission_name ' + @LikeOperator + N' @Permission' 550 | 551 | IF @IncludeMSShipped = 0 552 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.is_fixed_role = 0 ' + NCHAR(13) + 553 | ' AND Grantee.name NOT IN (''dbo'',''public'',''INFORMATION_SCHEMA'',''guest'',''sys'') ' 554 | 555 | IF @Print = 1 556 | BEGIN 557 | PRINT '-- Database & object Permissions' 558 | PRINT CAST(@ObjectList AS nvarchar(max)) 559 | PRINT CAST(@sql AS nvarchar(max)) 560 | END 561 | ELSE 562 | BEGIN 563 | IF object_id('tempdb..##DBPermissions') IS NOT NULL 564 | DROP TABLE ##DBPermissions 565 | 566 | -- Create temp table to store the data in 567 | CREATE TABLE ##DBPermissions ( 568 | GranteePrincipalId int NULL, 569 | GranteeName sysname NULL, 570 | GrantorName sysname NULL, 571 | class_desc nvarchar(60) NULL, 572 | permission_name nvarchar(128) NULL, 573 | ObjectName sysname NULL, 574 | SchemaName sysname NULL, 575 | state_desc nvarchar(60) NULL, 576 | RevokeScript nvarchar(max) NULL, 577 | GrantScript nvarchar(max) NULL 578 | ) 579 | 580 | -- Add insert statement to @sql 581 | SET @sql = @ObjectList + 582 | N'INSERT INTO ##DBPermissions ' + NCHAR(13) + 583 | @sql 584 | 585 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30), 586 | @ObjectName sysname, @Permission sysname', 587 | @Principal, @Role, @Type, @ObjectName, @Permission 588 | END 589 | 590 | IF @Print <> 1 591 | BEGIN 592 | IF @Output = 'None' 593 | PRINT '' 594 | ELSE IF @Output = 'CreateOnly' 595 | BEGIN 596 | SELECT CreateScript FROM ##DBPrincipals WHERE CreateScript IS NOT NULL 597 | UNION ALL 598 | SELECT AddScript FROM ##DBRoles WHERE AddScript IS NOT NULL 599 | UNION ALL 600 | SELECT GrantScript FROM ##DBPermissions WHERE GrantScript IS NOT NULL 601 | END 602 | ELSE IF @Output = 'DropOnly' 603 | BEGIN 604 | SELECT DropScript FROM ##DBPrincipals WHERE DropScript IS NOT NULL 605 | UNION ALL 606 | SELECT DropScript FROM ##DBRoles WHERE DropScript IS NOT NULL 607 | UNION ALL 608 | SELECT RevokeScript FROM ##DBPermissions WHERE RevokeScript IS NOT NULL 609 | END 610 | ELSE IF @Output = 'ScriptOnly' 611 | BEGIN 612 | SELECT DropScript, CreateScript FROM ##DBPrincipals WHERE DropScript IS NOT NULL OR CreateScript IS NOT NULL 613 | UNION ALL 614 | SELECT DropScript, AddScript FROM ##DBRoles WHERE DropScript IS NOT NULL OR AddScript IS NOT NULL 615 | UNION ALL 616 | SELECT RevokeScript, GrantScript FROM ##DBPermissions WHERE RevokeScript IS NOT NULL OR GrantScript IS NOT NULL 617 | END 618 | ELSE IF @Output = 'Report' 619 | BEGIN 620 | SELECT DBPrincipal, type, type_desc, 621 | STUFF((SELECT ', ' + ##DBRoles.RoleName 622 | FROM ##DBRoles 623 | WHERE ##DBPrincipals.DBPrincipalId = ##DBRoles.UserPrincipalId 624 | ORDER BY ##DBRoles.RoleName 625 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)') 626 | , 1, 2, '') AS RoleMembership, 627 | STUFF((SELECT ', ' + ##DBPermissions.state_desc + ' ' + ##DBPermissions.permission_name + ' on ' + 628 | COALESCE('OBJECT:'+##DBPermissions.SchemaName + '.' + ##DBPermissions.ObjectName, 629 | 'SCHEMA:'+##DBPermissions.SchemaName, 630 | 'DATABASE:'+db_name()) 631 | FROM ##DBPermissions 632 | WHERE ##DBPrincipals.DBPrincipalId = ##DBPermissions.GranteePrincipalId 633 | ORDER BY ##DBPermissions.state_desc, ##DBPermissions.ObjectName, ##DBPermissions.permission_name 634 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)') 635 | , 1, 2, '') AS DirectPermissions 636 | FROM ##DBPrincipals 637 | ORDER BY type, DBPrincipal 638 | END 639 | ELSE -- 'Default' or no match 640 | BEGIN 641 | SELECT DBPrincipal, type, type_desc, default_schema_name, 642 | create_date, modify_date, is_fixed_role, RoleAuthorization, sid, 643 | DropScript, CreateScript 644 | FROM ##DBPrincipals ORDER BY DBPrincipal 645 | IF LEN(@Role) > 0 646 | SELECT UserName, RoleName, DropScript, AddScript 647 | FROM ##DBRoles ORDER BY RoleName, UserName 648 | ELSE 649 | SELECT UserName, RoleName, DropScript, AddScript 650 | FROM ##DBRoles ORDER BY UserName, RoleName 651 | 652 | IF LEN(@ObjectName) > 0 653 | SELECT GranteeName, GrantorName, class_desc, permission_name, ObjectName, 654 | SchemaName, state_desc, RevokeScript, GrantScript 655 | FROM ##DBPermissions ORDER BY ObjectName, GranteeName 656 | ELSE 657 | SELECT GranteeName, GrantorName, class_desc, permission_name, ObjectName, 658 | SchemaName, state_desc, RevokeScript, GrantScript 659 | FROM ##DBPermissions ORDER BY GranteeName, ObjectName 660 | END 661 | 662 | IF @DropTempTables = 1 663 | BEGIN 664 | DROP TABLE ##DBPrincipals 665 | DROP TABLE ##DBRoles 666 | DROP TABLE ##DBPermissions 667 | END 668 | END 669 | GO 670 | -------------------------------------------------------------------------------- /sp_AzSYNDBPermissions.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************************* 2 | sp_AzSYNDBPermissions V1.0 3 | Kenneth Fisher 4 | 5 | http://www.sqlstudies.com 6 | 7 | This stored procedure returns 3 data sets. The first dataset is the list of database 8 | principals, the second is role membership, and the third is object and database level 9 | permissions. 10 | 11 | The final 2 columns of each query are "Un-Do"/"Do" scripts. For example removing a member 12 | from a role or adding them to a role. I am fairly confident in the role scripts, however, 13 | the scripts in the database principals query and database/object permissions query are 14 | works in progress. In particular certificates, keys and column level permissions are not 15 | scripted out. Also while the scripts have worked flawlessly on the systems I've tested 16 | them on, these systems are fairly similar when it comes to security so I can't say that 17 | in a more complicated system there won't be the odd bug. 18 | 19 | Standard disclaimer: You use scripts off of the web at your own risk. I fully expect this 20 | script to work without issue but I've been known to be wrong before. 21 | 22 | Data is ordered as follows 23 | 1st result set: DBPrincipal 24 | 2nd result set: RoleName, UserName if the parameter @Role is used else 25 | UserName, RoleName 26 | 3rd result set: ObjectName then Grantee_Name if the parameter @ObjectName 27 | is used otherwise Grantee_Name, ObjectName 28 | 29 | Because of complications when using Azure Synapse there are no parameters. This is 30 | strictly all of the permissions in the database and all three outputs. 31 | 32 | -- V1.0 33 | -- 8/31/2020 – Create sp_AzSYNDBPermissions based on queries from sp_AzSQLDBPermissionss 34 | *********************************************************************************************/ 35 | 36 | CREATE PROCEDURE dbo.sp_AzSYNDBPermissions 37 | AS 38 | -- Database Principals 39 | SELECT DBPrincipals.principal_id AS DBPrincipalId, DBPrincipals.name AS DBPrincipal, DBPrincipals.type, 40 | DBPrincipals.type_desc, DBPrincipals.default_schema_name, DBPrincipals.create_date, 41 | DBPrincipals.modify_date, DBPrincipals.is_fixed_role, 42 | Authorizations.name AS RoleAuthorization, DBPrincipals.sid, 43 | CASE WHEN DBPrincipals.is_fixed_role = 0 AND DBPrincipals.name NOT IN ('dbo','guest', 'INFORMATION_SCHEMA', 'public', 'sys') THEN 44 | 'IF DATABASE_PRINCIPAL_ID(''' + DBPrincipals.name + ''') IS NOT NULL ' + 45 | 'DROP ' + CASE DBPrincipals.[type] WHEN 'C' THEN NULL 46 | WHEN 'K' THEN NULL 47 | WHEN 'R' THEN 'ROLE' 48 | WHEN 'A' THEN 'APPLICATION ROLE' 49 | ELSE 'USER' END + 50 | ' '+QUOTENAME(DBPrincipals.name COLLATE SQL_Latin1_General_CP1_CI_AS) + ';' ELSE NULL END AS DropScript, 51 | CASE WHEN DBPrincipals.is_fixed_role = 0 AND DBPrincipals.name NOT IN ('dbo','guest', 'INFORMATION_SCHEMA', 'public', 'sys') THEN 52 | 'IF DATABASE_PRINCIPAL_ID(''' + DBPrincipals.name + ''') IS NULL ' + 53 | 'CREATE ' + CASE DBPrincipals.[type] WHEN 'C' THEN NULL 54 | WHEN 'K' THEN NULL 55 | WHEN 'R' THEN 'ROLE' 56 | WHEN 'A' THEN 'APPLICATION ROLE' 57 | ELSE 'USER' END + 58 | ' '+QUOTENAME(DBPrincipals.name COLLATE SQL_Latin1_General_CP1_CI_AS) END + 59 | CASE WHEN DBPrincipals.[type] = 'R' THEN 60 | ISNULL(' AUTHORIZATION '+QUOTENAME(Authorizations.name COLLATE SQL_Latin1_General_CP1_CI_AS),'') 61 | WHEN DBPrincipals.[type] = 'X' THEN ' FROM EXTERNAL PROVIDER' 62 | WHEN DBPrincipals.[type] = 'A' THEN 63 | '' 64 | WHEN DBPrincipals.[type] NOT IN ('C','K') THEN 65 | ISNULL(' WITH DEFAULT_SCHEMA = '+ 66 | QUOTENAME(DBPrincipals.default_schema_name COLLATE SQL_Latin1_General_CP1_CI_AS),'') 67 | ELSE '' END + 68 | CASE WHEN DBPrincipals.[type] = 'S' 69 | THEN ', PASSWORD = '''' ' ELSE '' END + 70 | ';' 71 | AS CreateScript 72 | FROM sys.database_principals DBPrincipals 73 | LEFT OUTER JOIN sys.database_principals Authorizations 74 | ON DBPrincipals.owning_principal_id = Authorizations.principal_id 75 | WHERE 1=1 76 | AND DBPrincipals.sid NOT IN (0x00, 0x01) 77 | 78 | 79 | -- Database Role Members 80 | SELECT Users.principal_id AS UserPrincipalId, Users.name AS UserName, Roles.name AS RoleName, 81 | CASE WHEN Users.is_fixed_role = 0 AND Users.name <> 'dbo' THEN 82 | 'EXEC sp_droprolemember @rolename = '+QUOTENAME(Roles.name COLLATE SQL_Latin1_General_CP1_CI_AS,'''')+', @membername = '+QUOTENAME(CASE WHEN Users.name = 'dbo' THEN NULL 83 | ELSE Users.name END COLLATE SQL_Latin1_General_CP1_CI_AS,'''')+';' END AS DropScript, 84 | CASE WHEN Users.is_fixed_role = 0 AND Users.name <> 'dbo' THEN 85 | 'EXEC sp_addrolemember @rolename = '+QUOTENAME(Roles.name COLLATE SQL_Latin1_General_CP1_CI_AS,'''')+', @membername = '+QUOTENAME(CASE WHEN Users.name = 'dbo' THEN NULL 86 | ELSE Users.name END COLLATE SQL_Latin1_General_CP1_CI_AS,'''')+';' END AS AddScript 87 | FROM sys.database_role_members RoleMembers 88 | JOIN sys.database_principals Users 89 | ON RoleMembers.member_principal_id = Users.principal_id 90 | JOIN sys.database_principals Roles 91 | ON RoleMembers.role_principal_id = Roles.principal_id 92 | WHERE 1=1 93 | 94 | 95 | -- Database & object Permissions 96 | ; WITH ObjectList AS ( 97 | SELECT SCHEMA_NAME(sys.all_objects.schema_id) COLLATE SQL_Latin1_General_CP1_CI_AS AS SchemaName, 98 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 99 | object_id AS id, 100 | 'OBJECT_OR_COLUMN' AS class_desc, 101 | 'OBJECT' AS class 102 | FROM sys.all_objects 103 | UNION ALL 104 | SELECT name COLLATE SQL_Latin1_General_CP1_CI_AS AS SchemaName, 105 | NULL AS name, 106 | schema_id AS id, 107 | 'SCHEMA' AS class_desc, 108 | 'SCHEMA' AS class 109 | FROM sys.schemas 110 | UNION ALL 111 | SELECT NULL AS SchemaName, 112 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 113 | principal_id AS id, 114 | 'DATABASE_PRINCIPAL' AS class_desc, 115 | CASE type_desc 116 | WHEN 'APPLICATION_ROLE' THEN 'APPLICATION ROLE' 117 | WHEN 'DATABASE_ROLE' THEN 'ROLE' 118 | ELSE 'USER' END AS class 119 | FROM sys.database_principals 120 | UNION ALL 121 | SELECT NULL AS SchemaName, 122 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 123 | assembly_id AS id, 124 | 'ASSEMBLY' AS class_desc, 125 | 'ASSEMBLY' AS class 126 | FROM sys.assemblies 127 | UNION ALL 128 | SELECT SCHEMA_NAME(sys.types.schema_id) COLLATE SQL_Latin1_General_CP1_CI_AS AS SchemaName, 129 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 130 | user_type_id AS id, 131 | 'TYPE' AS class_desc, 132 | 'TYPE' AS class 133 | FROM sys.types 134 | UNION ALL 135 | SELECT NULL AS SchemaName, 136 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 137 | symmetric_key_id AS id, 138 | 'SYMMETRIC_KEYS' AS class_desc, 139 | 'SYMMETRIC KEY' AS class 140 | FROM sys.symmetric_keys 141 | UNION ALL 142 | SELECT NULL AS SchemaName, 143 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 144 | certificate_id AS id, 145 | 'CERTIFICATE' AS class_desc, 146 | 'CERTIFICATE' AS class 147 | FROM sys.certificates 148 | UNION ALL 149 | SELECT NULL AS SchemaName, 150 | name COLLATE SQL_Latin1_General_CP1_CI_AS AS name, 151 | asymmetric_key_id AS id, 152 | 'ASYMMETRIC_KEY' AS class_desc, 153 | 'ASYMMETRIC KEY' AS class 154 | FROM sys.asymmetric_keys 155 | ) 156 | 157 | SELECT Grantee.principal_id AS GranteePrincipalId, Grantee.name AS GranteeName, Grantor.name AS GrantorName, 158 | Permission.class_desc, Permission.permission_name, 159 | ObjectList.name AS ObjectName, 160 | ObjectList.SchemaName, 161 | Permission.state_desc, 162 | CASE WHEN Grantee.is_fixed_role = 0 AND Grantee.name <> 'dbo' THEN 163 | 'REVOKE ' + 164 | CASE WHEN Permission.[state] = 'W' THEN 'GRANT OPTION FOR ' ELSE '' END + 165 | ' ' + Permission.permission_name COLLATE SQL_Latin1_General_CP1_CI_AS + 166 | CASE WHEN Permission.major_id <> 0 THEN ' ON ' + 167 | ObjectList.class + '::' + 168 | ISNULL(QUOTENAME(ObjectList.SchemaName),'') + 169 | CASE WHEN ObjectList.SchemaName + ObjectList.name IS NULL THEN '' ELSE '.' END + 170 | ISNULL(QUOTENAME(ObjectList.name),'') 171 | COLLATE SQL_Latin1_General_CP1_CI_AS + ' ' ELSE '' END + 172 | ' FROM ' + QUOTENAME(Grantee.name COLLATE SQL_Latin1_General_CP1_CI_AS) + '; ' END AS RevokeScript, 173 | CASE WHEN Grantee.is_fixed_role = 0 AND Grantee.name <> 'dbo' THEN 174 | CASE WHEN Permission.[state] = 'W' THEN 'GRANT' ELSE Permission.state_desc COLLATE SQL_Latin1_General_CP1_CI_AS END + 175 | ' ' + Permission.permission_name COLLATE SQL_Latin1_General_CP1_CI_AS + 176 | CASE WHEN Permission.major_id <> 0 THEN ' ON ' + 177 | ObjectList.class + '::' + 178 | ISNULL(QUOTENAME(ObjectList.SchemaName),'') + 179 | CASE WHEN ObjectList.SchemaName + ObjectList.name IS NULL THEN '' ELSE '.' END + 180 | ISNULL(QUOTENAME(ObjectList.name),'') 181 | COLLATE SQL_Latin1_General_CP1_CI_AS + ' ' ELSE '' END + 182 | ' TO ' + QUOTENAME(Grantee.name COLLATE SQL_Latin1_General_CP1_CI_AS) + ' ' + 183 | CASE WHEN Permission.[state] = 'W' THEN ' WITH GRANT OPTION ' ELSE '' END + 184 | ' AS '+ QUOTENAME(Grantor.name COLLATE SQL_Latin1_General_CP1_CI_AS)+';' END AS GrantScript 185 | FROM sys.database_permissions Permission 186 | JOIN sys.database_principals Grantee 187 | ON Permission.grantee_principal_id = Grantee.principal_id 188 | JOIN sys.database_principals Grantor 189 | ON Permission.grantor_principal_id = Grantor.principal_id 190 | LEFT OUTER JOIN ObjectList 191 | ON Permission.major_id = ObjectList.id 192 | AND Permission.class_desc = ObjectList.class_desc 193 | WHERE 1=1 194 | -------------------------------------------------------------------------------- /sp_DBPermissions.sql: -------------------------------------------------------------------------------- 1 | USE master 2 | GO 3 | IF OBJECT_ID('dbo.sp_DBPermissions') IS NULL 4 | EXEC sp_executesql N'CREATE PROCEDURE dbo.sp_DBPermissions AS PRINT ''Stub'';' 5 | GO 6 | /********************************************************************************************* 7 | sp_DBPermissions V7.0 8 | Kenneth Fisher 9 | 10 | http://www.sqlstudies.com 11 | https://github.com/sqlstudent144/SQL-Server-Scripts/blob/master/sp_DBPermissions.sql 12 | 13 | This stored procedure returns 3 data sets. The first dataset is the list of database 14 | principals, the second is role membership, and the third is object and database level 15 | permissions. 16 | 17 | The final 2 columns of each query are "Un-Do"/"Do" scripts. For example removing a member 18 | from a role or adding them to a role. I am fairly confident in the role scripts, however, 19 | the scripts in the database principals query and database/object permissions query are 20 | works in progress. In particular certificates, keys and column level permissions are not 21 | scripted out. Also while the scripts have worked flawlessly on the systems I've tested 22 | them on, these systems are fairly similar when it comes to security so I can't say that 23 | in a more complicated system there won't be the odd bug. 24 | 25 | Standard disclaimer: You use scripts off of the web at your own risk. I fully expect this 26 | script to work without issue but I've been known to be wrong before. 27 | 28 | Parameters: 29 | @DBName 30 | If NULL use the current database, otherwise give permissions based on the parameter. 31 | 32 | There is a special case where you pass in ALL to the @DBName. In this case the SP 33 | will loop through (yes I'm using a cursor) all of the DBs in sysdatabases and run 34 | the queries into temp tables before returning the results. WARNINGS: If you use 35 | this option and have a large number of databases it will be SLOW. If you use this 36 | option and don't specify any other parameters (say a specific @Principal) and have 37 | even a medium number of databases it will be SLOW. Also the undo/do scripts do 38 | not have USE statements in them so please take that into account. 39 | @Principal 40 | If NOT NULL then all three queries only pull for that database principal. @Principal 41 | is a pattern check. The queries check for any row where the passed in value exists. 42 | It uses the pattern '%' + @Principal + '%' 43 | @Role 44 | If NOT NULL then the roles query will pull members of the role. If it is NOT NULL and 45 | @DBName is NULL then DB principal and permissions query will pull the principal row for 46 | the role and the permissions for the role. @Role is a pattern check. The queries 47 | check for any row where the passed in value exists. It uses the pattern '%' + @Role + 48 | '%' 49 | @Type 50 | If NOT NULL then all three queries will only pull principals of that type. 51 | S = SQL login 52 | U = Windows login 53 | G = Windows group 54 | R = Server role 55 | C = Login mapped to a certificate 56 | K = Login mapped to an asymmetric key 57 | @ObjectName 58 | If NOT NULL then the third query will display permissions specific to the object 59 | specified and the first two queries will display only those users with those specific 60 | permissions. Unfortunately at this point only objects in sys.all_objects will work. 61 | This parameter uses the pattern '%' + @ObjectName + '%' 62 | @Permission 63 | If NOT NULL then the third query will display only permissions that match what is in 64 | the parameter. The first two queries will display only those users with that specific 65 | permission. 66 | @LoginName 67 | If NOT NULL then each of the queries will only pull back database principals that 68 | have the same SID as a login that matches the pattern '%' + @LoginName + '%' 69 | @UseLikeSearch 70 | When this is set to 1 (the default) then the search parameters will use LIKE (and 71 | %'s will be added around the @Principal, @Role, @ObjectName, and @LoginName parameters). 72 | When set to 0 searchs will use =. 73 | @IncludeMSShipped 74 | When this is set to 1 (the default) then all principals will be included. When set 75 | to 0 the fixed server roles and SA and Public principals will be excluded. 76 | @CopyTo 77 | If @Principal is filled in then the value in @CopyTo is used in the drop and create 78 | scripts instead of @Principal. In the case of the CREATE USER statement @CopyTo 79 | also replaces the name of the server level principal, however it does not affect the 80 | default schema name. 81 | NOTE: It is very important to note that if @CopyTo is not a valid name the drop/create 82 | scripts may fail. 83 | @DropTempTables 84 | When this is set to 1 (the default) the temp tables used are dropped. If it's 0 85 | then the tempt ables are kept for references after the code has finished. 86 | The temp tables are: 87 | ##DBPrincipals 88 | ##DBRoles 89 | ##DBPermissions 90 | @ShowOrphans 91 | By default this is 0. If it is 1 then it shows only orphaned principals and scripts to fix them. 92 | Note: This option is 2012 and up only. 93 | @Output 94 | What type of output is desired. 95 | Default - Either 'Default' or it doesn't match any of the allowed values then the SP 96 | will return the standard 3 outputs. 97 | None - No output at all. Usually used if you keeping the temp tables to do your own 98 | reporting. 99 | CreateOnly - Only return the create scripts where they aren't NULL. 100 | DropOnly - Only return the drop scripts where they aren't NULL. 101 | ScriptOnly - Return drop and create scripts where they aren't NULL. 102 | Report - Returns one output with one row per principal and a comma delimited list of 103 | roles the principal is a member of and a comma delimited list of the 104 | individual permissions they have. 105 | @Print 106 | Defaults to 0, but if a 1 is passed in then the queries are not run but printed 107 | out instead. This is primarily for debugging. 108 | 109 | Data is ordered as follows 110 | 1st result set: DBPrincipal 111 | 2nd result set: RoleName, UserName if the parameter @Role is used else 112 | UserName, RoleName 113 | 3rd result set: If @ObjectName is used then DBName, SchemaName, ObjectName, Grantee_Name, permission_name 114 | otherwise DBName, GranteeName, SchemaName, ObjectName, permission_name 115 | 116 | -- V2.0 117 | -- 8/18/2013 – Create a stub if the SP doesn’t exist, then always do an alter 118 | -- 8/18/2013 - Use instance collation for all concatenated strings 119 | -- 9/04/2013 - dbo can’t be added or removed from roles. Don’t script. 120 | -- 9/04/2013 - Fix scripts for schema level permissions. 121 | -- 9/04/2013 – Change print option to show values of variables not the 122 | -- Variable names. 123 | -- V3.0 124 | -- 10/5/2013 - Added @Type parameter to pull only principals of a given type. 125 | -- 10/10/2013 - Added @ObjectName parameter to pull only permissions for a given object. 126 | -- V4.0 127 | -- 11/18/2013 - Added parameter names to sp_addrolemember and sp_droprolemember. 128 | -- 11/19/2013 - Added an ORDER BY to each of the result sets. See above for details. 129 | -- 01/04/2014 - Add an ALL option to the DBName parameter. 130 | -- V4.1 131 | -- 02/07/2014 - Fix bug scripting permissions where object and schema have the same ID 132 | -- 02/15/2014 - Add support for user defined types 133 | -- 02/15/2014 - Fix: Add schema to object GRANT and REVOKE scripts 134 | -- V5.0 135 | -- 4/29/2014 - Fix: Removed extra print statements 136 | -- 4/29/2014 - Fix: Added SET NOCOUNT ON 137 | -- 4/29/2014 - Added a USE statement to the scripts when using the @DBName = 'All' option 138 | -- 5/01/2014 - Added @Permission parameter 139 | -- 5/14/2014 - Added additional permissions based on information from Kendal Van Dyke's 140 | post http://www.kendalvandyke.com/2014/02/using-sysobjects-when-scripting.html 141 | -- 6/02/2014 - Added @LoginName parameter 142 | -- V5.5 143 | -- 7/15/2014 - Bunch of changes recommended by @SQLSoldier/"https://twitter.com/SQLSoldier" 144 | Primarily changing the strings to unicode & adding QUOTENAME in a few places 145 | I'd missed it. 146 | -- V6.0 147 | -- 10/19/2014 - Add @UserLikeSearch and @IncludeMSShipped parameters. 148 | -- 11/29/2016 - Fixed permissions for symmetric keys 149 | -- Found and fixed by Brenda Grossnickle 150 | -- 03/25/2017 - Move SID towards the end of the first output so the more important 151 | -- columns are closer to the front. 152 | -- 03/25/2017 - Add IF Exists to drop and create user scripts 153 | -- 03/25/2017 - Remove create/drop user scripts for guest, public, sys and INFORMATION_SCHEMA 154 | -- 03/25/2017 - Add @DropTempTables to keep the temp tables after the SP is run. 155 | -- 03/26/2017 - Add @Output to allow different types of output. 156 | -- V6.1 157 | -- 06/25/2018 - Skip snapshots 158 | -- 02/13/2019 - Fix to direct permissions column in the report output to show schema permissions correctly 159 | -- 04/05/2019 - For 'All' DB parameter fix to only look at ONLINE and EMERGENCY DBs. 160 | -- 06/04/2019 - Add SchemaName and permission_name to the order of the third data set. 161 | This makes the order more reliable. 162 | -- 06/04/2019 - Begin cleanup of the dynamic SQL (specifically removing carrage return & extra quotes) 163 | -- 06/04/2019 - Fix @print where part of the permissions query was being truncated. 164 | -- V6.2 165 | -- 07/15/2022 - Add @CopyTo parameter to handle requests like "Please copy permissions from x to y." 166 | -- 07/15/2022 - Clean up dyanmic formatting to remove most of the N' and "' + CHAR(13) + " strings. 167 | -- 07/31/2022 - Formatting: Replace tabs with spaces 168 | -- 01/14/2023 - Fixes for unicode strings 169 | -- V7.0 170 | -- 08/15/2023 - Add orphan functionality with @ShowOrphans parameter. 171 | *********************************************************************************************/ 172 | 173 | ALTER PROCEDURE dbo.sp_DBPermissions 174 | ( 175 | @DBName sysname = NULL, 176 | @Principal sysname = NULL, 177 | @Role sysname = NULL, 178 | @Type nvarchar(30) = NULL, 179 | @ObjectName sysname = NULL, 180 | @Permission sysname = NULL, 181 | @LoginName sysname = NULL, 182 | @UseLikeSearch bit = 1, 183 | @IncludeMSShipped bit = 1, 184 | @CopyTo sysname = NULL, 185 | @DropTempTables bit = 1, 186 | @ShowOrphans bit = 0, 187 | @Output varchar(30) = 'Default', 188 | @Print bit = 0 189 | ) 190 | AS 191 | 192 | SET NOCOUNT ON 193 | 194 | DECLARE @Collation nvarchar(75) 195 | SET @Collation = N' COLLATE ' + CAST(SERVERPROPERTY('Collation') AS nvarchar(50)) 196 | 197 | DECLARE @sql nvarchar(max) 198 | DECLARE @sql2 nvarchar(max) 199 | DECLARE @ObjectList nvarchar(max) 200 | DECLARE @ObjectList2 nvarchar(max) 201 | DECLARE @use nvarchar(500) 202 | DECLARE @AllDBNames sysname 203 | 204 | IF @DBName IS NULL OR @DBName = N'All' 205 | BEGIN 206 | SET @use = '' 207 | IF @DBName IS NULL 208 | SET @DBName = DB_NAME() 209 | --SELECT @DBName = db_name(database_id) 210 | --FROM sys.dm_exec_requests 211 | --WHERE session_id = @@SPID 212 | END 213 | ELSE 214 | -- IF EXISTS (SELECT 1 FROM sys.databases WHERE name = @DBName) 215 | IF db_id(@DBName) IS NOT NULL 216 | SET @use = N'USE ' + QUOTENAME(@DBName) + N';' + NCHAR(13) 217 | ELSE 218 | BEGIN 219 | RAISERROR (N'%s is not a valid database name.', 220 | 16, 221 | 1, 222 | @DBName) 223 | RETURN 224 | END 225 | 226 | DECLARE @LikeOperator nvarchar(4) 227 | 228 | IF @UseLikeSearch = 1 229 | SET @LikeOperator = N'LIKE' 230 | ELSE 231 | SET @LikeOperator = N'=' 232 | 233 | IF @UseLikeSearch = 1 234 | BEGIN 235 | IF LEN(ISNULL(@Principal,'')) > 0 236 | SET @Principal = N'%' + @Principal + N'%' 237 | 238 | IF LEN(ISNULL(@Role,'')) > 0 239 | SET @Role = N'%' + @Role + N'%' 240 | 241 | IF LEN(ISNULL(@ObjectName,'')) > 0 242 | SET @ObjectName = N'%' + @ObjectName + N'%' 243 | 244 | IF LEN(ISNULL(@LoginName,'')) > 0 245 | SET @LoginName = N'%' + @LoginName + N'%' 246 | END 247 | 248 | IF (@Principal IS NULL AND @CopyTo IS NOT NULL) OR LEN(@CopyTo) = 0 249 | SET @CopyTo = NULL 250 | 251 | IF @Print = 1 AND @DBName = N'All' 252 | BEGIN 253 | PRINT 'DECLARE @AllDBNames sysname' 254 | PRINT 'SET @AllDBNames = ''master''' 255 | PRINT '' 256 | END 257 | --========================================================================= 258 | -- Database Principals 259 | SET @sql = 260 | N'SELECT ' + CASE WHEN @DBName = 'All' THEN N'@AllDBNames' ELSE N'N''' + @DBName + N'''' END + N' AS DBName, 261 | DBPrincipals.principal_id AS DBPrincipalId, DBPrincipals.name AS DBPrincipal, SrvPrincipals.name AS SrvPrincipal, 262 | DBPrincipals.type, DBPrincipals.type_desc, DBPrincipals.default_schema_name, DBPrincipals.create_date, 263 | DBPrincipals.modify_date, DBPrincipals.is_fixed_role, 264 | Authorizations.name AS RoleAuthorization, DBPrincipals.sid, 265 | CASE WHEN DBPrincipals.is_fixed_role = 0 AND DBPrincipals.name NOT IN (''dbo'',''guest'', ''INFORMATION_SCHEMA'', ''public'', ''sys'') THEN ' + NCHAR(13) + 266 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' + NCHAR(13) ELSE N'' END + 267 | N' ''IF DATABASE_PRINCIPAL_ID(N'''''' + ' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'DBPrincipals.name') + ' + '''''') IS NOT NULL '' + 268 | ''DROP '' + CASE DBPrincipals.[type] WHEN ''C'' THEN NULL 269 | WHEN ''K'' THEN NULL 270 | WHEN ''R'' THEN ''ROLE'' 271 | WHEN ''A'' THEN ''APPLICATION ROLE'' 272 | ELSE ''USER'' END + 273 | '' ''+QUOTENAME(' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'DBPrincipals.name') + '' + @Collation + N') + '';'' ELSE NULL END AS DropScript, 274 | CASE WHEN DBPrincipals.is_fixed_role = 0 AND DBPrincipals.name NOT IN (''dbo'',''guest'', ''INFORMATION_SCHEMA'', ''public'', ''sys'') THEN ' + NCHAR(13) + 275 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' +NCHAR(13) ELSE N'' END + 276 | N' ''IF DATABASE_PRINCIPAL_ID(N'''''' + ' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'DBPrincipals.name') + ' + '''''') IS NULL '' + 277 | ''CREATE '' + CASE DBPrincipals.[type] WHEN ''C'' THEN NULL 278 | WHEN ''K'' THEN NULL 279 | WHEN ''R'' THEN ''ROLE'' 280 | WHEN ''A'' THEN ''APPLICATION ROLE'' 281 | ELSE ''USER'' END + 282 | '' ''+QUOTENAME(' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'DBPrincipals.name') + '' + @Collation + N') END + 283 | CASE WHEN DBPrincipals.[type] = ''R'' THEN 284 | ISNULL('' AUTHORIZATION ''+QUOTENAME(Authorizations.name' + @Collation + N'),'''') 285 | WHEN DBPrincipals.[type] = ''A'' THEN 286 | '''' 287 | WHEN DBPrincipals.[type] NOT IN (''C'',''K'') THEN 288 | ISNULL('' FOR LOGIN '' + 289 | QUOTENAME(' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'SrvPrincipals.name') + '' + @Collation + N'),'' WITHOUT LOGIN'') + 290 | ISNULL('' WITH DEFAULT_SCHEMA = ''+ 291 | QUOTENAME(DBPrincipals.default_schema_name' + @Collation + N'),'''') 292 | ELSE '''' 293 | END + '';'' + 294 | CASE WHEN DBPrincipals.[type] NOT IN (''C'',''K'',''R'',''A'') 295 | AND SrvPrincipals.name IS NULL 296 | AND DBPrincipals.sid IS NOT NULL 297 | AND DBPrincipals.sid NOT IN (0x00, 0x01) 298 | THEN '' -- Possible missing server principal'' 299 | ELSE '''' END 300 | AS CreateScript' + 301 | CASE WHEN SERVERPROPERTY('ProductVersion') >= '12' AND @ShowOrphans = 1 THEN N', 302 | CASE WHEN DBPrincipals.name = ''dbo'' THEN ''NULL'' ELSE 303 | ''IF NOT EXISTS (SELECT * FROM sys.server_principals WHERE name = N'' + QUOTENAME(DBPrincipals.name,'''''''') + '') ' + 304 | N'CREATE LOGIN '' + QUOTENAME(DBPrincipals.name) + 305 | CASE WHEN DBPrincipals.type = (''S'') THEN '' WITH PASSWORD = '''''''', '' + 306 | '' SID = '' + CONVERT(varchar(85), DBPrincipals.sid, 1) 307 | WHEN DBPrincipals.type IN (''U'',''G'') THEN '' FROM WINDOWS '' 308 | ELSE '''' END END AS CreateLogin, ' + 309 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' +NCHAR(13) ELSE N'' END + 310 | N' CASE WHEN DBPrincipals.name = ''dbo'' THEN ''EXEC sp_changedbowner '''''''';'' ELSE 311 | ''ALTER USER '' + QUOTENAME(DBPrincipals.name) + '' WITH LOGIN = '' + QUOTENAME(DBPrincipals.name) + '';'' END AS AlterUser' ELSE '' END + ' 312 | FROM sys.database_principals DBPrincipals 313 | LEFT OUTER JOIN sys.database_principals Authorizations 314 | ON DBPrincipals.owning_principal_id = Authorizations.principal_id 315 | LEFT OUTER JOIN sys.server_principals SrvPrincipals 316 | ON DBPrincipals.sid = SrvPrincipals.sid 317 | AND DBPrincipals.sid NOT IN (0x00, 0x01) 318 | WHERE 1=1 ' 319 | 320 | IF SERVERPROPERTY('ProductVersion') >= '12' AND @ShowOrphans = 1 321 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.authentication_type_desc <> ''NONE'' 322 | AND SrvPrincipals.principal_id IS NULL 323 | AND DBPrincipals.sid NOT IN (0x00, 0x01)' 324 | 325 | IF LEN(ISNULL(@Principal,@Role)) > 0 326 | IF @Print = 1 327 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.name ' + @LikeOperator + N' N' + 328 | ISNULL(QUOTENAME(@Principal,N''''),QUOTENAME(@Role,'''')) 329 | ELSE 330 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.name ' + @LikeOperator + N' ISNULL(@Principal,@Role) ' 331 | 332 | IF LEN(@Type) > 0 333 | IF @Print = 1 334 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.type ' + @LikeOperator + N' N' + QUOTENAME(@Type,'''') 335 | ELSE 336 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.type ' + @LikeOperator + N' @Type' 337 | 338 | IF LEN(@LoginName) > 0 339 | IF @Print = 1 340 | SET @sql = @sql + NCHAR(13) + N' AND SrvPrincipals.name ' + @LikeOperator + N' N' + QUOTENAME(@LoginName,'''') 341 | ELSE 342 | SET @sql = @sql + NCHAR(13) + N' AND SrvPrincipals.name ' + @LikeOperator + N' @LoginName' 343 | 344 | IF LEN(@ObjectName) > 0 345 | BEGIN 346 | SET @sql = @sql + NCHAR(13) + 347 | N' AND EXISTS (SELECT 1 ' + NCHAR(13) + 348 | N' FROM sys.all_objects [Objects] ' + NCHAR(13) + 349 | N' INNER JOIN sys.database_permissions Permission ' + NCHAR(13) + 350 | N' ON Permission.major_id = [Objects].object_id ' + NCHAR(13) + 351 | N' WHERE Permission.major_id = [Objects].object_id ' + NCHAR(13) + 352 | N' AND Permission.grantee_principal_id = DBPrincipals.principal_id ' + NCHAR(13) 353 | 354 | IF @Print = 1 355 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' N' + QUOTENAME(@ObjectName,'''') 356 | ELSE 357 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' @ObjectName' 358 | 359 | SET @sql = @sql + N')' 360 | END 361 | 362 | IF LEN(@Permission) > 0 363 | BEGIN 364 | SET @sql = @sql + NCHAR(13) + 365 | N' AND EXISTS (SELECT 1 ' + NCHAR(13) + 366 | N' FROM sys.database_permissions Permission ' + NCHAR(13) + 367 | N' WHERE Permission.grantee_principal_id = DBPrincipals.principal_id ' + NCHAR(13) 368 | 369 | IF @Print = 1 370 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' N' + QUOTENAME(@Permission,'''') 371 | ELSE 372 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' @Permission' 373 | 374 | SET @sql = @sql + N')' 375 | END 376 | 377 | IF @IncludeMSShipped = 0 378 | SET @sql = @sql + NCHAR(13) + N' AND DBPrincipals.is_fixed_role = 0 ' + NCHAR(13) + 379 | ' AND DBPrincipals.name NOT IN (''dbo'',''public'',''INFORMATION_SCHEMA'',''guest'',''sys'') ' 380 | 381 | IF @Print = 1 382 | BEGIN 383 | PRINT N'-- Database Principals' 384 | PRINT CAST(@sql AS nvarchar(max)) 385 | PRINT '' -- Spacing before the next print 386 | PRINT '' 387 | END 388 | ELSE 389 | BEGIN 390 | IF object_id('tempdb..##DBPrincipals') IS NOT NULL 391 | DROP TABLE ##DBPrincipals 392 | 393 | -- Create temp table to store the data in 394 | CREATE TABLE ##DBPrincipals ( 395 | DBName sysname NULL, 396 | DBPrincipalId int NULL, 397 | DBPrincipal sysname NULL, 398 | SrvPrincipal sysname NULL, 399 | type char(1) NULL, 400 | type_desc nchar(60) NULL, 401 | default_schema_name sysname NULL, 402 | create_date datetime NULL, 403 | modify_date datetime NULL, 404 | is_fixed_role bit NULL, 405 | RoleAuthorization sysname NULL, 406 | sid varbinary(85) NULL, 407 | DropScript nvarchar(max) NULL, 408 | CreateScript nvarchar(max) NULL 409 | ) 410 | 411 | IF SERVERPROPERTY('ProductVersion') >= '12' AND @ShowOrphans = 1 412 | BEGIN 413 | ALTER TABLE ##DBPrincipals ADD CreateLogin nvarchar(max) NULL 414 | ALTER TABLE ##DBPrincipals ADD AlterUser nvarchar(max) NULL 415 | END 416 | 417 | SET @sql = @use + N'INSERT INTO ##DBPrincipals ' + NCHAR(13) + @sql 418 | 419 | IF @DBName = 'All' 420 | BEGIN 421 | -- Declare a READ_ONLY cursor to loop through the databases 422 | DECLARE cur_DBList CURSOR 423 | READ_ONLY 424 | FOR SELECT name FROM sys.databases 425 | WHERE state IN (0,5) 426 | AND source_database_id IS NULL 427 | ORDER BY name 428 | 429 | OPEN cur_DBList 430 | 431 | FETCH NEXT FROM cur_DBList INTO @AllDBNames 432 | WHILE (@@fetch_status <> -1) 433 | BEGIN 434 | IF (@@fetch_status <> -2) 435 | BEGIN 436 | SET @sql2 = N'USE ' + QUOTENAME(@AllDBNames) + N';' + NCHAR(13) + @sql 437 | EXEC sp_executesql @sql2, 438 | N'@Principal sysname, @Role sysname, @Type nvarchar(30), @ObjectName sysname, 439 | @AllDBNames sysname, @Permission sysname, @LoginName sysname', 440 | @Principal, @Role, @Type, @ObjectName, @AllDBNames, @Permission, @LoginName 441 | -- PRINT @sql2 442 | END 443 | FETCH NEXT FROM cur_DBList INTO @AllDBNames 444 | END 445 | 446 | CLOSE cur_DBList 447 | DEALLOCATE cur_DBList 448 | END 449 | ELSE 450 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30), 451 | @ObjectName sysname, @Permission sysname, @LoginName sysname', 452 | @Principal, @Role, @Type, @ObjectName, @Permission, @LoginName 453 | END 454 | --========================================================================= 455 | -- Database Role Members 456 | IF NOT (SERVERPROPERTY('ProductVersion') >= '12' AND @ShowOrphans = 1) 457 | BEGIN 458 | SET @sql = 459 | N'SELECT ' + CASE WHEN @DBName = 'All' THEN N'@AllDBNames' ELSE N'N''' + @DBName + N'''' END + N' AS DBName, 460 | Users.principal_id AS UserPrincipalId, Users.name AS UserName, Roles.name AS RoleName, ' + NCHAR(13) + 461 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' + NCHAR(13) ELSE N'' END + 462 | N' CASE WHEN Users.is_fixed_role = 0 AND Users.name <> ''dbo'' THEN 463 | ''EXEC sp_droprolemember @rolename = N''+QUOTENAME(Roles.name' + @Collation + 464 | N','''''''')+'', @membername = N''+QUOTENAME(CASE WHEN Users.name = ''dbo'' THEN NULL 465 | ELSE ' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'Users.name') + ' END' + @Collation + 466 | N','''''''')+'';'' END AS DropScript, ' + NCHAR(13) + 467 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' + NCHAR(13) ELSE N'' END + 468 | N' CASE WHEN Users.is_fixed_role = 0 AND Users.name <> ''dbo'' THEN 469 | ''EXEC sp_addrolemember @rolename = N''+QUOTENAME(Roles.name' + @Collation + 470 | N','''''''')+'', @membername = N''+QUOTENAME(CASE WHEN Users.name = ''dbo'' THEN NULL 471 | ELSE ' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'Users.name') + ' END' + @Collation + 472 | N','''''''')+'';'' END AS AddScript 473 | FROM sys.database_role_members RoleMembers 474 | JOIN sys.database_principals Users 475 | ON RoleMembers.member_principal_id = Users.principal_id 476 | JOIN sys.database_principals Roles 477 | ON RoleMembers.role_principal_id = Roles.principal_id 478 | WHERE 1=1 ' 479 | 480 | IF LEN(ISNULL(@Principal,'')) > 0 481 | IF @Print = 1 482 | SET @sql = @sql + NCHAR(13) + N' AND Users.name ' + @LikeOperator + N' N'+QUOTENAME(@Principal,'''') 483 | ELSE 484 | SET @sql = @sql + NCHAR(13) + N' AND Users.name ' + @LikeOperator + N' @Principal' 485 | 486 | IF LEN(ISNULL(@Role,'')) > 0 487 | IF @Print = 1 488 | SET @sql = @sql + NCHAR(13) + N' AND Roles.name ' + @LikeOperator + N' N'+QUOTENAME(@Role,'''') 489 | ELSE 490 | SET @sql = @sql + NCHAR(13) + N' AND Roles.name ' + @LikeOperator + N' @Role' 491 | 492 | IF LEN(@Type) > 0 493 | IF @Print = 1 494 | SET @sql = @sql + NCHAR(13) + N' AND Users.type ' + @LikeOperator + N' N' + QUOTENAME(@Type,'''') 495 | ELSE 496 | SET @sql = @sql + NCHAR(13) + N' AND Users.type ' + @LikeOperator + N' @Type' 497 | 498 | IF LEN(@LoginName) > 0 499 | BEGIN 500 | SET @sql = @sql + NCHAR(13) + 501 | N' AND EXISTS (SELECT 1 502 | FROM sys.server_principals SrvPrincipals 503 | WHERE Users.sid NOT IN (0x00, 0x01) 504 | AND SrvPrincipals.sid = Users.sid 505 | AND Users.type NOT IN (''R'') ' + NCHAR(13) 506 | IF @Print = 1 507 | SET @sql = @sql + NCHAR(13) + ' AND SrvPrincipals.name ' + @LikeOperator + N' N' + QUOTENAME(@LoginName,'''') 508 | ELSE 509 | SET @sql = @sql + NCHAR(13) + ' AND SrvPrincipals.name ' + @LikeOperator + N' @LoginName' 510 | 511 | SET @sql = @sql + N')' 512 | END 513 | 514 | IF LEN(@ObjectName) > 0 515 | BEGIN 516 | SET @sql = @sql + NCHAR(13) + 517 | N' AND EXISTS (SELECT 1 518 | FROM sys.all_objects [Objects] 519 | INNER JOIN sys.database_permissions Permission 520 | ON Permission.major_id = [Objects].object_id 521 | WHERE Permission.major_id = [Objects].object_id 522 | AND Permission.grantee_principal_id = Users.principal_id ' + NCHAR(13) 523 | 524 | IF @Print = 1 525 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' N' + QUOTENAME(@ObjectName,'''') 526 | ELSE 527 | SET @sql = @sql + N' AND [Objects].name ' + @LikeOperator + N' @ObjectName' 528 | 529 | SET @sql = @sql + N')' 530 | END 531 | 532 | IF LEN(@Permission) > 0 533 | BEGIN 534 | SET @sql = @sql + NCHAR(13) + 535 | N' AND EXISTS (SELECT 1 536 | FROM sys.database_permissions Permission 537 | WHERE Permission.grantee_principal_id = Users.principal_id ' + NCHAR(13) 538 | 539 | IF @Print = 1 540 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' N' + QUOTENAME(@Permission,'''') 541 | ELSE 542 | SET @sql = @sql + N' AND Permission.permission_name ' + @LikeOperator + N' @Permission' 543 | 544 | SET @sql = @sql + N')' 545 | END 546 | 547 | IF @IncludeMSShipped = 0 548 | SET @sql = @sql + NCHAR(13) + N' AND Users.is_fixed_role = 0 ' + NCHAR(13) + 549 | ' AND Users.name NOT IN (''dbo'',''public'',''INFORMATION_SCHEMA'',''guest'',''sys'') ' 550 | 551 | IF @Print = 1 552 | BEGIN 553 | PRINT N'-- Database Role Members' 554 | PRINT CAST(@sql AS nvarchar(max)) 555 | PRINT '' -- Spacing before the next print 556 | PRINT '' 557 | END 558 | ELSE 559 | BEGIN 560 | IF object_id('tempdb..##DBRoles') IS NOT NULL 561 | DROP TABLE ##DBRoles 562 | 563 | -- Create temp table to store the data in 564 | CREATE TABLE ##DBRoles ( 565 | DBName sysname NULL, 566 | UserPrincipalId int NULL, 567 | UserName sysname NULL, 568 | RoleName sysname NULL, 569 | DropScript nvarchar(max) NULL, 570 | AddScript nvarchar(max) NULL 571 | ) 572 | 573 | SET @sql = @use + NCHAR(13) + 'INSERT INTO ##DBRoles ' + NCHAR(13) + @sql 574 | 575 | IF @DBName = 'All' 576 | BEGIN 577 | -- Declare a READ_ONLY cursor to loop through the databases 578 | DECLARE cur_DBList CURSOR 579 | READ_ONLY 580 | FOR SELECT name FROM sys.databases 581 | WHERE state IN (0,5) 582 | AND source_database_id IS NULL 583 | ORDER BY name 584 | 585 | OPEN cur_DBList 586 | 587 | FETCH NEXT FROM cur_DBList INTO @AllDBNames 588 | WHILE (@@fetch_status <> -1) 589 | BEGIN 590 | IF (@@fetch_status <> -2) 591 | BEGIN 592 | SET @sql2 = 'USE ' + QUOTENAME(@AllDBNames) + ';' + NCHAR(13) + @sql 593 | EXEC sp_executesql @sql2, 594 | N'@Principal sysname, @Role sysname, @Type nvarchar(30), @ObjectName sysname, 595 | @AllDBNames sysname, @Permission sysname, @LoginName sysname', 596 | @Principal, @Role, @Type, @ObjectName, @AllDBNames, @Permission, @LoginName 597 | -- PRINT @sql2 598 | END 599 | FETCH NEXT FROM cur_DBList INTO @AllDBNames 600 | END 601 | 602 | CLOSE cur_DBList 603 | DEALLOCATE cur_DBList 604 | END 605 | ELSE 606 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30), 607 | @ObjectName sysname, @Permission sysname, @LoginName sysname', 608 | @Principal, @Role, @Type, @ObjectName, @Permission, @LoginName 609 | END 610 | END 611 | --========================================================================= 612 | -- Database & object Permissions 613 | IF NOT (SERVERPROPERTY('ProductVersion') >= '12' AND @ShowOrphans = 1) 614 | BEGIN 615 | SET @ObjectList = 616 | N'; WITH ObjectList AS ( 617 | SELECT NULL AS SchemaName , 618 | name ' + @Collation + ' AS name, 619 | database_id AS id, 620 | ''DATABASE'' AS class_desc, 621 | '''' AS class 622 | FROM master.sys.databases 623 | UNION ALL 624 | SELECT SCHEMA_NAME(sys.all_objects.schema_id) ' + @Collation + N' AS SchemaName, 625 | name ' + @Collation + N' AS name, 626 | object_id AS id, 627 | ''OBJECT_OR_COLUMN'' AS class_desc, 628 | ''OBJECT'' AS class 629 | FROM sys.all_objects 630 | UNION ALL 631 | SELECT name ' + @Collation + N' AS SchemaName, 632 | NULL AS name, 633 | schema_id AS id, 634 | ''SCHEMA'' AS class_desc, 635 | ''SCHEMA'' AS class 636 | FROM sys.schemas 637 | UNION ALL 638 | SELECT NULL AS SchemaName, 639 | name ' + @Collation + N' AS name, 640 | principal_id AS id, 641 | ''DATABASE_PRINCIPAL'' AS class_desc, 642 | CASE type_desc 643 | WHEN ''APPLICATION_ROLE'' THEN ''APPLICATION ROLE'' 644 | WHEN ''DATABASE_ROLE'' THEN ''ROLE'' 645 | ELSE ''USER'' END AS class 646 | FROM sys.database_principals 647 | UNION ALL 648 | SELECT SCHEMA_NAME(schema_id) ' + @Collation + N' AS SchemaName, 649 | name ' + @Collation + N' AS name, 650 | xml_collection_id AS id, 651 | ''XML_SCHEMA_COLLECTION'' AS class_desc, 652 | ''XML SCHEMA COLLECTION'' AS class 653 | FROM sys.xml_schema_collections 654 | UNION ALL 655 | SELECT NULL AS SchemaName, 656 | name ' + @Collation + N' AS name, 657 | message_type_id AS id, 658 | ''MESSAGE_TYPE'' AS class_desc, 659 | ''MESSAGE TYPE'' AS class 660 | FROM sys.service_message_types 661 | UNION ALL 662 | SELECT NULL AS SchemaName, 663 | name ' + @Collation + N' AS name, 664 | assembly_id AS id, 665 | ''ASSEMBLY'' AS class_desc, 666 | ''ASSEMBLY'' AS class 667 | FROM sys.assemblies 668 | UNION ALL' 669 | 670 | SET @ObjectList2 = N' 671 | SELECT SCHEMA_NAME(sys.types.schema_id) ' + @Collation + N' AS SchemaName, 672 | name ' + @Collation + N' AS name, 673 | user_type_id AS id, 674 | ''TYPE'' AS class_desc, 675 | ''TYPE'' AS class 676 | FROM sys.types 677 | UNION ALL 678 | SELECT NULL AS SchemaName, 679 | name ' + @Collation + N' AS name, 680 | service_contract_id AS id, 681 | ''SERVICE_CONTRACT'' AS class_desc, 682 | ''CONTRACT'' AS class 683 | FROM sys.service_contracts 684 | UNION ALL 685 | SELECT NULL AS SchemaName, 686 | name ' + @Collation + N' AS name, 687 | service_id AS id, 688 | ''SERVICE'' AS class_desc, 689 | ''SERVICE'' AS class 690 | FROM sys.services 691 | UNION ALL 692 | SELECT NULL AS SchemaName, 693 | name ' + @Collation + N' AS name, 694 | remote_service_binding_id AS id, 695 | ''REMOTE_SERVICE_BINDING'' AS class_desc, 696 | ''REMOTE SERVICE BINDING'' AS class 697 | FROM sys.remote_service_bindings 698 | UNION ALL 699 | SELECT NULL AS SchemaName, 700 | name ' + @Collation + N' AS name, 701 | route_id AS id, 702 | ''ROUTE'' AS class_desc, 703 | ''ROUTE'' AS class 704 | FROM sys.routes 705 | UNION ALL 706 | SELECT NULL AS SchemaName, 707 | name ' + @Collation + N' AS name, 708 | fulltext_catalog_id AS id, 709 | ''FULLTEXT_CATALOG'' AS class_desc, 710 | ''FULLTEXT CATALOG'' AS class 711 | FROM sys.fulltext_catalogs 712 | UNION ALL 713 | SELECT NULL AS SchemaName, 714 | name ' + @Collation + N' AS name, 715 | symmetric_key_id AS id, 716 | ''SYMMETRIC_KEYS'' AS class_desc, 717 | ''SYMMETRIC KEY'' AS class 718 | FROM sys.symmetric_keys 719 | UNION ALL 720 | SELECT NULL AS SchemaName, 721 | name ' + @Collation + N' AS name, 722 | certificate_id AS id, 723 | ''CERTIFICATE'' AS class_desc, 724 | ''CERTIFICATE'' AS class 725 | FROM sys.certificates 726 | UNION ALL 727 | SELECT NULL AS SchemaName, 728 | name ' + @Collation + N' AS name, 729 | asymmetric_key_id AS id, 730 | ''ASYMMETRIC_KEY'' AS class_desc, 731 | ''ASYMMETRIC KEY'' AS class 732 | FROM sys.asymmetric_keys 733 | ) ' + NCHAR(13) 734 | 735 | SET @sql = 736 | N'SELECT ' + CASE WHEN @DBName = 'All' THEN N'@AllDBNames' ELSE N'N''' + @DBName + N'''' END + N' AS DBName, 737 | Grantee.principal_id AS GranteePrincipalId, Grantee.name AS GranteeName, Grantor.name AS GrantorName, 738 | Permission.class_desc, Permission.permission_name, 739 | ObjectList.name + CASE WHEN Columns.name IS NOT NULL THEN '' ('' + Columns.name + '')'' ELSE '''' END AS ObjectName, 740 | ObjectList.SchemaName, 741 | Permission.state_desc, 742 | CASE WHEN Grantee.is_fixed_role = 0 AND Grantee.name <> ''dbo'' THEN ' + NCHAR(13) + 743 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' + NCHAR(13) ELSE N'' END + 744 | N' ''REVOKE '' + 745 | CASE WHEN Permission.[state] = ''W'' THEN ''GRANT OPTION FOR '' ELSE '''' END + 746 | '' '' + Permission.permission_name' + @Collation + N' + 747 | CASE WHEN Permission.major_id <> 0 THEN '' ON '' + 748 | ObjectList.class + ''::'' + 749 | ISNULL(QUOTENAME(ObjectList.SchemaName),'''') + 750 | CASE WHEN ObjectList.SchemaName + ObjectList.name IS NULL THEN '''' ELSE ''.'' END + 751 | ISNULL(QUOTENAME(ObjectList.name),'''') + ISNULL('' (''+ QUOTENAME(Columns.name) + '')'','''') 752 | ' + @Collation + ' + '' '' ELSE '''' END + 753 | '' FROM '' + QUOTENAME(' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'Grantee.name') + '' + @Collation + N') + ''; '' END AS RevokeScript, 754 | CASE WHEN Grantee.is_fixed_role = 0 AND Grantee.name <> ''dbo'' THEN ' + NCHAR(13) + 755 | CASE WHEN @DBName = 'All' THEN N' ''USE '' + QUOTENAME(@AllDBNames) + ''; '' + ' + NCHAR(13) ELSE N'' END + 756 | N' CASE WHEN Permission.[state] = ''W'' THEN ''GRANT'' ELSE Permission.state_desc' + @Collation + 757 | N' END + 758 | '' '' + Permission.permission_name' + @Collation + N' + 759 | CASE WHEN Permission.major_id <> 0 THEN '' ON '' + 760 | ObjectList.class + ''::'' + 761 | ISNULL(QUOTENAME(ObjectList.SchemaName),'''') + 762 | CASE WHEN ObjectList.SchemaName + ObjectList.name IS NULL THEN '''' ELSE ''.'' END + 763 | ISNULL(QUOTENAME(ObjectList.name),'''') + ISNULL('' (''+ QUOTENAME(Columns.name) + '')'','''') 764 | ' + @Collation + N' + '' '' ELSE '''' END + 765 | '' TO '' + QUOTENAME(' + ISNULL('N'+QUOTENAME(@CopyTo,''''),'Grantee.name') + '' + @Collation + N') + '' '' + 766 | CASE WHEN Permission.[state] = ''W'' THEN '' WITH GRANT OPTION '' ELSE '''' END + 767 | '' AS ''+ QUOTENAME(Grantor.name' + @Collation + N')+'';'' END AS GrantScript 768 | FROM sys.database_permissions Permission 769 | JOIN sys.database_principals Grantee 770 | ON Permission.grantee_principal_id = Grantee.principal_id 771 | JOIN sys.database_principals Grantor 772 | ON Permission.grantor_principal_id = Grantor.principal_id 773 | LEFT OUTER JOIN ObjectList 774 | ON Permission.major_id = ObjectList.id 775 | AND Permission.class_desc = ObjectList.class_desc 776 | LEFT OUTER JOIN sys.columns AS Columns 777 | ON Permission.major_id = Columns.object_id 778 | AND Permission.minor_id = Columns.column_id 779 | WHERE 1=1 ' 780 | 781 | IF LEN(ISNULL(@Principal,@Role)) > 0 782 | IF @Print = 1 783 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.name ' + @LikeOperator + N' N' + ISNULL(QUOTENAME(@Principal,''''),QUOTENAME(@Role,'''')) 784 | ELSE 785 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.name ' + @LikeOperator + N' ISNULL(@Principal,@Role) ' 786 | 787 | IF LEN(@Type) > 0 788 | IF @Print = 1 789 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.type ' + @LikeOperator + N' N' + QUOTENAME(@Type,'''') 790 | ELSE 791 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.type ' + @LikeOperator + N' @Type' 792 | 793 | IF LEN(@ObjectName) > 0 794 | IF @Print = 1 795 | SET @sql = @sql + NCHAR(13) + N' AND ObjectList.name ' + @LikeOperator + N' N' + QUOTENAME(@ObjectName,'''') 796 | ELSE 797 | SET @sql = @sql + NCHAR(13) + N' AND ObjectList.name ' + @LikeOperator + N' @ObjectName ' 798 | 799 | IF LEN(@Permission) > 0 800 | IF @Print = 1 801 | SET @sql = @sql + NCHAR(13) + N' AND Permission.permission_name ' + @LikeOperator + N' N' + QUOTENAME(@Permission,'''') 802 | ELSE 803 | SET @sql = @sql + NCHAR(13) + N' AND Permission.permission_name ' + @LikeOperator + N' @Permission' 804 | 805 | IF LEN(@LoginName) > 0 806 | BEGIN 807 | SET @sql = @sql + NCHAR(13) + 808 | N' AND EXISTS (SELECT 1 809 | FROM sys.server_principals SrvPrincipals 810 | WHERE SrvPrincipals.sid = Grantee.sid 811 | AND Grantee.sid NOT IN (0x00, 0x01) 812 | AND Grantee.type NOT IN (''R'') ' + NCHAR(13) 813 | IF @Print = 1 814 | SET @sql = @sql + NCHAR(13) + N' AND SrvPrincipals.name ' + @LikeOperator + N' N' + QUOTENAME(@LoginName,'''') 815 | ELSE 816 | SET @sql = @sql + NCHAR(13) + N' AND SrvPrincipals.name ' + @LikeOperator + N' @LoginName' 817 | 818 | SET @sql = @sql + ')' 819 | END 820 | 821 | IF @IncludeMSShipped = 0 822 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.is_fixed_role = 0 ' + NCHAR(13) + 823 | ' AND Grantee.name NOT IN (''dbo'',''public'',''INFORMATION_SCHEMA'',''guest'',''sys'') ' 824 | 825 | IF @Print = 1 826 | BEGIN 827 | PRINT '-- Database & object Permissions' 828 | PRINT CAST(@use AS nvarchar(max)) 829 | PRINT CAST(@ObjectList AS nvarchar(max)) 830 | PRINT CAST(@ObjectList2 AS nvarchar(max)) 831 | PRINT CAST(@sql AS nvarchar(max)) 832 | END 833 | ELSE 834 | BEGIN 835 | IF object_id('tempdb..##DBPermissions') IS NOT NULL 836 | DROP TABLE ##DBPermissions 837 | 838 | -- Create temp table to store the data in 839 | CREATE TABLE ##DBPermissions ( 840 | DBName sysname NULL, 841 | GranteePrincipalId int NULL, 842 | GranteeName sysname NULL, 843 | GrantorName sysname NULL, 844 | class_desc nvarchar(60) NULL, 845 | permission_name nvarchar(128) NULL, 846 | ObjectName sysname NULL, 847 | SchemaName sysname NULL, 848 | state_desc nvarchar(60) NULL, 849 | RevokeScript nvarchar(max) NULL, 850 | GrantScript nvarchar(max) NULL 851 | ) 852 | 853 | -- Add insert statement to @sql 854 | SET @sql = @use + @ObjectList + @ObjectList2 + 855 | N'INSERT INTO ##DBPermissions ' + NCHAR(13) + 856 | @sql 857 | 858 | IF @DBName = 'All' 859 | BEGIN 860 | -- Declare a READ_ONLY cursor to loop through the databases 861 | DECLARE cur_DBList CURSOR 862 | READ_ONLY 863 | FOR SELECT name FROM sys.databases 864 | WHERE state IN (0,5) 865 | AND source_database_id IS NULL 866 | ORDER BY name 867 | 868 | OPEN cur_DBList 869 | 870 | FETCH NEXT FROM cur_DBList INTO @AllDBNames 871 | WHILE (@@fetch_status <> -1) 872 | BEGIN 873 | IF (@@fetch_status <> -2) 874 | BEGIN 875 | SET @sql2 = 'USE ' + QUOTENAME(@AllDBNames) + ';' + NCHAR(13) + @sql 876 | EXEC sp_executesql @sql2, 877 | N'@Principal sysname, @Role sysname, @Type nvarchar(30), @ObjectName sysname, 878 | @AllDBNames sysname, @Permission sysname, @LoginName sysname', 879 | @Principal, @Role, @Type, @ObjectName, @AllDBNames, @Permission, @LoginName 880 | -- PRINT @sql2 881 | END 882 | FETCH NEXT FROM cur_DBList INTO @AllDBNames 883 | END 884 | 885 | CLOSE cur_DBList 886 | DEALLOCATE cur_DBList 887 | END 888 | ELSE 889 | BEGIN 890 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30), 891 | @ObjectName sysname, @Permission sysname, @LoginName sysname', 892 | @Principal, @Role, @Type, @ObjectName, @Permission, @LoginName 893 | END 894 | END 895 | END 896 | 897 | IF @Print <> 1 898 | IF (SERVERPROPERTY('ProductVersion') >= '12' AND @ShowOrphans = 1) 899 | IF @Output IN ('CreateOnly', 'DropOnly', 'ScriptOnly') 900 | SELECT DropScript, CreateScript, CreateLogin, AlterUser 901 | FROM ##DBPrincipals ORDER BY DBName, DBPrincipal 902 | ELSE 903 | SELECT DBName, DBPrincipal, SrvPrincipal, type, type_desc, default_schema_name, 904 | create_date, modify_date, is_fixed_role, RoleAuthorization, sid, 905 | DropScript, CreateScript, CreateLogin, AlterUser 906 | FROM ##DBPrincipals ORDER BY DBName, DBPrincipal 907 | ELSE 908 | BEGIN 909 | IF @Output = 'None' 910 | PRINT '' 911 | ELSE IF @Output = 'CreateOnly' 912 | BEGIN 913 | SELECT CreateScript FROM ##DBPrincipals WHERE CreateScript IS NOT NULL 914 | UNION ALL 915 | SELECT AddScript FROM ##DBRoles WHERE AddScript IS NOT NULL 916 | UNION ALL 917 | SELECT GrantScript FROM ##DBPermissions WHERE GrantScript IS NOT NULL 918 | END 919 | ELSE IF @Output = 'DropOnly' 920 | BEGIN 921 | SELECT DropScript FROM ##DBPrincipals WHERE DropScript IS NOT NULL 922 | UNION ALL 923 | SELECT DropScript FROM ##DBRoles WHERE DropScript IS NOT NULL 924 | UNION ALL 925 | SELECT RevokeScript FROM ##DBPermissions WHERE RevokeScript IS NOT NULL 926 | END 927 | ELSE IF @Output = 'ScriptOnly' 928 | BEGIN 929 | SELECT DropScript, CreateScript FROM ##DBPrincipals WHERE DropScript IS NOT NULL OR CreateScript IS NOT NULL 930 | UNION ALL 931 | SELECT DropScript, AddScript FROM ##DBRoles WHERE DropScript IS NOT NULL OR AddScript IS NOT NULL 932 | UNION ALL 933 | SELECT RevokeScript, GrantScript FROM ##DBPermissions WHERE RevokeScript IS NOT NULL OR GrantScript IS NOT NULL 934 | END 935 | ELSE IF @Output = 'Report' 936 | BEGIN 937 | SELECT DBName, DBPrincipal, SrvPrincipal, type, type_desc, 938 | STUFF((SELECT N', ' + ##DBRoles.RoleName 939 | FROM ##DBRoles 940 | WHERE ##DBPrincipals.DBName = ##DBRoles.DBName 941 | AND ##DBPrincipals.DBPrincipalId = ##DBRoles.UserPrincipalId 942 | ORDER BY ##DBRoles.RoleName 943 | FOR XML PATH(''),TYPE).value('.','NVARCHAR(MAX)') 944 | , 1, 2, '') AS RoleMembership, 945 | STUFF((SELECT N', ' + ##DBPermissions.state_desc + N' ' + ##DBPermissions.permission_name + N' on ' + 946 | COALESCE(N'OBJECT:'+##DBPermissions.SchemaName + N'.' + ##DBPermissions.ObjectName, 947 | N'SCHEMA:'+##DBPermissions.SchemaName, 948 | N'DATABASE:'+##DBPermissions.DBName) 949 | FROM ##DBPermissions 950 | WHERE ##DBPrincipals.DBName = ##DBPermissions.DBName 951 | AND ##DBPrincipals.DBPrincipalId = ##DBPermissions.GranteePrincipalId 952 | ORDER BY ##DBPermissions.state_desc, ISNULL(##DBPermissions.ObjectName, ##DBPermissions.DBName), ##DBPermissions.permission_name 953 | FOR XML PATH(''),TYPE).value('.','NVARCHAR(MAX)') 954 | , 1, 2, '') AS DirectPermissions 955 | FROM ##DBPrincipals 956 | ORDER BY DBName, type, DBPrincipal 957 | END 958 | ELSE -- 'Default' or no match 959 | BEGIN 960 | SELECT DBName, DBPrincipal, SrvPrincipal, type, type_desc, default_schema_name, 961 | create_date, modify_date, is_fixed_role, RoleAuthorization, sid, 962 | DropScript, CreateScript 963 | FROM ##DBPrincipals ORDER BY DBName, DBPrincipal 964 | IF LEN(@Role) > 0 965 | SELECT DBName, UserName, RoleName, DropScript, AddScript 966 | FROM ##DBRoles ORDER BY DBName, RoleName, UserName 967 | ELSE 968 | SELECT DBName, UserName, RoleName, DropScript, AddScript 969 | FROM ##DBRoles ORDER BY DBName, UserName, RoleName 970 | 971 | IF LEN(@ObjectName) > 0 972 | SELECT DBName, GranteeName, GrantorName, class_desc, permission_name, ObjectName, 973 | SchemaName, state_desc, RevokeScript, GrantScript 974 | FROM ##DBPermissions ORDER BY DBName, SchemaName, ObjectName, GranteeName, permission_name 975 | ELSE 976 | SELECT DBName, GranteeName, GrantorName, class_desc, permission_name, ObjectName, 977 | SchemaName, state_desc, RevokeScript, GrantScript 978 | FROM ##DBPermissions ORDER BY DBName, GranteeName, SchemaName, ObjectName, permission_name 979 | END 980 | 981 | IF @DropTempTables = 1 982 | BEGIN 983 | DROP TABLE ##DBPrincipals 984 | DROP TABLE ##DBRoles 985 | DROP TABLE ##DBPermissions 986 | END 987 | END 988 | GO 989 | -------------------------------------------------------------------------------- /sp_SrvPermissions.sql: -------------------------------------------------------------------------------- 1 | USE master 2 | GO 3 | IF OBJECT_ID('dbo.sp_SrvPermissions') IS NULL 4 | EXEC sp_executesql N'CREATE PROCEDURE dbo.sp_SrvPermissions AS PRINT ''Stub'';' 5 | GO 6 | /********************************************************************************************* 7 | sp_SrvPermissions V6.1 8 | Kenneth Fisher 9 | 10 | http://www.sqlstudies.com 11 | https://github.com/sqlstudent144/SQL-Server-Scripts/edit/master/sp_SrvPermissions.sql 12 | 13 | This stored procedure returns 3 data sets. The first dataset is the list of server 14 | principals, the second is role membership, and the third is server level permissions. 15 | 16 | The final 2 columns of each query are "Un-Do"/"Do" scripts. For example removing a member 17 | from a role or adding them to a role. I am fairly confident in the role scripts, however, 18 | the scripts in the server principals query and server permissions query are works in 19 | progress. In particular certificates and keys are not scripted out. Also while the scripts 20 | have worked flawlessly on the systems I've tested them on, these systems are fairly similar 21 | when it comes to security so I can't say that in a more complicated system there won't be 22 | the odd bug. 23 | 24 | Notes on the create script for server principals: 25 | 1) I have included a hashed version of the password and the sid. This means that when run 26 | on another server the password and the sid will remain the same. 27 | 2) In SQL 2005 the create script on the server principals query DOES NOT WORK. This is 28 | because the conversion of the sid (in varbinary) to character doesn't appear to work 29 | as I expected in SQL 2005. It works fine in SQL 2008 and above. If you want to use 30 | this script in SQL 2005 you can change the CONVERTs in the principal script to 31 | master.sys.fn_varbintohexstr 32 | 33 | Standard disclaimer: You use scripts off of the web at your own risk. I fully expect this 34 | script to work without issue but I've been known to be wrong before. 35 | 36 | Parameters: 37 | @Principal 38 | If NOT NULL then all three queries only pull for that server principal. @Principal 39 | is a pattern check. The queries check for any row where the passed in value exists. 40 | It uses the pattern '%' + @Principal + '%' 41 | @Role 42 | If NOT NULL then the roles query will pull members of the role. If it is NOT NULL and 43 | @Principal is NULL then Server principal and permissions query will pull the principal 44 | row for the role and the permissions for the role. @Role is a pattern check. The 45 | queries check for any row where the passed in value exists. It uses the pattern 46 | '%' + @Role + '%' 47 | @Type 48 | If NOT NULL then all three queries will only pull principals of that type. 49 | S = SQL login 50 | U = Windows login 51 | G = Windows group 52 | R = Server role 53 | C = Login mapped to a certificate 54 | K = Login mapped to an asymmetric key 55 | @DBName 56 | If NOT NULL then only return those principals and information about them where the 57 | principal exists within the DB specified. 58 | @UseLikeSearch 59 | When this is set to 1 (the default) then the search parameters will use LIKE (and 60 | %'s will be added around the @Principal and @Role parameters). 61 | When set to 0 searchs will use =. 62 | @IncludeMSShipped 63 | When this is set to 1 (the default) then all principals will be included. When set 64 | to 0 the fixed server roles and SA and Public principals will be excluded. 65 | @CopyTo 66 | If @Principal is filled in then the value in @CopyTo is used in the drop and create 67 | scripts instead of @Principal. If @CopyTo is used the SID value will not be included 68 | in the CREATE LOGIN script. 69 | NOTE: It is very important to note that if @CopyTo is not a valid name the drop/create 70 | scripts may fail. 71 | @DropTempTables 72 | When this is set to 1 (the default) the temp tables used are dropped. If it's 0 73 | then the tempt ables are kept for references after the code has finished. 74 | The temp tables are: 75 | ##SrvPrincipals 76 | ##SrvRoles 77 | ##SrvPermissions 78 | @Output 79 | What type of output is desired. 80 | Default - Either 'Default' or it doesn't match any of the allowed values then the SP 81 | will return the standard 3 outputs. 82 | None - No output at all. Usually used if you keeping the temp tables to do your own 83 | reporting. 84 | CreateOnly - Only return the create scripts where they aren't NULL. 85 | DropOnly - Only return the drop scripts where they aren't NULL. 86 | ScriptsOnly - Return drop and create scripts where they aren't NULL. 87 | Report - Returns one output with one row per principal and a comma delimited list of 88 | roles the principal is a member of and a comma delimited list of the 89 | individual permissions they have. 90 | @Print 91 | Defaults to 0, but if a 1 is passed in then the queries are not run but printed 92 | out instead. This is primarily for debugging. 93 | 94 | Data is ordered as follows 95 | 1st result set: SrvPrincipal 96 | 2nd result set: RoleName, LoginName if the parameter @Role is used else 97 | LoginName, RoleName 98 | 3rd result set: GranteeName 99 | 100 | ********************************************************************************************* 101 | -- V2.0 102 | -- 8/18/2013 – Create a stub if the SP doesn’t exist, then always do an alter 103 | -- 9/04/2013 – Change print option to show values of variables not the 104 | -- Variable names. 105 | -- V3.0 106 | -- 10/5/2013 - Added @Type parameter to pull only principals of a given type. 107 | -- 10/20/2013 - Remove SID in CREATE LOGIN script from v2005 and lower since it requires 108 | a special function to convert from binary to varchar. 109 | -- V4.0 110 | -- 11/18/2013 - Corrected bug in the order of the parameters for sp_addsrvrolemember 111 | and sp_dropsrvrolemember, also added parameter names both. 112 | -- 01/09/2014 - Added an ORDER BY to each of the result sets. See above for details. 113 | -- V5.0 114 | -- 04/27/2014 - Add @DBName parameter 115 | -- V5.5 116 | -- 7/22/2014 - Changed strings to unicode 117 | -- V6.0 118 | -- 10/19/2014 - Add @UserLikeSearch and @IncludeMSShipped parameters. 119 | -- 03/25/2017 - Move SID towards the end of the first output so the more important 120 | -- columns are closer to the front. 121 | -- 03/25/2017 - Add IF Exists to drop and create principal scripts 122 | -- 03/25/2017 - Add @DropTempTables to keep the temp tables after the SP is run. 123 | -- 03/26/2017 - Add @Output to allow different types of output. 124 | -- V6.1 125 | -- 06/13/2018 - Removed scripts for principal IDs under 100 (anecdotally the system IDs) 126 | -- - Added SET NOCOUNT ON 127 | -- 05/28/2019 - Add scripts & mappings for certificate & asymmetric key mapped principals. 128 | -- - Start cleaning up the dynamic SQL a bit to make it easier to read. 129 | -- - Fix SERVER ROLE scripts 130 | -- - Add CHECK_POLICY and CHECK_EXPIRATION 131 | -- - Add script support for disabled 132 | -- - Add script support for a single credential. Will not support multiple credentials. 133 | -- 07/17/2022 - Add @CopyTo parameter to handle requests like "Please copy permissions from x to y." 134 | -- 07/31/2022 - Formatting: Replace tabs with spaces 135 | *********************************************************************************************/ 136 | ALTER PROCEDURE dbo.sp_SrvPermissions 137 | ( 138 | @Principal sysname = NULL, 139 | @Role sysname = NULL, 140 | @Type nvarchar(30) = NULL, 141 | @DBName sysname = NULL, 142 | @UseLikeSearch bit = 1, 143 | @IncludeMSShipped bit = 1, 144 | @CopyTo sysname = NULL, 145 | @DropTempTables bit = 1, 146 | @Output varchar(30) = 'Default', 147 | @Print bit = 0 148 | ) 149 | AS 150 | 151 | SET NOCOUNT ON 152 | 153 | IF @DBName IS NOT NULL AND NOT EXISTS (SELECT 1 FROM sys.databases WHERE name = @DBName) 154 | BEGIN 155 | RAISERROR (N'%s is not a valid database name.', 156 | 16, 157 | 1, 158 | @DBName) 159 | RETURN 160 | END 161 | 162 | DECLARE @Collation nvarchar(50) 163 | SET @Collation = N' COLLATE ' + CAST(SERVERPROPERTY('Collation') AS nvarchar(50)) 164 | 165 | DECLARE @Version2005orLower bit 166 | SELECT @Version2005orLower = CASE WHEN PARSENAME(CAST(SERVERPROPERTY('productversion') AS VARCHAR(20)),4) < 10 THEN 1 167 | ELSE 0 END 168 | 169 | DECLARE @sql nvarchar(max) 170 | DECLARE @LikeOperator nvarchar(4) 171 | 172 | IF @UseLikeSearch = 1 173 | SET @LikeOperator = N'LIKE' 174 | ELSE 175 | SET @LikeOperator = N'=' 176 | 177 | IF @UseLikeSearch = 1 178 | BEGIN 179 | IF LEN(ISNULL(@Principal,'')) > 0 180 | SET @Principal = N'%' + @Principal + N'%' 181 | 182 | IF LEN(ISNULL(@Role,'')) > 0 183 | SET @Role = N'%' + @Role+ N'%' 184 | END 185 | 186 | IF (@Principal IS NULL AND @CopyTo IS NOT NULL) OR LEN(@CopyTo) = 0 187 | SET @CopyTo = NULL 188 | 189 | --========================================================================= 190 | -- Server Principals 191 | SET @sql = 192 | N'SELECT Logins.principal_id AS SrvPrincipalId, Logins.name AS SrvPrincipal, Logins.type, Logins.type_desc, 193 | Logins.is_disabled, Logins.default_database_name, Logins.default_language_name, 194 | CASE sql_logins.is_policy_checked WHEN 1 THEN ''ON'' WHEN 0 THEN ''OFF'' END AS check_policy, 195 | CASE sql_logins.is_expiration_checked WHEN 1 THEN ''ON'' WHEN 0 THEN ''OFF'' END AS check_expiration, 196 | ISNULL(Cert.name,aKey.name) AS Cert_or_asymmetric_key, 197 | Logins.sid, 198 | CASE WHEN Logins.principal_id < 100 THEN NULL ELSE 199 | ''IF EXISTS (SELECT * FROM sys.server_principals WHERE name = '' + QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + ','''''''') + '') '' + 200 | ''DROP '' + CASE Logins.type 201 | WHEN ''R'' THEN ''SERVER ROLE'' 202 | ELSE ''LOGIN'' END + 203 | '' ''+QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + '' + @Collation + ') END + '';'' AS DropScript, 204 | CASE WHEN Logins.principal_id < 100 THEN NULL ELSE 205 | ''IF NOT EXISTS (SELECT * FROM sys.server_principals WHERE name = '' + QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + ','''''''') + '') '' + 206 | ''CREATE '' + CASE Logins.type 207 | WHEN ''R'' THEN ''SERVER ROLE'' 208 | ELSE ''LOGIN'' END + 209 | '' ''+QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + '' + @Collation + ') END + 210 | CASE WHEN Logins.type = (''S'') THEN '' WITH PASSWORD = '' + 211 | CONVERT(varchar(256), LOGINPROPERTY(Logins.name, ''PasswordHash''),1 ) + '' HASHED' + 212 | CASE WHEN @Version2005orLower = 0 AND @CopyTo IS NULL THEN N','' + 213 | '' SID = '' + CONVERT(varchar(85), Logins.sid, 1) ' 214 | ELSE N'''' END + ' 215 | WHEN Logins.type IN (''U'',''G'') THEN '' FROM WINDOWS '' 216 | WHEN Logins.type = ''C'' THEN ISNULL('' FROM CERTIFICATE '' + QUOTENAME(Cert.name),'''') 217 | WHEN Logins.type = ''K'' THEN ISNULL('' FROM ASYMMETRIC KEY '' + QUOTENAME(aKey.name),'''') 218 | ELSE '''' END + 219 | CASE WHEN Logins.type IN (''S'',''U'',''G'') THEN -- Note: Types, S, U and G are the only ones that have additional options. 220 | CASE WHEN Logins.default_database_name IS NOT NULL OR Logins.default_language_name IS NOT NULL THEN 221 | CASE WHEN Logins.Type = ''S'' THEN '','' ELSE '' WITH '' END 222 | ELSE '''' END + 223 | ISNULL('' DEFAULT_DATABASE = '' + QUOTENAME(Logins.default_database_name' + @Collation + N'), '''') + 224 | CASE WHEN Logins.default_database_name IS NOT NULL AND Logins.default_language_name IS NOT NULL THEN '','' ELSE '''' END + 225 | ISNULL('' DEFAULT_LANGUAGE = '' + QUOTENAME(Logins.default_language_name' + @Collation + N'), '''') + 226 | CASE WHEN Logins.type = ''S'' THEN 227 | ISNULL('', CHECK_EXPIRATION = '' + CASE WHEN sql_logins.is_expiration_checked = 1 THEN ''ON'' ELSE ''OFF'' END, '''') + 228 | ISNULL('', CHECK_POLICY = '' + CASE WHEN sql_logins.is_policy_checked = 1 THEN ''ON'' ELSE ''OFF'' END, '''') + 229 | ISNULL('', CREDENTIAL = '' + QUOTENAME(Creds.name), '''') 230 | ELSE '''' END 231 | ELSE '''' END + 232 | ''; '' + 233 | CASE WHEN Logins.is_disabled = 1 THEN ''ALTER LOGIN '' + QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + ') + '' DISABLE; '' ELSE '''' END 234 | AS CreateScript 235 | FROM sys.server_principals Logins 236 | LEFT OUTER JOIN sys.certificates Cert 237 | ON Logins.sid = Cert.sid 238 | LEFT OUTER JOIN sys.asymmetric_keys aKey 239 | ON Logins.sid = aKey.sid 240 | LEFT OUTER JOIN sys.sql_logins 241 | ON Logins.sid = sql_logins.sid 242 | LEFT OUTER JOIN sys.server_principal_credentials LoginCreds 243 | ON Logins.principal_id = LoginCreds.principal_id 244 | LEFT OUTER JOIN sys.credentials Creds 245 | ON LoginCreds.credential_id = Creds.credential_id 246 | WHERE 1=1 ' 247 | 248 | IF LEN(ISNULL(@Principal,@Role)) > 0 249 | IF @Print = 1 250 | SET @sql = @sql + NCHAR(13) + N' AND Logins.name ' + @LikeOperator + N' ' + ISNULL(+QUOTENAME(@Principal,''''),QUOTENAME(@Role,'''')) 251 | ELSE 252 | SET @sql = @sql + NCHAR(13) + N' AND Logins.name ' + @LikeOperator + N' ISNULL(@Principal,@Role) ' 253 | 254 | IF LEN(@Type) > 0 255 | IF @Print = 1 256 | SET @sql = @sql + NCHAR(13) + N' AND Logins.type ' + @LikeOperator + N' ' + QUOTENAME(@Type,'''') 257 | ELSE 258 | SET @sql = @sql + NCHAR(13) + N' AND Logins.type ' + @LikeOperator + N' @Type' 259 | 260 | IF @DBName IS NOT NULL 261 | SET @sql = @sql + NCHAR(13) + N' AND Logins.SID IN (SELECT SID FROM [' + @DBName + N'].sys.database_principals 262 | WHERE type IN (''G'',''S'',''U'',''K'',''C''))' 263 | 264 | IF @IncludeMSShipped = 0 265 | SET @sql = @sql + NCHAR(13) + N' AND Logins.is_fixed_role = 0 ' + NCHAR(13) + 266 | ' AND Logins.name NOT IN (''sa'',''public'') ' 267 | 268 | IF @Print = 1 269 | PRINT '-- Server Principals' + NCHAR(13) + @sql + NCHAR(13) + NCHAR(13) 270 | ELSE 271 | BEGIN 272 | IF object_id('tempdb..##SrvPrincipals') IS NOT NULL 273 | DROP TABLE ##SrvPrincipals 274 | 275 | -- Create temp table to store the data in 276 | CREATE TABLE ##SrvPrincipals ( 277 | SrvPrincipalId int NULL, 278 | SrvPrincipal sysname NULL, 279 | type char(1) NULL, 280 | type_desc nchar(60) NULL, 281 | is_disabled bit NULL, 282 | default_database_name sysname NULL, 283 | default_language_name sysname NULL, 284 | [check_policy] char(3) NULL, 285 | [check_expiration] char(3) NULL, 286 | Cert_or_asymmetric_key sysname NULL, 287 | sid varbinary(85) NULL, 288 | DropScript nvarchar(max) NULL, 289 | CreateScript nvarchar(max) NULL 290 | ) 291 | 292 | SET @sql = N'INSERT INTO ##SrvPrincipals ' + NCHAR(13) + @sql 293 | 294 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type varchar(30)', @Principal, @Role, @Type 295 | END 296 | --========================================================================= 297 | -- Server level roles 298 | SET @sql = 299 | N'SELECT Logins.principal_id AS LoginPrincipalId, Logins.name AS LoginName, Roles.name AS RoleName, 300 | CASE WHEN Logins.principal_id < 100 THEN NULL ELSE 301 | ''EXEC sp_dropsrvrolemember @loginame = ''+QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + '' + @Collation + 302 | ','''''''')+'', @rolename = ''+QUOTENAME(Roles.name' + @Collation + 303 | ','''''''') + '';'' END AS DropScript, 304 | CASE WHEN Logins.principal_id < 100 THEN NULL ELSE 305 | ''EXEC sp_addsrvrolemember @loginame = ''+QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Logins.name') + '' + @Collation + 306 | ','''''''')+'', @rolename = ''+QUOTENAME(Roles.name' + @Collation + 307 | ','''''''') + '';'' END AS AddScript 308 | FROM sys.server_role_members RoleMembers 309 | JOIN sys.server_principals Logins 310 | ON RoleMembers.member_principal_id = Logins.principal_id 311 | JOIN sys.server_principals Roles 312 | ON RoleMembers.role_principal_id = Roles.principal_id 313 | WHERE 1=1 ' 314 | 315 | IF LEN(ISNULL(@Principal,'')) > 0 316 | IF @Print = 1 317 | SET @sql = @sql + NCHAR(13) + N' AND Logins.name ' + @LikeOperator + N' '+QUOTENAME(@Principal,'''') 318 | ELSE 319 | SET @sql = @sql + NCHAR(13) + N' AND Logins.name ' + @LikeOperator + N' @Principal' 320 | 321 | IF LEN(ISNULL(@Role,'')) > 0 322 | IF @Print = 1 323 | SET @sql = @sql + NCHAR(13) + N' AND Roles.name ' + @LikeOperator + N' '+QUOTENAME(@Role,'''') 324 | ELSE 325 | SET @sql = @sql + NCHAR(13) + N' AND Roles.name ' + @LikeOperator + N' @Role' 326 | 327 | IF LEN(@Type) > 0 328 | IF @Print = 1 329 | SET @sql = @sql + NCHAR(13) + N' AND Logins.type ' + @LikeOperator + N' ' + QUOTENAME(@Type,'''') 330 | ELSE 331 | SET @sql = @sql + NCHAR(13) + N' AND Logins.type ' + @LikeOperator + N' @Type' 332 | 333 | IF @DBName IS NOT NULL 334 | SET @sql = @sql + NCHAR(13) + N' AND Logins.SID IN (SELECT SID FROM [' + @DBName + N'].sys.database_principals 335 | WHERE type IN (''G'',''S'',''U'',''K'',''C''))' 336 | 337 | IF @IncludeMSShipped = 0 338 | SET @sql = @sql + NCHAR(13) + N' AND Logins.is_fixed_role = 0 ' + NCHAR(13) + 339 | ' AND Logins.name NOT IN (''sa'',''public'') ' 340 | 341 | IF @Print = 1 342 | PRINT '-- Server Role Members' + NCHAR(13) + @sql + NCHAR(13) + NCHAR(13) 343 | ELSE 344 | BEGIN 345 | IF object_id('tempdb..##SrvRoles') IS NOT NULL 346 | DROP TABLE ##SrvRoles 347 | 348 | -- Create temp table to store the data in 349 | CREATE TABLE ##SrvRoles ( 350 | LoginPrincipalId int NULL, 351 | LoginName sysname NULL, 352 | RoleName sysname NULL, 353 | DropScript nvarchar(max) NULL, 354 | AddScript nvarchar(max) NULL 355 | ) 356 | 357 | SET @sql = 'INSERT INTO ##SrvRoles ' + NCHAR(13) + @sql 358 | 359 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30)', @Principal, @Role, @Type 360 | END 361 | 362 | --========================================================================= 363 | -- Server Permissions 364 | SET @sql = 365 | N'SELECT Grantee.principal_id AS GranteePrincipalId, Grantee.name AS GranteeName, 366 | Grantor.name AS GrantorName, Permission.class_desc, Permission.permission_name, 367 | Permission.state_desc, 368 | CASE WHEN Grantee.principal_id < 100 THEN NULL ELSE 369 | ''REVOKE '' + 370 | CASE WHEN Permission.class_desc = ''ENDPOINT'' THEN NULL 371 | WHEN Permission.[state] = ''W'' THEN ''GRANT OPTION FOR '' ELSE '''' END + 372 | '' '' + Permission.permission_name' + @Collation + ' + 373 | '' FROM '' + QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Grantee.name') + '' + @Collation + ') + ''; '' END AS RevokeScript, 374 | CASE WHEN Grantee.principal_id < 100 THEN NULL ELSE 375 | CASE WHEN Permission.class_desc = ''ENDPOINT'' THEN NULL 376 | WHEN Permission.[state] = ''W'' THEN ''GRANT'' ELSE Permission.state_desc' + @Collation + 377 | ' END + 378 | '' '' + Permission.permission_name' + @Collation + ' + 379 | '' TO '' + QUOTENAME(' + ISNULL(QUOTENAME(@CopyTo,''''),'Grantee.name') + '' + @Collation + ') + '' '' + 380 | CASE WHEN Permission.[state] = ''W'' THEN '' WITH GRANT OPTION '' ELSE '''' END + 381 | '' AS ''+ QUOTENAME(Grantor.name' + @Collation + ') + '';'' END AS GrantScript 382 | FROM sys.server_permissions Permission 383 | JOIN sys.server_principals Grantee 384 | ON Permission.grantee_principal_id = Grantee.principal_id 385 | JOIN sys.server_principals Grantor 386 | ON Permission.grantor_principal_id = Grantor.principal_id 387 | WHERE 1=1 ' 388 | 389 | IF LEN(ISNULL(@Principal,@Role)) > 0 390 | IF @Print = 1 391 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.name ' + @LikeOperator + N' ' + ISNULL(+QUOTENAME(@Principal,''''),QUOTENAME(@Role,'''')) 392 | ELSE 393 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.name ' + @LikeOperator + N' ISNULL(@Principal,@Role) ' 394 | 395 | IF LEN(@Type) > 0 396 | IF @Print = 1 397 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.type ' + @LikeOperator + N' ' + QUOTENAME(@Type,'''') 398 | ELSE 399 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.type ' + @LikeOperator + N' @Type' 400 | 401 | IF @DBName IS NOT NULL 402 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.SID IN (SELECT SID FROM [' + @DBName + N'].sys.database_principals 403 | WHERE type IN (''G'',''S'',''U'',''K'',''C''))' 404 | 405 | IF @IncludeMSShipped = 0 406 | SET @sql = @sql + NCHAR(13) + N' AND Grantee.is_fixed_role = 0 ' + NCHAR(13) + 407 | ' AND Grantee.name NOT IN (''sa'',''public'') ' 408 | 409 | IF @Print = 1 410 | PRINT '-- Server Permissions' + NCHAR(13) + @sql + NCHAR(13) + NCHAR(13) 411 | ELSE 412 | BEGIN 413 | IF object_id('tempdb..##SrvPermissions') IS NOT NULL 414 | DROP TABLE ##SrvPermissions 415 | 416 | -- Create temp table to store the data in 417 | CREATE TABLE ##SrvPermissions ( 418 | GranteePrincipalId int NULL, 419 | GranteeName sysname NULL, 420 | GrantorName sysname NULL, 421 | class_desc nvarchar(60) NULL, 422 | permission_name nvarchar(128) NULL, 423 | state_desc nvarchar(60) NULL, 424 | RevokeScript nvarchar(max) NULL, 425 | GrantScript nvarchar(max) NULL 426 | ) 427 | 428 | -- Add insert statement to @sql 429 | SET @sql = N'INSERT INTO ##SrvPermissions ' + NCHAR(13) + @sql 430 | 431 | EXEC sp_executesql @sql, N'@Principal sysname, @Role sysname, @Type nvarchar(30)', @Principal, @Role, @Type 432 | END 433 | 434 | IF @Print <> 1 435 | BEGIN 436 | 437 | IF @Output = 'None' 438 | PRINT '' 439 | ELSE IF @Output = 'CreateOnly' 440 | BEGIN 441 | SELECT CreateScript FROM ##SrvPrincipals WHERE CreateScript IS NOT NULL 442 | UNION ALL 443 | SELECT AddScript FROM ##SrvRoles WHERE AddScript IS NOT NULL 444 | UNION ALL 445 | SELECT GrantScript FROM ##SrvPermissions WHERE GrantScript IS NOT NULL 446 | END 447 | ELSE IF @Output = 'DropOnly' 448 | BEGIN 449 | SELECT DropScript FROM ##SrvPrincipals WHERE DropScript IS NOT NULL 450 | UNION ALL 451 | SELECT DropScript FROM ##SrvRoles WHERE DropScript IS NOT NULL 452 | UNION ALL 453 | SELECT RevokeScript FROM ##SrvPermissions WHERE RevokeScript IS NOT NULL 454 | END 455 | ELSE IF @Output = 'ScriptOnly' 456 | BEGIN 457 | SELECT DropScript, CreateScript FROM ##SrvPrincipals WHERE DropScript IS NOT NULL OR CreateScript IS NOT NULL 458 | UNION ALL 459 | SELECT DropScript, AddScript FROM ##SrvRoles WHERE DropScript IS NOT NULL OR AddScript IS NOT NULL 460 | UNION ALL 461 | SELECT RevokeScript, GrantScript FROM ##SrvPermissions WHERE RevokeScript IS NOT NULL OR GrantScript IS NOT NULL 462 | END 463 | ELSE IF @Output = 'Report' 464 | BEGIN 465 | SELECT SrvPrincipal, type, type_desc, is_disabled, 466 | STUFF((SELECT ', ' + ##SrvRoles.RoleName 467 | FROM ##SrvRoles 468 | WHERE ##SrvPrincipals.SrvPrincipalId = ##SrvRoles.LoginPrincipalId 469 | ORDER BY ##SrvRoles.RoleName 470 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)') 471 | , 1, 2, '') AS RoleMembership, 472 | STUFF((SELECT ', ' + ##SrvPermissions.state_desc + ' ' + ##SrvPermissions.permission_name + ' ' + 473 | CASE WHEN class_desc <> 'SERVER' THEN class_desc ELSE '' END 474 | FROM (SELECT DISTINCT * FROM ##SrvPermissions) ##SrvPermissions 475 | WHERE ##SrvPrincipals.SrvPrincipalId = ##SrvPermissions.GranteePrincipalId 476 | ORDER BY ##SrvPermissions.state_desc, ##SrvPermissions.permission_name 477 | FOR XML PATH(''),TYPE).value('.','VARCHAR(MAX)') 478 | , 1, 2, '') AS DirectPermissions 479 | FROM ##SrvPrincipals 480 | ORDER BY SrvPrincipal 481 | END 482 | ELSE -- 'Default' or no match 483 | BEGIN 484 | SELECT SrvPrincipal, type, type_desc, is_disabled, default_database_name, 485 | default_language_name, [check_policy], [check_expiration], Cert_or_asymmetric_key, 486 | sid, DropScript, CreateScript 487 | FROM ##SrvPrincipals ORDER BY SrvPrincipal 488 | IF LEN(@Role) > 0 489 | SELECT LoginName, RoleName, DropScript, AddScript FROM ##SrvRoles ORDER BY RoleName, LoginName 490 | ELSE 491 | SELECT LoginName, RoleName, DropScript, AddScript FROM ##SrvRoles ORDER BY LoginName, RoleName 492 | SELECT GranteeName, GrantorName, class_desc, permission_name, state_desc, RevokeScript, GrantScript 493 | FROM ##SrvPermissions ORDER BY GranteeName 494 | END 495 | 496 | IF @DropTempTables = 1 497 | BEGIN 498 | DROP TABLE ##SrvPrincipals 499 | DROP TABLE ##SrvRoles 500 | DROP TABLE ##SrvPermissions 501 | END 502 | END 503 | GO 504 | --------------------------------------------------------------------------------