├── .github
└── ISSUE_TEMPLATE
│ ├── bug_report.md
│ └── feature_request.md
├── CODE_OF_CONDUCT.md
├── CONTRIBUTING.md
├── CatagoryControlledAgentJobs.sql
├── Checking your backup paths exist and auto creating them.sql
├── DAG Dashboard.pbix
├── Data Relay
├── DataRelay Demos.sql
├── Writing Your Own Encryption Routines in SQL.pptm
└── ~$Writing Your Own Encryption Routines in SQL.pptm
├── Database Files Sizes and Growth rates.sql
├── Find the primary server of an availability group.ps1
├── Find untrusted Foreign Keys and Orphaned Data (Cross Apply Version).sql
├── Find untrusted Foreign Keys and Orphaned Data (Cursor Version).sql
├── Generate a Temporary table definition to match a resultset.sql
├── GroupBy
├── Writing Your Own Encryption Routines in SQL.pptm
└── WritingYouOwnEncryption_demos.sql
├── High Severity Alert Notifications.sql
├── How far has my update got.sql
├── LICENSE.md
├── LSNCheck and FileExistence_CS.sql
├── Open Transaction Details.sql
├── README.md
├── Resend_an_email.sql
├── SQLUndercoverCatalogue
├── CatalogueInterrogation.ps1
├── CatalogueInterrogation_OLD.ps1
├── ModuleDefinitions
│ ├── GetADGroups.sql
│ ├── GetAgentJobs.sql
│ ├── GetAvailabilityGroups.sql
│ ├── GetCluster.sql
│ ├── GetDatabases.sql
│ ├── GetDatabases2008.sql
│ ├── GetExplicitPermissions.sql
│ ├── GetLinkedServers.sql
│ ├── GetLogins.sql
│ ├── GetServerConfig.sql
│ ├── GetServers.sql
│ ├── GetServices.sql
│ ├── GetServicesEnhanced.sql
│ ├── GetSnapshots.sql
│ ├── GetTables.sql
│ ├── GetTraceFlags.sql
│ ├── GetUsers.sql
│ ├── UpdateADGroups.sql
│ ├── UpdateAgentJobs.sql
│ ├── UpdateAvailabilityGroups.sql
│ ├── UpdateCluster.sql
│ ├── UpdateDatabases.sql
│ ├── UpdateDatabases2008.sql
│ ├── UpdateExplicitPermissions.sql
│ ├── UpdateLinkedServers.sql
│ ├── UpdateLogins.sql
│ ├── UpdateServerConfig.sql
│ ├── UpdateServers.sql
│ ├── UpdateServices.sql
│ ├── UpdateServicesEnhanced.sql
│ ├── UpdateSnapshots.sql
│ ├── UpdateTables.sql
│ ├── UpdateTraceFlags.sql
│ └── UpdateUsers.sql
├── UndercoverCatalogue.pbit
├── UndercoverCatalogueSetup_040.sql
├── Updates
│ ├── .vs
│ │ └── slnx.sqlite
│ ├── Catalogue_UD040.sql
│ ├── Catalogue_UD041.sql
│ ├── Catalogue_UD042.sql
│ ├── Catalogue_UD043.sql
│ ├── Catalogue_UD044.sql
│ ├── Catalogue_UD045.sql
│ ├── Catalogue_UD050.sql
│ ├── Manifest.csv
│ └── UndercoverCatalogueUpgrade_030.sql
└── Useful Scripts
│ └── Find Missing and Mismatched Logins.sql
├── SQLUndercoverInspector
├── Deprecated
│ ├── SQLUndercoverinspectorV1.sql
│ └── V1 - Additional files
│ │ ├── Inspector_Template.pbit
│ │ ├── Install-Inspector.ps1
│ │ └── Invoke-SQLUndercoverInspector.ps1
├── SQLUndercoverinspectorV2.sql
└── V2 - Additional files
│ ├── All Inspector custom modules.zip
│ ├── All Powershell Inspector files.zip
│ ├── InspectorAutoUpdate.psm1
│ ├── InspectorV2.pbit
│ ├── Inspector_BlitzFileStats_CustomModule.sql
│ ├── Inspector_BlitzWaits_CustomModule.sql
│ ├── Inspector_CPU_CustomModule.sql
│ ├── Inspector_Catalogue_CustomModule.sql
│ ├── Install-Inspector.ps1
│ ├── Invoke-SQLUndercoverInspector.ps1
│ ├── Manifest.csv
│ ├── Offline Auto Updates.zip
│ └── Swap view MultiWarningModules for table.sql
├── SnapshotRestoreHistory.sql
├── Undercover Academy
└── SQL Server Backup and Recovery
│ └── 1 Taking and Restoring a Backup
│ └── Taking and Restoring a Backup.sql
├── Undercover TV Scripts
└── BeginningSMO
│ ├── 01-LoadAssembly.ps1
│ ├── 02-BasicConn.ps1
│ ├── 03-SQLAuth.ps1
│ ├── 04-ExploringObjectModel.ps1
│ ├── 05-LimitingObjects.ps1
│ ├── 06-Methods.ps1
│ ├── 07-ScriptData1.ps1
│ ├── 08-ScriptData2.ps1
│ ├── Beginning SMO.docx
│ └── DataScripter.ps1
├── UpdateStaticstics.sql
├── Use Python to copy a SQL Login.sql
├── What if it all grows out.sql
├── When was my last backup taken.sql
├── fn_SplitString.sql
├── move SQL files in bulk.sql
├── sp_AGFailover.sql
├── sp_AGReconfigure.sql
├── sp_ChangeAgentJobOperator.sql
├── sp_ChangeDatabaseOwnerShip.sql
├── sp_ChangeJobOwnerShip.sql
├── sp_FailedJobs.sql
├── sp_FailedLogins.sql
├── sp_LockDetails.sql
├── sp_RunningJobs.sql
├── sp_Snapshot.sql
├── sp_Tablecount.sql
├── sp_WhatsmyAG.sql
├── sp_drivespace.sql
└── sp_restorescript.sql
/.github/ISSUE_TEMPLATE/bug_report.md:
--------------------------------------------------------------------------------
1 | ---
2 | name: Bug report
3 | about: Create a report to help us improve
4 |
5 | ---
6 |
7 | **Describe the bug**
8 | A clear and concise description of what the bug is.
9 |
10 | **To Reproduce**
11 | Steps to reproduce the behavior:
12 | 1. Go to '...'
13 | 2. Click on '....'
14 | 3. Scroll down to '....'
15 | 4. See error
16 |
17 | **Expected behavior**
18 | A clear and concise description of what you expected to happen.
19 |
20 | **Screenshots**
21 | If applicable, add screenshots to help explain your problem.
22 |
23 | **Desktop (please complete the following information):**
24 | - OS: [e.g. iOS]
25 | - Browser [e.g. chrome, safari]
26 | - Version [e.g. 22]
27 |
28 | **Smartphone (please complete the following information):**
29 | - Device: [e.g. iPhone6]
30 | - OS: [e.g. iOS8.1]
31 | - Browser [e.g. stock browser, safari]
32 | - Version [e.g. 22]
33 |
34 | **Additional context**
35 | Add any other context about the problem here.
36 |
--------------------------------------------------------------------------------
/.github/ISSUE_TEMPLATE/feature_request.md:
--------------------------------------------------------------------------------
1 | ---
2 | name: Feature request
3 | about: Suggest an idea for this project
4 |
5 | ---
6 |
7 | **Is your feature request related to a problem? Please describe.**
8 | A clear and concise description of what the problem is. Ex. I'm always frustrated when [...]
9 |
10 | **Describe the solution you'd like**
11 | A clear and concise description of what you want to happen.
12 |
13 | **Describe alternatives you've considered**
14 | A clear and concise description of any alternative solutions or features you've considered.
15 |
16 | **Additional context**
17 | Add any other context or screenshots about the feature request here.
18 |
--------------------------------------------------------------------------------
/CODE_OF_CONDUCT.md:
--------------------------------------------------------------------------------
1 | # Contributor Covenant Code of Conduct
2 |
3 | ## Our Pledge
4 |
5 | In the interest of fostering an open and welcoming environment, we as contributors and maintainers pledge to making participation in our project and our community a harassment-free experience for everyone, regardless of age, body size, disability, ethnicity, gender identity and expression, level of experience, nationality, personal appearance, race, religion, or sexual identity and orientation.
6 |
7 | ## Our Standards
8 |
9 | Examples of behavior that contributes to creating a positive environment include:
10 |
11 | * Using welcoming and inclusive language
12 | * Being respectful of differing viewpoints and experiences
13 | * Gracefully accepting constructive criticism
14 | * Focusing on what is best for the community
15 | * Showing empathy towards other community members
16 |
17 | Examples of unacceptable behavior by participants include:
18 |
19 | * The use of sexualized language or imagery and unwelcome sexual attention or advances
20 | * Trolling, insulting/derogatory comments, and personal or political attacks
21 | * Public or private harassment
22 | * Publishing others' private information, such as a physical or electronic address, without explicit permission
23 | * Other conduct which could reasonably be considered inappropriate in a professional setting
24 |
25 | ## Our Responsibilities
26 |
27 | Project maintainers are responsible for clarifying the standards of acceptable behavior and are expected to take appropriate and fair corrective action in response to any instances of unacceptable behavior.
28 |
29 | Project maintainers have the right and responsibility to remove, edit, or reject comments, commits, code, wiki edits, issues, and other contributions that are not aligned to this Code of Conduct, or to ban temporarily or permanently any contributor for other behaviors that they deem inappropriate, threatening, offensive, or harmful.
30 |
31 | ## Scope
32 |
33 | This Code of Conduct applies both within project spaces and in public spaces when an individual is representing the project or its community. Examples of representing a project or community include using an official project e-mail address, posting via an official social media account, or acting as an appointed representative at an online or offline event. Representation of a project may be further defined and clarified by project maintainers.
34 |
35 | ## Attribution
36 |
37 | This Code of Conduct is adapted from the [Contributor Covenant][homepage], version 1.4, available at [http://contributor-covenant.org/version/1/4][version]
38 |
39 | [homepage]: http://contributor-covenant.org
40 | [version]: http://contributor-covenant.org/version/1/4/
41 |
--------------------------------------------------------------------------------
/CONTRIBUTING.md:
--------------------------------------------------------------------------------
1 | # Welcome along to the Undercover Toolbox!
2 |
3 | All our tools are open source and we're always keen to welcome new contributers aboard and hear your ideas. Please feel free to report bugs, request new features or code things yourself.
4 |
5 | ## Report Bugs
6 |
7 | If you happen to stumble across any bugs in our code (however unlikley we know that is), please feel raise an issue for it an we'll look into it.
8 |
9 | When raising an issue, please...
10 | Detail the script or tool that you're referring to.
11 | Give a full description of the bug including any error messages that you've recieved.
12 | Detail the version of SQL Server that you're running.
13 | If possible, the line of code where the bug occurs.
14 |
15 | The more information that you can give us, the better chance we've got of replicating the problem and fixing it.
16 |
17 | ## Request New Features
18 |
19 | If you think of a new feature that you'd like to see included in any of our tools please raise it as an issue. We'll take a look at it and if we like what you're suggesting, we'll look at incorporating it into a future release.
20 |
21 | Before requesting any new features, please check our open issues to make sure that your idea is original and not something that we're already working on.
22 |
23 | ## Submitting Changes and Features
24 |
25 | If you've got a new feature that you'd like to see added you've got a much better chance of getting it in if you can code it yourself. Now, that's now because we're lazy but because we're all very busy working on private work, spending time with our families and working on our own Undercover projects.
26 |
27 | #### Please, before starting work on any code, raise the change as an issue
28 |
29 | We'll have a look at what you're suggesting and if we like the idea then we'll give you the green light.
30 |
31 |
--------------------------------------------------------------------------------
/CatagoryControlledAgentJobs.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Managing Agent Jobs on Availability Group Servers
3 | David Fowler
4 | 16/01/2020
5 |
6 | MIT License
7 | ------------
8 |
9 | Copyright 2020 Sql Undercover
10 |
11 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
12 | (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
13 | publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
14 | subject to the following conditions:
15 |
16 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
17 |
18 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
19 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
20 | FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
21 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
22 |
23 | */
24 |
25 | --category enabeld jobs
26 |
27 | ------------------------------------------------------------------------------------------------------------------------------
28 |
29 | --create job categories
30 |
31 | IF OBJECT_ID('tempdb..#Cats') IS NOT NULL
32 | DROP TABLE #Cats
33 |
34 | IF OBJECT_ID('tempdb..#Cmds') IS NOT NULL
35 | DROP TABLE #Cmds
36 |
37 | --create temp tables
38 | CREATE TABLE #Cats
39 | (CatName VARCHAR(35))
40 |
41 | CREATE TABLE #Cmds
42 | (Cmd VARCHAR(4000))
43 |
44 | --insert category prefixes
45 | INSERT INTO #Cats
46 | VALUES ('Execute On Primary Only: '),
47 | ('Execute On Secondary Only: '),
48 | ('Execute On All Nodes: ')
49 |
50 | --fetch all ags and build up category names
51 | INSERT INTO #Cmds
52 | SELECT 'EXEC msdb.dbo.sp_add_category @class=N''JOB'', @type=N''LOCAL'', @name=N''' + CatName + name + ''''
53 | from sys.availability_groups, #Cats
54 |
55 | INSERT INTO #Cmds
56 | SELECT 'EXEC msdb.dbo.sp_add_category @class=N''JOB'', @type=N''LOCAL'', @name=N''' + CatName + 'All AGs'''
57 | from #Cats
58 |
59 | INSERT INTO #Cmds
60 | VALUES ('EXEC msdb.dbo.sp_add_category @class=N''JOB'', @type=N''LOCAL'', @name=N''Execute On Disabled''')
61 |
62 |
63 |
64 | --cursor for commands
65 | DECLARE CmdCur CURSOR FOR
66 | SELECT Cmd
67 | FROM #Cmds
68 |
69 | DECLARE @Command VARCHAR(4000)
70 |
71 | OPEN CmdCur
72 |
73 | FETCH NEXT FROM CmdCur INTO @Command
74 |
75 | WHILE @@FETCH_STATUS = 0
76 | BEGIN
77 | EXEC (@Command)
78 | FETCH NEXT FROM CmdCur INTO @Command
79 | END
80 |
81 | CLOSE CmdCur
82 | DEALLOCATE CmdCur
83 |
84 |
85 | ------------------------------------------------------------------------------------------------
86 | ------------------------------Create Enable\Disable Proc----------------------------------------
87 | ------------------------------------------------------------------------------------------------
88 |
89 | USE master
90 | GO
91 |
92 | --create maintenance schema is not already exists
93 |
94 | CREATE PROC EnableDisableJobs
95 | AS
96 |
97 | BEGIN
98 |
99 | IF OBJECT_ID('tempdb..#JobList') IS NOT NULL
100 | DROP TABLE #JobList
101 |
102 | CREATE TABLE #JobList
103 | (JobId UNIQUEIDENTIFIER,
104 | AGName SYSNAME,
105 | ReplicaName SYSNAME,
106 | AGRole VARCHAR(120),
107 | AGName_Cat VARCHAR(120),
108 | State_Cat VARCHAR(120),
109 | IsEnabled BIT,
110 | EnableFlag BIT)
111 |
112 |
113 | --get status of AGs and job parameters
114 | INSERT INTO #JobList (JobId,AGName,ReplicaName,AGRole,AGName_Cat,State_Cat,IsEnabled)
115 | SELECT sysjobs.job_id AS JobId,
116 | AGs.name AS AGName,
117 | Replicas.replica_server_name AS ReplicaName,
118 | ReplicaStats.role_desc AS AGRole,
119 | CASE
120 | WHEN syscategories.name = 'Execute On Disabled' THEN 'All AGs'
121 | ELSE SUBSTRING(syscategories.name,CHARINDEX(':',syscategories.name,0) + 2,LEN(syscategories.name))
122 | END AS AGName_Cat,
123 | CASE
124 | WHEN syscategories.name = 'Execute On Disabled' THEN 'Disabled'
125 | ELSE REPLACE(SUBSTRING(syscategories.name,12,CHARINDEX(':',syscategories.name,0) - 12),' Only','')
126 | END AS State_Cat,
127 | sysjobs.enabled
128 | FROM msdb.dbo.sysjobs
129 | JOIN msdb.dbo.syscategories ON syscategories.category_id = sysjobs.category_id,
130 | sys.availability_groups AGs
131 | JOIN sys.availability_replicas Replicas ON AGs.group_id = Replicas.group_id
132 | JOIN sys.dm_hadr_availability_replica_states ReplicaStats ON ReplicaStats.replica_id = Replicas.replica_id
133 | WHERE syscategories.name LIKE 'Execute On%'
134 | AND Replicas.replica_server_name = @@SERVERNAME
135 |
136 |
137 | --remove rows where AGs don't match
138 | DELETE FROM #JobList
139 | WHERE AGName != AGName_Cat
140 | AND AGName_Cat != 'All AGs'
141 |
142 |
143 | --set EnableFlag
144 | UPDATE #JobList
145 | SET EnableFlag = CASE
146 | WHEN State_Cat = 'Disabled' THEN '0'
147 | WHEN State_Cat = 'All Nodes' THEN '1'
148 | WHEN AGrole = State_Cat THEN '1'
149 | WHEN AGrole != State_Cat THEN '0'
150 | END
151 |
152 |
153 | --create alter job statements and cursor through them
154 | DECLARE CmdCur CURSOR STATIC FORWARD_ONLY FOR
155 | SELECT DISTINCT 'USE msdb EXEC sp_update_job @job_id = ''' + CAST(JobId AS VARCHAR(50)) + ''', @Enabled = ' + CAST(EnableFlag AS CHAR(1))
156 | FROM #JobList
157 | WHERE IsEnabled != EnableFlag --ignore jobs that don't need an enable state change
158 |
159 |
160 | OPEN CmdCur
161 |
162 | DECLARE @Cmd VARCHAR(8000)
163 |
164 | FETCH NEXT FROM CmdCur INTO @Cmd
165 |
166 | WHILE @@FETCH_STATUS = 0
167 | BEGIN
168 | EXEC (@cmd)
169 | FETCH NEXT FROM CmdCur INTO @Cmd
170 | END
171 |
172 | CLOSE CmdCur
173 | DEALLOCATE CmdCur
174 |
175 | END
176 |
177 |
178 |
179 | GO
180 |
181 |
182 |
183 | ---------------------------------------------------------------------------------------
184 | ----------------------CREATE ENABLE\DISABLE AGENT JOB----------------------------------
185 | ---------------------------------------------------------------------------------------
186 |
187 | /* ==Scripting Parameters==
188 |
189 | Source Server Version : SQL Server 2012 (11.0.5634)
190 | Source Database Engine Edition : Microsoft SQL Server Enterprise Edition
191 | Source Database Engine Type : Standalone SQL Server
192 |
193 | Target Server Version : SQL Server 2012
194 | Target Database Engine Edition : Microsoft SQL Server Enterprise Edition
195 | Target Database Engine Type : Standalone SQL Server
196 | */
197 |
198 | USE [msdb]
199 | GO
200 |
201 | /****** Object: Job [_Enable\Disable Jobs] Script Date: 6/26/2018 10:26:57 AM ******/
202 | BEGIN TRANSACTION
203 | DECLARE @ReturnCode INT
204 | SELECT @ReturnCode = 0
205 | /****** Object: JobCategory [Execute On All Nodes: All AGs] Script Date: 6/26/2018 10:26:57 AM ******/
206 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Execute On All Nodes: All AGs' AND category_class=1)
207 | BEGIN
208 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Execute On All Nodes: All AGs'
209 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
210 |
211 | END
212 |
213 | DECLARE @jobId BINARY(16)
214 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'_Enable\Disable Jobs',
215 | @enabled=1,
216 | @notify_level_eventlog=0,
217 | @notify_level_email=0,
218 | @notify_level_netsend=0,
219 | @notify_level_page=0,
220 | @delete_level=0,
221 | @description=N'enable or disable agent job dependant on the job''s category',
222 | @category_name=N'Execute On All Nodes: All AGs',
223 | @owner_login_name=N'sa', @job_id = @jobId OUTPUT
224 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
225 | /****** Object: Step [enable or disable jobs] Script Date: 6/26/2018 10:26:57 AM ******/
226 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'enable or disable jobs',
227 | @step_id=1,
228 | @cmdexec_success_code=0,
229 | @on_success_action=1,
230 | @on_success_step_id=0,
231 | @on_fail_action=2,
232 | @on_fail_step_id=0,
233 | @retry_attempts=0,
234 | @retry_interval=0,
235 | @os_run_priority=0, @subsystem=N'TSQL',
236 | @command=N'EXEC EnableDisableJobs',
237 | @database_name=N'master',
238 | @flags=0
239 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
240 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
241 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
242 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'5 minutes',
243 | @enabled=1,
244 | @freq_type=4,
245 | @freq_interval=1,
246 | @freq_subday_type=4,
247 | @freq_subday_interval=5,
248 | @freq_relative_interval=0,
249 | @freq_recurrence_factor=0,
250 | @active_start_date=20180626,
251 | @active_end_date=99991231,
252 | @active_start_time=0,
253 | @active_end_time=235959
254 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
255 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
256 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
257 | COMMIT TRANSACTION
258 | GOTO EndSave
259 | QuitWithRollback:
260 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
261 | EndSave:
262 | GO
263 |
264 |
--------------------------------------------------------------------------------
/Checking your backup paths exist and auto creating them.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 01/09/2017
5 | Version: 1
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | This script is for personal, educational, and internal
11 | corporate purposes, provided that this header is preserved. Redistribution or sale
12 | of this script,in whole or in part, is prohibited without the author's express
13 | written consent.
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 |
23 | ******************************************************************/
24 |
25 |
26 | --variable to hold directory to check
27 | DECLARE @Path VARCHAR(50) = 'O:\SQLUndercover\Backups'
28 |
29 | IF OBJECT_ID('tempdb..#xp_fileexist_Results') IS NOT NULL DROP TABLE #xp_fileexist_Results
30 |
31 | CREATE TABLE #xp_fileexist_Results (
32 | File_Exists int,
33 | File_is_a_Directory int,
34 | Parent_Directory_Exists int
35 | )
36 |
37 | --check if directory exists
38 | INSERT INTO #xp_fileexist_Results
39 | (File_Exists, file_is_a_directory, parent_directory_exists)
40 | EXEC Master.dbo.xp_fileexist @Path
41 |
42 | IF EXISTS (SELECT 1 FROM #xp_fileexist_Results WHERE File_is_a_Directory = 1) --if exists PRINT 'Directory Exists'
43 | PRINT 'Directory Exists'
44 | ELSE --if directory doesn't exist, attempt to create it
45 | BEGIN
46 | EXEC xp_create_subdir @FullPath
47 |
48 | --perform another existance check to make sure that the directory was actually created
49 | TRUNCATE TABLE #xp_fileexist_Results
50 |
51 | INSERT INTO #xp_fileexist_Results
52 | (File_Exists, file_is_a_directory, parent_directory_exists)
53 | EXEC Master.dbo.xp_fileexist @FullPath
54 |
55 | IF EXISTS (SELECT 1 FROM #xp_fileexist_Results WHERE File_is_a_Directory = 1) --if new directory exists PRINT 'Directory Created'
56 | PRINT 'Directory Created'
57 | ELSE
58 | PRINT 'Error Creating Folder' --if new directory doesn't exist then there must have been a problem creating it
59 | END
--------------------------------------------------------------------------------
/DAG Dashboard.pbix:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/DAG Dashboard.pbix
--------------------------------------------------------------------------------
/Data Relay/Writing Your Own Encryption Routines in SQL.pptm:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/Data Relay/Writing Your Own Encryption Routines in SQL.pptm
--------------------------------------------------------------------------------
/Data Relay/~$Writing Your Own Encryption Routines in SQL.pptm:
--------------------------------------------------------------------------------
1 | David Fowler D a v i d F o w l e r
--------------------------------------------------------------------------------
/Database Files Sizes and Growth rates.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: Adrian Buckman
4 | Revision date: 06/09/2017
5 | Version: 1
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | This script is for personal, educational, and internal
11 | corporate purposes, provided that this header is preserved. Redistribution or sale
12 | of this script,in whole or in part, is prohibited without the author's express
13 | written consent.
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 |
23 | ******************************************************************/
24 |
25 |
26 |
27 | SELECT [Database_name],
28 | [DataFilename],
29 | [PhysicalFile_name],
30 | [File_id],
31 | [DatabaseFileSize_MB],
32 | [GrowthRate_MB],
33 | [Is_Percent_Growth],
34 | CASE [GrowthCheck].[is_percent_Growth]
35 | WHEN 1
36 | THEN [Growth]
37 | ELSE 0
38 | END AS [GrowthPercentage%],
39 | [NextGrowth]
40 | FROM
41 | (
42 | SELECT DB_NAME([Masterfiles].[Database_id]) AS [Database_name],
43 | [Masterfiles].[Name] AS [DataFilename],
44 | [MasterFiles].[physical_name] AS [PhysicalFile_name],
45 | [MasterFiles].[File_id],
46 | ((CAST([Size] AS BIGINT) * 8) / 1024) AS [DatabaseFileSize_MB],
47 | CASE [Masterfiles].[is_percent_Growth]
48 | WHEN 0
49 | THEN([Masterfiles].[Growth] * 8) / 1024
50 | WHEN 1
51 | THEN(((CAST([Size] AS BIGINT) * 8) / 1024) * [Growth]) / 100
52 | END AS [GrowthRate_MB],
53 | [Masterfiles].[is_percent_growth],
54 | [Masterfiles].[growth],
55 | CASE [Masterfiles].[is_percent_growth]
56 | WHEN 0
57 | THEN((CAST([Size] AS BIGINT) * 8) / 1024) + ([Growth] * 8) / 1024
58 | WHEN 1
59 | THEN((CAST([Size] AS BIGINT) * 8) / 1024) + (((CAST([Size] AS BIGINT) * 8) / 1024) * [Growth]) / 100
60 | END [NextGrowth]
61 | FROM [SYS].[master_files] [Masterfiles]
62 | INNER JOIN [sys].[databases] [DatabasesList] ON [Masterfiles].[database_id] = [DatabasesList].[database_id]
63 | WHERE [Masterfiles].[Database_ID] > 4 --Ignore System databases
64 | --AND [Type_desc] = 'ROWS' --Data Files only
65 | AND [DatabasesList].State = 0 --Online Databases only
66 | ) [GrowthCheck]
67 | ORDER BY [Database_name] ASC,
68 | [File_ID] ASC;
--------------------------------------------------------------------------------
/Find the primary server of an availability group.ps1:
--------------------------------------------------------------------------------
1 | #Find an availability group's primary server
2 | #set $ServerName to any node that's part of the AG that you're interested in
3 |
4 | $ServerName = 'SQL01'
5 |
6 | [reflection.assembly]::LoadWithPartialName("Microsoft.SqlServer.Smo") | out-null
7 | $svr = New-Object ('Microsoft.SqlServer.Management.Smo.Server') $ServerName;
8 | $svr.ConnectionContext.StatementTimeout = 0;
9 |
10 | foreach ($AvailabilityGroup in $svr.AvailabilityGroups)
11 | {
12 | Write-Host "$($AvailabilityGroup.Name) : $($AvailabilityGroup.PrimaryReplicaServerName)"
13 | }
--------------------------------------------------------------------------------
/Find untrusted Foreign Keys and Orphaned Data (Cross Apply Version).sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: Adrian Buckman
4 | Revision date: 22/10/2017
5 | Version: 1
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | Description: Show Untrusted Foreign key information including Foreign key name, FK table, FK Columns, PK Table , PK Columns reference
11 | Produce SQL Statements to Re enable Untrusted Foreign Keys using @EnableForeignKey = 1 and if these fail to re enable then statements to check the data will be produced.
12 |
13 | This script is for personal, educational, and internal
14 | corporate purposes, provided that this header is preserved. Redistribution or sale
15 | of this script,in whole or in part, is prohibited without the author's express
16 | written consent.
17 |
18 | The software is provided "as is", without warranty of any kind, express or
19 | implied, including but not limited to the warranties of merchantability,
20 | fitness for a particular purpose and noninfringement. in no event shall the
21 | authors or copyright holders be liable for any claim, damages or other
22 | liability, whether in an action of contract, tort or otherwise, arising from,
23 | out of or in connection with the software or the use or other dealings in the
24 | software.
25 |
26 | ******************************************************************/
27 |
28 |
29 |
30 | DECLARE @EnableForeignKey BIT = 1 --1: Produce Enable Foreign key scripts, 0: Produce a script to identify if any Orphaned foreign keys exist
31 |
32 | IF OBJECT_ID('TempDB..#UntrustedFKs') IS NOT NULL
33 | DROP TABLE #UntrustedFKs;
34 |
35 | --Populate the Temp Table with Untrusted Foreign Key information
36 | SELECT DISTINCT [FKeys].[object_id] ,
37 | QUOTENAME([PKSchema].[name])+'.'+QUOTENAME((OBJECT_NAME([FKeys].[referenced_object_id]))) AS [PK_Tablename],
38 | STUFF(
39 | (
40 | SELECT ','+QUOTENAME(COL_NAME([PKCols].[referenced_object_id],[PKCols].[referenced_column_id]))
41 | FROM [sys].[foreign_key_columns] [PKCols]
42 | WHERE [PKCols].[constraint_object_id] = [FKeys].[object_id] FOR XML PATH('')
43 | ),1,1,'') AS [PK_Columns],
44 | QUOTENAME(SCHEMA_NAME([FKeys].[Schema_id]))+'.'+QUOTENAME(OBJECT_NAME([FKeys].[Parent_object_id]))+'.'+QUOTENAME([FKeys].[name]) AS [ForeignKey],
45 | STUFF(
46 | (
47 | SELECT ','+QUOTENAME(COL_NAME([FKCols].[parent_object_id],[FKCols].[parent_column_id]))
48 | FROM [sys].[foreign_key_columns] AS [FKCols]
49 | WHERE [FKCols].[constraint_object_id] = [FKeys].object_id FOR XML PATH('')
50 | ),1,1,'') AS [FK_Columns]
51 | INTO #UntrustedFKs
52 | FROM [sys].[foreign_keys] [FKeys]
53 | LEFT JOIN [sys].[foreign_key_columns] [FKCols] ON [FKeys].[object_id] = [FKCols].[constraint_object_id]
54 | LEFT JOIN [sys].[objects] [PKObject] ON [PKObject].[object_id] = [FKeys].[referenced_object_id]
55 | LEFT JOIN [sys].[schemas] [PKSchema] ON [PKObject].[schema_id] = [PKSchema].[schema_id]
56 | WHERE [FKeys].[is_not_trusted] = 1
57 |
58 | --Build Orphaned Foreign Key Scripts and show Table and Key Relationships
59 | SELECT DISTINCT
60 | CASE
61 | WHEN @EnableForeignKey = 0
62 | THEN
63 | 'SELECT FK.'+REPLACE(FK_Columns,',',' ,FK.')+'
64 | FROM '+PK_Tablename+' PK
65 | RIGHT JOIN '+QUOTENAME(PARSENAME(ForeignKey,3))+'.'+QUOTENAME(PARSENAME(ForeignKey,2))+' FK ON '+[PK_FK_Columns_By_Position]+'
66 | WHERE PK.'+REPLACE(PK_Columns,',',' IS NULL AND PK.')+' IS NULL AND FK.'+REPLACE(FK_Columns,',',' IS NOT NULL AND FK.')+ ' IS NOT NULL
67 | '
68 | ELSE
69 | 'BEGIN TRY
70 | RAISERROR(''Enabling Foreign key '+[ForeignKey]+' WITH CHECK...'',0,0) WITH NOWAIT
71 | ALTER TABLE '+QUOTENAME(PARSENAME(ForeignKey,3))+'.'+QUOTENAME(PARSENAME(ForeignKey,2))+' WITH CHECK CHECK CONSTRAINT '+QUOTENAME(PARSENAME(ForeignKey,1)) +'
72 | END TRY
73 | BEGIN CATCH
74 | RAISERROR(''FAILED: Orphaned FK Data exists for FK - '+[ForeignKey]+ ' , see output for a script to identify the data'',0,0) WITH NOWAIT'+
75 | '
76 | SELECT '''+[ForeignKey]+''' AS Failed_ForeignKey,''SELECT FK.'+REPLACE(FK_Columns,',',' ,FK.')+'
77 | FROM '+PK_Tablename+' PK
78 | RIGHT JOIN '+QUOTENAME(PARSENAME(ForeignKey,3))+'.'+QUOTENAME(PARSENAME(ForeignKey,2))+' FK ON '+[PK_FK_Columns_By_Position]+'
79 | WHERE PK.'+REPLACE(PK_Columns,',',' IS NULL AND PK.')+' IS NULL AND FK.'+REPLACE(FK_Columns,',',' IS NOT NULL AND FK.')+ ' IS NOT NULL'' AS Identify_Orphaned_ForeignKeys_Script
80 | END CATCH
81 |
82 | '
83 | END AS Orphaned_ForeignKeys_Script,
84 | [ForeignKey],
85 | [PK_Tablename],
86 | [PK_Columns],
87 | [FK_Columns]
88 | FROM #UntrustedFKs FKeys
89 |
90 | CROSS APPLY (SELECT STUFF(CAST((
91 | SELECT
92 | (
93 | SELECT DISTINCT
94 | ' AND PK.'+ QUOTENAME(COL_NAME([FKCols].[referenced_object_id],[FKCols].[referenced_column_id])) +
95 | '= FK.'+ QUOTENAME(COL_NAME([FKCols].[parent_object_id],[FKCols].[parent_column_id]))
96 | FROM [sys].[foreign_key_columns] AS [FKCols]
97 | WHERE [FKCols].[constraint_object_id] = [FKeys2].[object_id]
98 | AND [FKCols].[referenced_column_id] = [ReferenceCols].[column_id] FOR XML PATH('')
99 | )
100 | FROM [sys].[foreign_keys] [FKeys2]
101 | LEFT JOIN [sys].[foreign_key_columns] [FKCols] ON [FKeys2].[object_id] = [FKCols].[constraint_object_id]
102 | LEFT JOIN [sys].[all_columns] [ReferenceCols] ON [FKCols].[referenced_object_id] = [ReferenceCols].[object_id]
103 | AND [FKCols].[referenced_column_id] = [ReferenceCols].[column_id]
104 | WHERE [Fkeys].[Object_Id] = [FKeys2].[object_id]
105 | FOR XML PATH(''),TYPE)
106 | AS NVARCHAR(1000)),1,5,'') AS [PK_FK_Columns_By_Position]) AS PKFKCRelCols
--------------------------------------------------------------------------------
/Find untrusted Foreign Keys and Orphaned Data (Cursor Version).sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: Adrian Buckman
4 | Revision date: 22/10/201
5 | Version: 1
6 |
7 | Description: Show Untrusted Foreign key information including Foreign key name, FK table, FK Columns, PK Table , PK Columns reference
8 | Produce SQL Statements to Re enable Untrusted Foreign Keys using @EnableForeignKey = 1 and if these fail to re enable then statements to check the data will be produced.
9 |
10 | © www.sqlundercover.com
11 |
12 |
13 | This script is for personal, educational, and internal
14 | corporate purposes, provided that this header is preserved. Redistribution or sale
15 | of this script,in whole or in part, is prohibited without the author's express
16 | written consent.
17 |
18 | The software is provided "as is", without warranty of any kind, express or
19 | implied, including but not limited to the warranties of merchantability,
20 | fitness for a particular purpose and noninfringement. in no event shall the
21 | authors or copyright holders be liable for any claim, damages or other
22 | liability, whether in an action of contract, tort or otherwise, arising from,
23 | out of or in connection with the software or the use or other dealings in the
24 | software.
25 |
26 | ******************************************************************/
27 |
28 |
29 |
30 | DECLARE @EnableForeignKey BIT = 1 -- 1: Produce Enable Foreign key scripts, 0: Produce a script to identify if any Orphaned foreign keys exist
31 | DECLARE @SortBy TINYINT = 3 --Order by Column number specify a value from 1-5
32 |
33 | DECLARE @ColumnName NVARCHAR(128)
34 | DECLARE @FKObjectID INT
35 | DECLARE @PKFKCRels NVARCHAR(1000)
36 |
37 | SET NOCOUNT ON;
38 |
39 | SET @ColumnName = CHOOSE(@SortBy,'Orphaned_ForeignKeys_Script','ForeignKey','PK_Tablename','PK_Columns','FK_Columns')
40 | IF @ColumnName IS NOT NULL
41 | BEGIN
42 |
43 | IF OBJECT_ID('TempDB..#OutputList') IS NOT NULL
44 | DROP TABLE #OutputList;
45 |
46 | CREATE TABLE #OutputList
47 | (
48 | ID INT IDENTITY(1,1),
49 | Orphaned_ForeignKeys_Script NVARCHAR(4000),
50 | ForeignKey NVARCHAR(1000),
51 | PK_Tablename NVARCHAR(256),
52 | PK_Columns NVARCHAR(1000),
53 | FK_Columns NVARCHAR(1000)
54 | );
55 |
56 | --Cursor through all non trusted Foreign keys
57 | DECLARE FK_Cur CURSOR STATIC FORWARD_ONLY LOCAL
58 | FOR
59 |
60 | SELECT
61 | [Object_id]
62 | FROM [sys].[foreign_keys] [FKeys]
63 | WHERE [FKeys].[is_not_trusted] = 1
64 |
65 | OPEN FK_Cur
66 |
67 | FETCH NEXT FROM FK_Cur INTO @FKObjectID
68 |
69 | WHILE @@FETCH_STATUS = 0
70 |
71 | BEGIN
72 |
73 | DECLARE @PKFKCRelCols NVARCHAR(1000) = ''
74 |
75 | --For each non trusted Foreign key Match each Foreign key column with it's Referenced PK counterpart
76 | DECLARE Column_Cur CURSOR FORWARD_ONLY LOCAL
77 | FOR
78 | SELECT
79 | (
80 | SELECT
81 | 'PK.'+ QUOTENAME(COL_NAME([FKCols].[referenced_object_id],[FKCols].[referenced_column_id])) +
82 | '= FK.'+ QUOTENAME(COL_NAME([FKCols].[parent_object_id],[FKCols].[parent_column_id])) + ' AND '
83 | FROM [sys].[foreign_key_columns] AS [FKCols]
84 | WHERE [FKCols].[constraint_object_id] = [FKeys].[object_id]
85 | AND [FKCols].[referenced_column_id] = [ReferenceCols].[column_id] FOR XML PATH('')
86 | ) AS [PK_FK_Columns_By_Position]
87 |
88 | FROM [sys].[foreign_keys] [FKeys]
89 | LEFT JOIN [sys].[foreign_key_columns] [FKCols] ON [FKeys].[object_id] = [FKCols].[constraint_object_id]
90 | LEFT JOIN [sys].[all_columns] [ReferenceCols] ON [FKCols].[referenced_object_id] = [ReferenceCols].[object_id]
91 | AND [FKCols].[referenced_column_id] = [ReferenceCols].[column_id]
92 | WHERE [FKeys].[object_id] = @FKObjectID
93 |
94 | OPEN Column_Cur
95 |
96 | FETCH NEXT FROM Column_Cur INTO @PKFKCRels
97 |
98 | WHILE @@FETCH_STATUS = 0
99 |
100 | BEGIN
101 |
102 | --Build a list of columns including Aliases and 'AND' clauses to be used in the joins in the scripted output
103 | SET @PKFKCRelCols = @PKFKCRelCols + @PKFKCRels
104 |
105 | FETCH NEXT FROM Column_Cur INTO @PKFKCRels
106 |
107 | END
108 |
109 | CLOSE Column_Cur
110 | DEALLOCATE Column_Cur
111 |
112 | --Strip additional AND added from the cursor above
113 | SET @PKFKCRelCols = LEFT(@PKFKCRelCols,LEN(@PKFKCRelCols)-4)
114 |
115 | --Build the Orphaned Foreign keys script output and include additional columns that show the Foreign key name, the PK table name, PK columns and FK columns
116 | INSERT INTO #OutputList (Orphaned_ForeignKeys_Script, ForeignKey, PK_Tablename, PK_Columns,FK_Columns)
117 | SELECT DISTINCT
118 | CASE
119 | WHEN @EnableForeignKey = 0
120 | THEN
121 | 'SELECT FK.'+REPLACE(FK_Columns,',',' ,FK.')+'
122 | FROM '+PK_Tablename+' PK
123 | RIGHT JOIN '+QUOTENAME(PARSENAME(ForeignKey,3))+'.'+QUOTENAME(PARSENAME(ForeignKey,2))+' FK ON '+@PKFKCRelCols+'
124 | WHERE PK.'+REPLACE(PK_Columns,',',' IS NULL AND PK.')+' IS NULL AND FK.'+REPLACE(FK_Columns,',',' IS NOT NULL AND FK.')+ ' IS NOT NULL
125 | '
126 | ELSE
127 | 'BEGIN TRY
128 | RAISERROR(''Enabling Foreign key '+[ForeignKey]+' WITH CHECK...'',0,0) WITH NOWAIT
129 | ALTER TABLE '+QUOTENAME(PARSENAME(ForeignKey,3))+'.'+QUOTENAME(PARSENAME(ForeignKey,2))+' WITH CHECK CHECK CONSTRAINT '+QUOTENAME(PARSENAME(ForeignKey,1)) +'
130 | END TRY
131 | BEGIN CATCH
132 | RAISERROR(''FAILED: Orphaned FK Data exists for FK - '+[ForeignKey]+ ' , see output for a script to identify the data'',0,0) WITH NOWAIT'+
133 | '
134 | SELECT '''+[ForeignKey]+''' AS Failed_ForeignKey,''SELECT FK.'+REPLACE(FK_Columns,',',' ,FK.')+'
135 | FROM '+PK_Tablename+' PK
136 | RIGHT JOIN '+QUOTENAME(PARSENAME(ForeignKey,3))+'.'+QUOTENAME(PARSENAME(ForeignKey,2))+' FK ON '+@PKFKCRelCols+'
137 | WHERE PK.'+REPLACE(PK_Columns,',',' IS NULL AND PK.')+' IS NULL AND FK.'+REPLACE(FK_Columns,',',' IS NOT NULL AND FK.')+ ' IS NOT NULL'' AS Identify_Orphaned_ForeignKeys_Script
138 | END CATCH
139 |
140 | '
141 | END AS Orphaned_ForeignKeys_Script,
142 | [ForeignKey],
143 | [PK_Tablename],
144 | [PK_Columns],
145 | [FK_Columns]
146 | FROM
147 | (
148 | SELECT
149 | QUOTENAME([PKSchema].[name])+'.'+QUOTENAME((OBJECT_NAME([FKeys].[referenced_object_id]))) AS [PK_Tablename],
150 | STUFF(
151 | (
152 | SELECT ','+QUOTENAME(COL_NAME([PKCols].[referenced_object_id],[PKCols].[referenced_column_id]))
153 | FROM [sys].[foreign_key_columns] [PKCols]
154 | WHERE [PKCols].[constraint_object_id] = [FKeys].[object_id] FOR XML PATH('')
155 | ),1,1,'') AS [PK_Columns],
156 | QUOTENAME(SCHEMA_NAME([FKeys].[Schema_id]))+'.'+QUOTENAME(OBJECT_NAME([FKeys].[Parent_object_id]))+'.'+QUOTENAME([FKeys].[name]) AS [ForeignKey],
157 | STUFF(
158 | (
159 | SELECT ','+QUOTENAME(COL_NAME([FKCols].[parent_object_id],[FKCols].[parent_column_id]))
160 | FROM [sys].[foreign_key_columns] AS [FKCols]
161 | WHERE [FKCols].[constraint_object_id] = [FKeys].object_id FOR XML PATH('')
162 | ),1,1,'') AS [FK_Columns]
163 | FROM [sys].[foreign_keys] [FKeys]
164 | LEFT JOIN [sys].[foreign_key_columns] [FKCols] ON [FKeys].[object_id] = [FKCols].[constraint_object_id]
165 | LEFT JOIN [sys].[objects] [PKObject] ON [PKObject].[object_id] = [FKeys].[referenced_object_id]
166 | LEFT JOIN [sys].[schemas] [PKSchema] ON [PKObject].[schema_id] = [PKSchema].[schema_id]
167 | WHERE [FKeys].[object_id] = @FKObjectID
168 | ) DERIVED;
169 |
170 | FETCH NEXT FROM FK_Cur INTO @FKObjectID
171 |
172 | END
173 |
174 | CLOSE FK_Cur
175 | DEALLOCATE FK_Cur
176 |
177 | EXEC (
178 | N'SELECT
179 | Orphaned_ForeignKeys_Script,
180 | ForeignKey,
181 | PK_Tablename,
182 | PK_Columns,
183 | FK_Columns
184 | FROM #OutputList
185 | ORDER BY '+@ColumnName+' ASC')
186 |
187 | END
188 | ELSE
189 | BEGIN
190 | RAISERROR('Invalid @Sortby Value set , only enter values ranging from 1 - 5 inclusive',11,0)
191 | END
--------------------------------------------------------------------------------
/Generate a Temporary table definition to match a resultset.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 21/08/2017
5 | Version: 1
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | This script is for personal, educational, and internal
11 | corporate purposes, provided that this header is preserved. Redistribution or sale
12 | of this script,in whole or in part, is prohibited without the author's express
13 | written consent.
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 |
23 | ******************************************************************/
24 |
25 | SET NOCOUNT ON
26 |
27 | DECLARE @Query VARCHAR(MAX) = 'select * from sys.databases'
28 | DECLARE @TempTableName VARCHAR(128) = '#temptable'
29 | DECLARE @ColumnList VARCHAR(MAX)
30 |
31 | SELECT @ColumnList = STUFF((SELECT ',' + name + ' ' + system_type_name + ' ' +
32 | CASE is_nullable WHEN 0 THEN 'NOT NULL' ELSE 'NULL' END
33 | + CHAR(10)
34 | FROM sys.dm_exec_describe_first_result_set(@Query, NULL, 0)
35 | FOR XML PATH('')) ,1,1,'')
36 |
37 | PRINT 'CREATE TABLE ' + @TempTableName + '('
38 | PRINT @ColumnList
39 | PRINT(')')
--------------------------------------------------------------------------------
/GroupBy/Writing Your Own Encryption Routines in SQL.pptm:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/GroupBy/Writing Your Own Encryption Routines in SQL.pptm
--------------------------------------------------------------------------------
/GroupBy/WritingYouOwnEncryption_demos.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/GroupBy/WritingYouOwnEncryption_demos.sql
--------------------------------------------------------------------------------
/High Severity Alert Notifications.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/High Severity Alert Notifications.sql
--------------------------------------------------------------------------------
/How far has my update got.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 05/10/2017
5 | Version: 1
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | This script is for personal, educational, and internal
11 | corporate purposes, provided that this header is preserved. Redistribution or sale
12 | of this script,in whole or in part, is prohibited without the author's express
13 | written consent.
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 |
23 | ******************************************************************/
24 |
25 |
26 | DECLARE @SPID INT = 54
27 |
28 | SELECT COUNT(*)--fn_dblog.*
29 | FROM fn_dblog(null,null)
30 | WHERE
31 | operation IN ('LOP_MODIFY_ROW', 'LOP_INSERT_ROWS','LOP_DELETE_ROWS') AND
32 | context IN ('LCX_HEAP', 'LCX_CLUSTERED') AND
33 | [Transaction ID] =
34 | (SELECT fn_dblog.[Transaction ID]
35 | FROM sys.dm_tran_session_transactions session_trans
36 | JOIN fn_dblog(null,null) ON fn_dblog.[Xact ID] = session_trans.transaction_id
37 | WHERE session_id = @SPID)
--------------------------------------------------------------------------------
/LICENSE.md:
--------------------------------------------------------------------------------
1 | ## MIT License
2 |
3 | ## Copyright (c) 2018 SQL Undercover
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 |
23 |
--------------------------------------------------------------------------------
/LSNCheck and FileExistence_CS.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/LSNCheck and FileExistence_CS.sql
--------------------------------------------------------------------------------
/Open Transaction Details.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/Open Transaction Details.sql
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # SQL Undercover Toolbox
2 |
3 | The SQL Undercover Toolbox comprises of a collection of scripts, stored procedures and functions designed to make your life as a DBA easier.
4 |
5 | ## Documentation
6 | Full documentation can be found on [sqlundercover.com](https://sqlundercover.com). URLs for each script can be found in the script's header.
7 |
8 | ## License
9 | All SQL Undercover Toolbox scripts are released under the [MIT license](https://github.com/SQLUndercover/UndercoverToolbox/blob/master/LICENSE.md)
10 |
--------------------------------------------------------------------------------
/Resend_an_email.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/Resend_an_email.sql
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetADGroups.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: ADGroups
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 | DECLARE @GroupName SYSNAME
10 |
11 | --create temp table to hold results from xp_logininfo
12 | IF OBJECT_ID('tempdb.dbo.#LoginInfo') IS NOT NULL
13 | DROP TABLE #LoginInfo
14 |
15 | CREATE TABLE #LoginInfo
16 | (accountname SYSNAME NULL,
17 | type CHAR(8) NULL,
18 | privilege CHAR(9) NULL,
19 | mappedloginname SYSNAME NULL,
20 | permissionpath SYSNAME NULL)
21 |
22 | --create temp table to hold final results
23 | IF OBJECT_ID('tempdb.dbo.#FinalResults') IS NOT NULL
24 | DROP TABLE #FinalResults
25 |
26 | CREATE TABLE #FinalResults(
27 | GroupName SYSNAME NOT NULL,
28 | AccountName SYSNAME NOT NULL,
29 | AccountType CHAR(8) NOT NULL)
30 |
31 |
32 | --cursor to hold all windows groups
33 |
34 | DECLARE GroupsCur CURSOR FAST_FORWARD LOCAL FOR
35 | SELECT name
36 | FROM sys.server_principals
37 | WHERE type_desc = 'WINDOWS_GROUP'
38 |
39 | OPEN GroupsCur
40 |
41 | FETCH NEXT FROM GroupsCur INTO @GroupName
42 |
43 | WHILE @@FETCH_STATUS = 0
44 | BEGIN
45 | TRUNCATE TABLE #LoginInfo --truncate work table to prevent data from previous loop being carried through
46 |
47 | DECLARE @SQL VARCHAR(100)
48 | SET @SQL = 'EXEC xp_logininfo ''' + @GroupName + ''', ''members'''
49 |
50 | --populate #LoginInfo
51 | BEGIN TRY
52 | INSERT INTO #LoginInfo
53 | EXEC (@SQL)
54 | END TRY
55 | BEGIN CATCH --catch if there's an issue evaluating the group for some reason
56 | INSERT INTO #LoginInfo (accountname, type)
57 | VALUES (@GroupName, '*ERROR*')
58 | END CATCH
59 |
60 | --append to final results temp table
61 | INSERT INTO #FinalResults (GroupName,AccountName,AccountType)
62 | SELECT @GroupName, accountname, type
63 | FROM #LoginInfo
64 |
65 | FETCH NEXT FROM GroupsCur INTO @GroupName
66 | END
67 |
68 | SELECT GroupName,AccountName,AccountType
69 | FROM #FinalResults
70 |
71 | END
72 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetAgentJobs.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: AgentJobs
5 | --Script: Get
6 |
7 | BEGIN
8 | --get all agent jobs on server
9 | SELECT @@SERVERNAME AS ServerName,
10 | sysjobs.job_id AS JobID,
11 | sysjobs.name AS JobName,
12 | sysjobs.enabled AS Enabled,
13 | sysjobs.description AS Description,
14 | syscategories.name AS Category,
15 | sysjobs.date_created AS DateCreated,
16 | sysjobs.date_modified AS DateModified,
17 | sysschedules.enabled AS ScheduleEnabled,
18 | sysschedules.name AS ScheduleName,
19 | CASE freq_type
20 | WHEN 1 THEN 'Occurs on ' + STUFF(RIGHT(active_start_date, 4), 3,0, '/') + '/' + LEFT(active_start_date, 4) + ' at '
21 | + REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime) /* hh:mm:ss 24H */, 9), 14), ':000', ' ') /* HH:mm:ss:000AM/PM then replace the :000 with space.*/
22 | WHEN 4 THEN 'Occurs every ' + CAST(freq_interval as varchar(10)) + ' day(s) '
23 | + CASE freq_subday_type
24 | WHEN 1 THEN 'at '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
25 | WHEN 2 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' second(s)'
26 | WHEN 4 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' minute(s)'
27 | WHEN 8 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' hour(s)'
28 | ELSE ''
29 | END
30 | + CASE WHEN freq_subday_type in (2,4,8) /* repeat seconds/mins/hours */
31 | THEN ' between '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
32 | + ' and '
33 | + LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_end_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
34 | ELSE ''
35 | END
36 | WHEN 8 THEN 'Occurs every ' + CAST(freq_recurrence_factor as varchar(10))
37 | + ' week(s) on '
38 | +
39 | REPLACE( CASE WHEN freq_interval&1 = 1 THEN 'Sunday, ' ELSE '' END
40 | + CASE WHEN freq_interval&2 = 2 THEN 'Monday, ' ELSE '' END
41 | + CASE WHEN freq_interval&4 = 4 THEN 'Tuesday, ' ELSE '' END
42 | + CASE WHEN freq_interval&8 = 8 THEN 'Wednesday, ' ELSE '' END
43 | + CASE WHEN freq_interval&16 = 16 THEN 'Thursday, ' ELSE '' END
44 | + CASE WHEN freq_interval&32 = 32 THEN 'Friday, ' ELSE '' END
45 | + CASE WHEN freq_interval&64 = 64 THEN 'Saturday, ' ELSE '' END
46 | + '|', ', |', ' ') /* get rid of trailing comma */
47 |
48 | + CASE freq_subday_type
49 | WHEN 1 THEN 'at '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
50 | WHEN 2 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' second(s)'
51 | WHEN 4 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' minute(s)'
52 | WHEN 8 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' hour(s)'
53 | ELSE ''
54 | END
55 | + CASE WHEN freq_subday_type in (2,4,8) /* repeat seconds/mins/hours */
56 | THEN ' between '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
57 | + ' and '
58 | + LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_end_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
59 | ELSE ''
60 | END
61 | WHEN 16 THEN 'Occurs every ' + CAST(freq_recurrence_factor as varchar(10))
62 | + ' month(s) on '
63 | + 'day ' + CAST(freq_interval as varchar(10)) + ' of that month '
64 | + CASE freq_subday_type
65 | WHEN 1 THEN 'at '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
66 | WHEN 2 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' second(s)'
67 | WHEN 4 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' minute(s)'
68 | WHEN 8 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' hour(s)'
69 | ELSE ''
70 | END
71 | + CASE WHEN freq_subday_type in (2,4,8) /* repeat seconds/mins/hours */
72 | THEN ' between '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
73 | + ' and '
74 | + LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_end_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
75 | ELSE ''
76 | END
77 | WHEN 32 THEN 'Occurs '
78 | + CASE freq_relative_interval
79 | WHEN 1 THEN 'every first '
80 | WHEN 2 THEN 'every second '
81 | WHEN 4 THEN 'every third '
82 | WHEN 8 THEN 'every fourth '
83 | WHEN 16 THEN 'on the last '
84 | END
85 | + CASE freq_interval
86 | WHEN 1 THEN 'Sunday'
87 | WHEN 2 THEN 'Monday'
88 | WHEN 3 THEN 'Tuesday'
89 | WHEN 4 THEN 'Wednesday'
90 | WHEN 5 THEN 'Thursday'
91 | WHEN 6 THEN 'Friday'
92 | WHEN 7 THEN 'Saturday'
93 | WHEN 8 THEN 'day'
94 | WHEN 9 THEN 'weekday'
95 | WHEN 10 THEN 'weekend'
96 | END
97 | + ' of every ' + CAST(freq_recurrence_factor as varchar(10)) + ' month(s) '
98 | + CASE freq_subday_type
99 | WHEN 1 THEN 'at '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
100 | WHEN 2 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' second(s)'
101 | WHEN 4 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' minute(s)'
102 | WHEN 8 THEN 'every ' + CAST(freq_subday_interval as varchar(10)) + ' hour(s)'
103 | ELSE ''
104 | END
105 | + CASE
106 | WHEN freq_subday_type in (2,4,8) /* repeat seconds/mins/hours */
107 | THEN ' between '+ LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_start_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
108 | + ' and '
109 | + LTRIM(REPLACE( RIGHT(CONVERT(varchar(30), CAST(convert(varchar(8), STUFF(STUFF(RIGHT('000000' + CAST(active_end_time as varchar(10)), 6), 3, 0, ':' ), 6, 0, ':' ), 8) as datetime), 9), 14), ':000', ' '))
110 | ELSE ''
111 | END
112 | WHEN 64 THEN 'Runs when the SQL Server Agent service starts'
113 | WHEN 128 THEN 'Runs when the computer is idle'
114 | END
115 | AS ScheduleFrequency,
116 | sysjobsteps.step_id AS StepID,
117 | sysjobsteps.step_name AS StepName,
118 | sysjobsteps.subsystem AS SubSystem,
119 | sysjobsteps.command AS Command,
120 | sysjobsteps.database_name AS DatabaseName
121 | FROM msdb.dbo.sysjobs
122 | JOIN msdb.dbo.syscategories ON sysjobs.category_id = syscategories.category_id
123 | JOIN msdb.dbo.sysjobschedules ON sysjobs.job_id = sysjobschedules.job_id
124 | JOIN msdb.dbo.sysschedules ON sysjobschedules.schedule_id = sysschedules.schedule_id
125 | JOIN msdb.dbo.sysjobsteps ON sysjobsteps.job_id = sysjobs.job_id
126 | END
127 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetAvailabilityGroups.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: AvailabilityGroups
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 | --Get availability group details
10 | SELECT AGs.name AS AGName,
11 | replicas.replica_server_name AS ServerName,
12 | replica_states.role_desc AS Role,
13 | AGs.automated_backup_preference_desc AS BackupPreference,
14 | replicas.availability_mode_desc AS AvailabilityMode,
15 | replicas.failover_mode_desc AS FailoverMode,
16 | replicas.secondary_role_allow_connections_desc AS ConnectionsToSecondary
17 | FROM sys.availability_groups AGs
18 | JOIN sys.availability_replicas replicas ON replicas.group_id = AGs.group_id
19 | JOIN sys.dm_hadr_availability_replica_states replica_states ON replica_states.replica_id = replicas.replica_id
20 |
21 | END
22 |
23 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetCluster.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.2 - 07 February 2020
4 | --Module: Cluster
5 | --Script: Get
6 |
7 | SELECT cluster_name AS ClusterName,
8 | quorum_type_desc AS QuorumType,
9 | quorum_state_desc AS QuorumState,
10 | member_name AS MemberName,
11 | member_type_desc AS MemberType,
12 | number_of_quorum_votes AS QuorumVotes
13 | FROM sys.dm_hadr_cluster
14 | ,sys.dm_hadr_cluster_members
15 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetDatabases.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.5 - 10 September 2024
4 | --Module: Databases
5 | --Script: Get
6 | BEGIN
7 | --get all databases on server
8 | SELECT @@SERVERNAME AS ServerName
9 | ,databases.name AS DBName
10 | ,databases.database_id AS DatabaseID
11 | ,server_principals.name AS OwnerName
12 | ,databases.compatibility_level AS CompatibilityLevel
13 | ,databases.collation_name AS CollationName
14 | ,databases.recovery_model_desc AS RecoveryModelDesc
15 | ,availability_groups.name AS AGName
16 | ,files.FilePaths
17 | ,files.DatabaseSizeMB
18 | ,databases.state_desc AS StateDesc
19 | ,lastaccess.last_user_access
20 | FROM sys.databases
21 | LEFT OUTER JOIN sys.server_principals ON server_principals.sid = databases.owner_sid
22 | LEFT OUTER JOIN sys.availability_replicas ON availability_replicas.replica_id = databases.replica_id
23 | LEFT OUTER JOIN sys.availability_groups ON availability_groups.group_id = availability_replicas.group_id
24 | JOIN (
25 | SELECT database_id
26 | ,(SUM(CAST(size AS BIGINT)) * 8) / 1024 AS DatabaseSizeMB
27 | ,STUFF((
28 | SELECT ' ,' + files2.physical_name
29 | FROM sys.master_files files2
30 | WHERE files2.database_id = files1.database_id
31 | FOR XML PATH('')
32 | ), 1, 2, '') AS FilePaths
33 | FROM sys.master_files files1
34 | GROUP BY database_id
35 | ) files ON files.database_id = databases.database_id
36 | JOIN (
37 | SELECT db_name(databases.database_id) AS DBName
38 | ,(
39 | SELECT MAX(last_user_access)
40 | FROM (
41 | VALUES (MAX(last_user_seek))
42 | ,(MAX(last_user_scan))
43 | ,(MAX(last_user_lookup))
44 | ) AS value(last_user_access)
45 | ) AS last_user_access
46 | FROM sys.dm_db_index_usage_stats indexstats
47 | RIGHT OUTER JOIN sys.databases databases ON indexstats.database_id = databases.database_id
48 | GROUP BY databases.database_id
49 | ) AS lastaccess ON databases.name = lastaccess.DBName
50 | WHERE databases.source_database_id IS NULL
51 | END
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetDatabases2008.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Databases (2008 Compatability)
5 | --Script: Get
6 |
7 | --Please note that this is an unsupported module and is provided as is
8 |
9 | BEGIN
10 | --get all databases on server
11 |
12 | SELECT @@SERVERNAME AS ServerName,
13 | databases.name AS DBName,
14 | databases.database_id AS DatabaseID,
15 | server_principals.name AS OwnerName,
16 | databases.compatibility_level AS CompatibilityLevel,
17 | databases.collation_name AS CollationName,
18 | databases.recovery_model_desc AS RecoveryModelDesc,
19 | NULL AS AGName,
20 | files.FilePaths,
21 | files.DatabaseSizeMB,
22 | databases.state_desc AS StateDesc
23 | FROM sys.databases
24 | LEFT OUTER JOIN sys.server_principals ON server_principals.sid = databases.owner_sid
25 | --LEFT OUTER JOIN sys.availability_replicas ON availability_replicas.replica_id = databases.replica_id
26 | --LEFT OUTER JOIN sys.availability_groups ON availability_groups.group_id = availability_replicas.group_id
27 | JOIN (SELECT database_id, (SUM(CAST (size AS BIGINT)) * 8)/1024 AS DatabaseSizeMB,STUFF((SELECT ', ' + files2.physical_name
28 | FROM sys.master_files files2
29 | WHERE files2.database_id = files1.database_id
30 | FOR XML PATH('')
31 | ), 1, 2, '') AS FilePaths
32 | FROM sys.master_files files1
33 | GROUP BY database_id) files ON files.database_id = databases.database_id
34 | END
35 |
36 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetExplicitPermissions.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: ExplicitPermissions
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 | DECLARE @DBName SYSNAME
10 | DECLARE @cmd NVARCHAR(4000)
11 |
12 | IF OBJECT_ID('tempdb.dbo.#ExplicitPermissions_tmp') IS NOT NULL
13 | DROP TABLE #ExplicitPermissions_tmp
14 |
15 | --create temp table to bulid up result set
16 | CREATE TABLE #ExplicitPermissions_tmp(
17 | [Name] [sysname] NOT NULL,
18 | [PermissionName] [nvarchar](128) NULL,
19 | [StateDesc] [nvarchar](60) NULL,
20 | [ServerName] [nvarchar](128) NULL,
21 | [DBName] [nvarchar](128) NULL,
22 | [MajorObject] [nvarchar](128) NULL,
23 | [MinorObject] [nvarchar](128) NULL)
24 |
25 |
26 | --cursor to cycle through all databases on the server
27 | DECLARE DBCur CURSOR FOR
28 | SELECT [name]
29 | FROM sys.databases
30 |
31 | OPEN DBCur
32 |
33 | FETCH NEXT FROM DBCur INTO @DBName
34 |
35 | WHILE @@FETCH_STATUS = 0
36 | BEGIN
37 |
38 | --get all permissions for the selected database
39 | BEGIN TRY
40 | SET @cmd =
41 | 'USE ' + QUOTENAME(@DBName) + '
42 |
43 | SELECT database_principals.name,
44 | database_permissions.permission_name,
45 | database_permissions.state_desc,
46 | @@SERVERNAME AS ServerName,
47 | DB_Name() AS DBName,
48 | OBJECT_NAME(database_permissions.major_id) AS MajorObject,
49 | OBJECT_NAME(database_permissions.minor_id) AS MinorObject
50 | FROM sys.database_principals
51 | JOIN sys.database_permissions ON database_principals.principal_id = database_permissions.grantee_principal_id
52 | WHERE database_principals.name != ''public'''
53 |
54 | INSERT INTO #ExplicitPermissions_tmp(Name,PermissionName,StateDesc,ServerName,DBName,MajorObject,MinorObject)
55 | EXEC sp_executesql @stmt = @cmd
56 | END TRY
57 | BEGIN CATCH
58 | --if database in in accessible do nothing and move on to next database
59 | END CATCH
60 |
61 | FETCH NEXT FROM DBCur INTO @DBName
62 |
63 | END
64 |
65 | CLOSE DBCur
66 | DEALLOCATE DBCur
67 |
68 | SELECT * FROM #ExplicitPermissions_tmp
69 |
70 | END
71 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetLinkedServers.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: LinkedServers
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 | SELECT @@SERVERNAME AS Server,
10 | servers.name AS LinkedServerName,
11 | servers.data_source AS DataSource,
12 | servers.provider AS Provider,
13 | servers.product AS Product,
14 | servers.location AS Location,
15 | servers.provider_string AS ProviderString,
16 | servers.catalog AS Catalog,
17 | server_principals.name AS LocalUser,
18 | linked_logins.uses_self_credential AS Impersonate,
19 | linked_logins.remote_name AS RemoteUser
20 | FROM sys.servers
21 | JOIN sys.linked_logins ON servers.server_id = linked_logins.server_id
22 | LEFT OUTER JOIN sys.server_principals ON linked_logins.local_principal_id = server_principals.principal_id
23 | WHERE is_linked = 1
24 |
25 | END
26 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetLogins.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Logins
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 | --get all logins on server
10 | SELECT @@SERVERNAME AS ServerName,
11 | principals_logins.name AS LoginName,
12 | principals_logins.sid AS SID,
13 | principals_roles.name AS RoleName,
14 | principals_logins.is_disabled AS IsDisabled,
15 | CAST(LOGINPROPERTY(principals_logins.name, 'PasswordHash') AS VARBINARY(256))AS PasswordHash, -- **the varbinary of password hash is erroring in powershell, something to be looked at
16 | principals_logins.type_desc AS LoginType
17 | FROM sys.server_role_members
18 | RIGHT OUTER JOIN sys.server_principals principals_roles
19 | ON server_role_members.role_principal_id = principals_roles.principal_id
20 | RIGHT OUTER JOIN sys.server_principals principals_logins
21 | ON server_role_members.member_principal_id = principals_logins.principal_id
22 | WHERE principals_logins.type IN ('G','S','U') --include only windows groups, windows logins and SQL logins
23 | ORDER BY principals_logins.name
24 |
25 | END
26 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetServerConfig.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.1 - 14 January 2020
4 | --Module: ServerConfig
5 | --Script: Get
6 |
7 | BEGIN
8 | --get server configuration settings
9 |
10 | SELECT @@SERVERNAME AS ServerName,
11 | [name] AS SettingName,
12 | CAST([value] AS INT) AS SettingValue,
13 | CAST(value_in_use AS int) AS SettingValueInUse
14 | FROM sys.configurations
15 |
16 | END
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetServers.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Servers
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 |
10 | SELECT
11 | @@SERVERNAME AS ServerName,
12 | CAST(SERVERPROPERTY('collation') AS NVARCHAR(128)) AS Collation,
13 | CAST(SERVERPROPERTY('Edition') AS NVARCHAR(128)) AS Edition,
14 | CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)) AS VersionNo,
15 | sqlserver_start_time AS ServerStartTime,
16 | [cost threshold for parallelism] AS CostThreshold,
17 | [max worker threads] AS MaxWorkerThreads,
18 | [max degree of parallelism] AS [MaxDOP],
19 | cpu_count AS CPUCount,
20 | NULL AS NUMACount, --not implemented, needs a version check
21 | physical_memory_kb / 1024 AS PhysicalMemoryMB,
22 | [max server memory (MB)] AS MaxMemoryMB,
23 | [min server memory (MB)] AS MinMemoryMB,
24 | NULL AS MemoryModel, --not implemented, needs a version check
25 | CAST(SERVERPROPERTY('IsClustered') AS BIT) AS IsClustered,
26 | virtual_machine_type_desc AS VMType
27 | FROM sys.dm_os_sys_info,
28 | (
29 | SELECT [max worker threads],[cost threshold for parallelism],[max degree of parallelism],[min server memory (MB)],[max server memory (MB)]
30 | FROM
31 | (SELECT name, CAST(value_in_use AS INT) AS value_in_use
32 | FROM sys.configurations
33 | WHERE name in ('max worker threads','cost threshold for parallelism','max degree of parallelism','min server memory (MB)','max server memory (MB)')) AS Source
34 | PIVOT
35 | (
36 | MAX(value_in_use)
37 | FOR name IN ([max worker threads],[cost threshold for parallelism],[max degree of parallelism],[min server memory (MB)],[max server memory (MB)])
38 | )AS PivotTable
39 | ) AS config
40 | END
41 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetServices.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.1 - 14 January 2020
4 | --Module: Services
5 | --Script: Get
6 |
7 | SELECT @@SERVERNAME AS ServerName,
8 | servicename AS ServiceName,
9 | startup_type_desc AS StartupType,
10 | status_desc AS StatusDesc,
11 | service_account AS ServiceAccount,
12 | NULL AS InstantFileInit
13 | FROM sys.dm_server_services
14 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetServicesEnhanced.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 11 December 2019
4 | --Module: ServicesEnhanced
5 | --Script: Get
6 |
7 | IF (OBJECT_ID('tempdb.dbo.#RawServices') IS NOT NULL)
8 | DROP TABLE #RawServices
9 |
10 | IF (OBJECT_ID('tempdb.dbo.#Services') IS NOT NULL)
11 | DROP TABLE #Services
12 |
13 | DECLARE @ServiceName VARCHAR(256)
14 | DECLARE @cmd NVARCHAR(500)
15 |
16 | CREATE TABLE #RawServices
17 | ( ServiceName VARCHAR(256) NULL,
18 | RowNo INT IDENTITY(1,1))
19 |
20 | CREATE TABLE #Services
21 | (
22 | ServerName SYSNAME NULL,
23 | ServiceName NVARCHAR(256) NULL,
24 | StartupType NVARCHAR(256) NULL,
25 | StatusDesc NVARCHAR(256) NULL,
26 | ServiceAccount NVARCHAR(256) NULL,
27 | InstantFileInit INT NULL
28 | )
29 |
30 |
31 | --populate #RawServices with SQL related services
32 |
33 | INSERT INTO #RawServices(ServiceName)
34 | EXEC xp_cmdshell 'sc query type= service state= all'-- |find "MSOLAP"'-- |find /V "DISPLAY_NAME"'
35 |
36 |
37 | --sanitise data
38 | DELETE FROM #RawServices
39 | WHERE ServiceName IS NULL
40 | OR (ServiceName NOT LIKE 'SERVICE_NAME:%' AND ServiceName NOT LIKE '%STATE%:%')
41 |
42 | UPDATE #RawServices
43 | SET ServiceName = CASE WHEN CHARINDEX('RUNNING', ServiceName) > 0 THEN 'Running'
44 | WHEN CHARINDEX('STOPPED', ServiceName) > 0 THEN 'Stopped'
45 | ELSE 'Other'
46 | END
47 | WHERE ServiceName NOT LIKE 'SERVICE_NAME:%'
48 |
49 | UPDATE #RawServices
50 | SET ServiceName = REPLACE(ServiceName, 'SERVICE_NAME: ','')
51 |
52 | --Get running state
53 | INSERT INTO #Services(ServerName,ServiceName,StatusDesc)
54 | SELECT @@SERVERNAME, ServiceName, State
55 | FROM
56 | (SELECT ServiceName, ROW_NUMBER() OVER (ORDER BY RowNo) AS ServiceID
57 | FROM #RawServices
58 | WHERE ServiceName NOT IN ('RUNNING','STOPPED','START_PENDING','STOP_PENDING','UNKNOWN')) AS ServicesNames
59 | JOIN
60 | (SELECT ServiceName AS State, ROW_NUMBER() OVER (ORDER BY RowNo) AS ServiceID
61 | FROM #RawServices
62 | WHERE ServiceName IN ('RUNNING','STOPPED','START_PENDING','STOP_PENDING','UNKNOWN')) AS States ON States.ServiceID = ServicesNames.ServiceID
63 |
64 | --remove the services that we're no worried about
65 |
66 | DELETE FROM #Services
67 | WHERE ServiceName NOT LIKE 'MS%OLAP%'
68 | AND ServiceName NOT LIKE 'MsDtsServer%'
69 | AND ServiceName != 'SQLServerReportingServices'
70 | AND ServiceName NOT LIKE 'ReportServer%'
71 | AND ServiceName != 'SQL Server Distributed Replay Client'
72 | AND ServiceName != 'SQL Server Distributed Replay Controller'
73 |
74 |
75 |
76 | DECLARE ServicesCur CURSOR STATIC FORWARD_ONLY FOR
77 | SELECT ServiceName
78 | FROM #Services
79 |
80 | --EXEC xp_cmdshell 'sc qc BrokerInfrastructure'
81 |
82 | OPEN ServicesCur
83 |
84 | --fetch service details
85 | FETCH NEXT FROM ServicesCur INTO @ServiceName
86 |
87 | WHILE @@FETCH_STATUS = 0
88 | BEGIN
89 |
90 | TRUNCATE TABLE #RawServices
91 |
92 | SET @cmd = 'sc qc "' + @ServiceName + '"'
93 |
94 | INSERT #RawServices(ServiceName)
95 | EXEC xp_cmdshell @cmd
96 |
97 | --Update with Startup Type
98 | UPDATE #Services
99 | SET StartupType = CASE WHEN CHARINDEX('DISABLED', RawServices.ServiceName) > 0 THEN 'Disabled'
100 | WHEN CHARINDEX('AUTO_START', RawServices.ServiceName) > 0 THEN 'Automatic'
101 | WHEN CHARINDEX('DEMAND_START', RawServices.ServiceName) > 0 THEN 'Manual'
102 | ELSE 'Other'
103 | END
104 | FROM #RawServices RawServices
105 | WHERE RawServices.ServiceName LIKE '%START_TYPE%'
106 | AND #Services.ServiceName = @ServiceName
107 |
108 | --Update with Service Account
109 | UPDATE #Services
110 | SET ServiceAccount = REPLACE(RawServices.ServiceName,' SERVICE_START_NAME : ', '')
111 | FROM #RawServices RawServices
112 | WHERE RawServices.ServiceName LIKE '%SERVICE_START_NAME%'
113 | AND #Services.ServiceName = @ServiceName
114 |
115 |
116 | --Update with service display name
117 | UPDATE #Services
118 | SET ServiceName = REPLACE(RawServices.ServiceName, ' DISPLAY_NAME : ','')
119 | FROM #RawServices RawServices
120 | WHERE RawServices.ServiceName LIKE '%DISPLAY_NAME%:%'
121 | AND #Services.ServiceName = @ServiceName
122 |
123 |
124 | FETCH NEXT FROM ServicesCur INTO @ServiceName
125 |
126 | END
127 |
128 | CLOSE ServicesCur
129 | DEALLOCATE ServicesCur
130 |
131 | SELECT ServerName,
132 | ServiceName,
133 | StartupType,
134 | StatusDesc,
135 | ServiceAccount,
136 | 'N' AS InstantFileInit
137 | FROM #Services
138 |
139 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetSnapshots.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.4 - 15 April 2024
4 | --Module: Snapshots
5 | --Script: Get
6 |
7 | SELECT @@SERVERNAME AS ServerName,
8 | database_id AS DatabaseID,
9 | name AS SnapshotName,
10 | DB_NAME(source_database_id) AS SourceDBName,
11 | create_date AS CreateDate
12 | FROM sys.databases
13 | WHERE source_database_id IS NOT NULL
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetTables.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.3 - 04 May 2020
4 | --Module: Tables
5 | --Script: Get
6 |
7 | BEGIN
8 |
9 | IF OBJECT_ID('tempdb.dbo.#Tables') IS NOT NULL
10 | DROP TABLE #Tables
11 |
12 | CREATE TABLE #Tables
13 | (ServerName NVARCHAR(128) NOT NULL,
14 | DatabaseName NVARCHAR(128) NOT NULL,
15 | SchemaName SYSNAME NOT NULL,
16 | TableName SYSNAME NOT NULL,
17 | Columns XML,
18 | Rows BIGINT,
19 | TotalSizeMB BIGINT,
20 | UsedSizeMB BIGINT
21 | )
22 |
23 | DECLARE @DBName SYSNAME
24 |
25 | --cursor to hold database
26 | DECLARE DBCur CURSOR FAST_FORWARD LOCAL FOR
27 | SELECT name
28 | FROM sys.databases
29 |
30 | DECLARE @cmd NVARCHAR(2000)
31 |
32 | OPEN DBCur
33 |
34 | FETCH NEXT FROM DBCur INTO @DBName
35 |
36 | WHILE @@FETCH_STATUS = 0
37 | BEGIN
38 |
39 | SET @cmd = N'USE ' + QUOTENAME(@DBName) + N';
40 | SELECT NameServer, DatabaseName, SchemaName, TableName, Cols, SUM(rows) AS Rows, SUM(total_pages) * 8 / 1024 AS TotalSizeMB, SUM(used_pages) * 8 / 1024 AS UsedSizeMB
41 | FROM
42 | (SELECT @@SERVERNAME AS NameServer,
43 | DB_NAME() AS DatabaseName,
44 | schemas.name AS SchemaName,
45 | tables.name AS TableName,
46 | --CAST((
47 | (
48 | SELECT columns.name AS ColName,
49 | types.name AS DataType,
50 | CASE
51 | WHEN columns.max_length = -1 THEN ''MAX''
52 | WHEN types.name IN (''nchar'',''nvarchar'') THEN CAST(columns.max_length/2 AS VARCHAR)
53 | ELSE CAST(columns.max_length AS VARCHAR)
54 | END AS Length,
55 | columns.is_nullable AS IsNullable,
56 | columns.is_identity AS IsIdentity,
57 | columns.is_computed AS IsComputed
58 | FROM sys.columns
59 | JOIN sys.types ON columns.user_type_id = types.user_type_id
60 | WHERE columns.object_id = tables.object_id
61 | FOR XML RAW
62 | ) AS Cols,
63 | --) AS XML) Cols,
64 | CASE WHEN indexes.type IN (0,1) THEN partitions.rows
65 | ELSE 0
66 | END rows,
67 | allocUnits.total_pages,
68 | allocUnits.used_pages
69 | FROM sys.tables
70 | JOIN sys.schemas ON tables.schema_id = schemas.schema_id
71 | JOIN sys.indexes ON tables.object_id = indexes.object_id
72 | JOIN sys.partitions ON indexes.object_id = partitions.object_id AND indexes.index_id = partitions.index_id
73 | CROSS APPLY (SELECT SUM(total_pages) AS total_pages, SUM(used_pages) AS used_pages FROM sys.allocation_units WHERE container_id = partitions.partition_id) AS allocUnits) a
74 | GROUP BY NameServer, DatabaseName, SchemaName, TableName, Cols
75 |
76 | '
77 |
78 | BEGIN TRY
79 | INSERT INTO #Tables
80 | EXEC sp_executesql @cmd
81 | END TRY
82 | BEGIN CATCH
83 | --if database in in accessible do nothing and move on to next database
84 | END CATCH
85 |
86 | FETCH NEXT FROM DBCur INTO @DBName
87 |
88 | END
89 |
90 | SELECT ServerName
91 | ,DatabaseName
92 | ,SchemaName
93 | ,TableName
94 | ,Columns
95 | ,Rows
96 | ,TotalSizeMB
97 | ,UsedSizeMB
98 | FROM #Tables
99 |
100 | END
101 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetTraceFlags.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.2 - 06 February 2020
4 | --Module: TraceFlags
5 | --Script: Get
6 |
7 | CREATE TABLE #TraceFlags
8 | (
9 | TraceFlag INT,
10 | Status BIT,
11 | Global BIT,
12 | Session BIT
13 | )
14 |
15 | INSERT INTO #TraceFlags
16 | EXEC sp_executesql N'DBCC tracestatus'
17 |
18 | SELECT @@SERVERNAME AS ServerName, TraceFlag
19 | FROM #TraceFlags
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/GetUsers.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Users
5 | --Script: Get
6 |
7 |
8 | BEGIN
9 |
10 | DECLARE @DBName SYSNAME
11 | DECLARE @cmd NVARCHAR(4000)
12 |
13 | IF OBJECT_ID('tempdb.dbo.#Users_Tmp') IS NOT NULL
14 | DROP TABLE #Users_Tmp
15 |
16 | --create temp table to bulid up result set
17 | CREATE TABLE #Users_Tmp(
18 | [ServerName] [nvarchar](128) NULL,
19 | [DBName] [nvarchar](128) NULL,
20 | [UserName] [sysname] NOT NULL,
21 | [SID] [varbinary](85) NULL,
22 | [RoleName] [sysname] NULL,
23 | [MappedLoginName] [sysname] NOT NULL)
24 |
25 |
26 | --cursor to cycle through all databases on the server
27 | DECLARE DBCur CURSOR FOR
28 | SELECT [name]
29 | FROM sys.databases
30 |
31 | OPEN DBCur
32 |
33 | FETCH NEXT FROM DBCur INTO @DBName
34 |
35 | WHILE @@FETCH_STATUS = 0
36 | BEGIN
37 |
38 | --get all users for the selected database
39 |
40 | BEGIN TRY
41 | SET @cmd =
42 | 'USE ' + QUOTENAME(@DBName) + '
43 |
44 | SELECT @@SERVERNAME AS ServerName,
45 | DB_NAME() AS DBName,
46 | principals_logins.name AS UserName,
47 | principals_logins.sid AS SID,
48 | principals_roles.name AS RoleName,
49 | ISNULL(server_principals.name, ''***ORPHANED USER***'') AS MappedLoginName
50 | FROM sys.database_role_members
51 | RIGHT OUTER JOIN sys.database_principals principals_roles
52 | ON database_role_members.role_principal_id = principals_roles.principal_id
53 | RIGHT OUTER JOIN sys.database_principals principals_logins
54 | ON database_role_members.member_principal_id = principals_logins.principal_id
55 | LEFT OUTER JOIN sys.server_principals
56 | ON server_principals.sid = principals_logins.sid
57 | WHERE principals_logins.type IN (''G'',''S'',''U'') --include only windows groups, windows logins and SQL logins
58 | AND principals_logins.sid IS NOT NULL
59 | ORDER BY principals_logins.name'
60 |
61 | INSERT INTO #Users_Tmp(ServerName,DBName,UserName,SID,RoleName,MappedLoginName)
62 | EXEC sp_executesql @stmt = @cmd
63 | END TRY
64 | BEGIN CATCH
65 | --if the database is inaccessable, do nothing and move on to the next one
66 | END CATCH
67 | FETCH NEXT FROM DBCur INTO @DBName
68 |
69 | END
70 |
71 | CLOSE DBCur
72 | DEALLOCATE DBCur
73 |
74 | SELECT * FROM #Users_Tmp
75 |
76 | END
77 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateADGroups.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: ADGroups
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update LastRecorded date where the account and group is known to the catalogue
11 | UPDATE Catalogue.ADGroups
12 | SET LastRecorded = GETDATE()
13 | WHERE EXISTS
14 | (SELECT 1
15 | FROM [Catalogue].[ADGroups_Stage]
16 | WHERE ADGroups.GroupName = ADGroups_Stage.GroupName
17 | AND ADGroups.AccountName = ADGroups_Stage.AccountName)
18 |
19 | --insert ADGroup details where not known to the Catalogue
20 | INSERT INTO Catalogue.ADGroups(GroupName,AccountName,AccountType,FirstRecorded,LastRecorded,Notes)
21 | SELECT GroupName,
22 | AccountName,
23 | AccountType,
24 | GETDATE(),
25 | GETDATE(),
26 | NULL
27 | FROM [Catalogue].[ADGroups_Stage]
28 | WHERE NOT EXISTS
29 | (SELECT 1 FROM Catalogue.ADGroups
30 | WHERE ADGroups.GroupName = ADGroups_Stage.GroupName
31 | AND ADGroups.AccountName = ADGroups_Stage.AccountName)
32 |
33 | END
34 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateAgentJobs.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: AgentJobs
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update jobs where they are known
11 | UPDATE Catalogue.AgentJobs
12 | SET JobName = AgentJobs_Stage.JobName,
13 | Enabled = AgentJobs_Stage.Enabled,
14 | Description = AgentJobs_Stage.Description,
15 | Category = AgentJobs_Stage.Category,
16 | DateCreated = AgentJobs_Stage.DateCreated,
17 | DateModified = AgentJobs_Stage.DateModified,
18 | ScheduleEnabled = AgentJobs_Stage.ScheduleEnabled,
19 | ScheduleName = AgentJobs_Stage.ScheduleName,
20 | ScheduleFrequency = AgentJobs_Stage.ScheduleFrequency,
21 | StepID = AgentJobs_Stage.StepID,
22 | StepName = AgentJobs_Stage.StepName,
23 | SubSystem = AgentJobs_Stage.SubSystem,
24 | Command = AgentJobs_Stage.Command,
25 | DatabaseName = AgentJobs_Stage.DatabaseName,
26 | LastRecorded = GETDATE()
27 | FROM Catalogue.AgentJobs_Stage
28 | WHERE AgentJobs.ServerName = AgentJobs_Stage.ServerName
29 | AND AgentJobs.JobID = AgentJobs_Stage.JobID
30 | AND AgentJobs.StepID = AgentJobs_Stage.StepID
31 |
32 | --insert jobs that are unknown to the catlogue
33 | INSERT INTO Catalogue.AgentJobs
34 | (ServerName,JobID,JobName,Enabled,Description,Category,DateCreated,DateModified,
35 | ScheduleEnabled,ScheduleName,ScheduleFrequency,StepID, StepName,SubSystem,Command,DatabaseName,
36 | FirstRecorded, LastRecorded)
37 | SELECT ServerName,
38 | JobID,
39 | JobName,
40 | Enabled,
41 | Description,
42 | Category,
43 | DateCreated,
44 | DateModified,
45 | ScheduleEnabled,
46 | ScheduleName,
47 | ScheduleFrequency,
48 | StepID,
49 | StepName,
50 | SubSystem,
51 | Command,
52 | DatabaseName,
53 | GETDATE(),
54 | GETDATE()
55 | FROM Catalogue.AgentJobs_Stage
56 | WHERE NOT EXISTS
57 | (SELECT 1 FROM Catalogue.AgentJobs
58 | WHERE JobID = AgentJobs_Stage.JobID
59 | AND StepID = AgentJobs_Stage.StepID
60 | AND ServerName = AgentJobs_Stage.ServerName)
61 |
62 | END
63 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateAvailabilityGroups.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: AvailabilityGroups
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update AGs where they are known
11 | UPDATE Catalogue.AvailabilityGroups
12 | SET AGName = AvailabilityGroups_Stage.AGName,
13 | ServerName = AvailabilityGroups_Stage.ServerName,
14 | Role = AvailabilityGroups_Stage.Role,
15 | BackupPreference = AvailabilityGroups_Stage.BackupPreference,
16 | AvailabilityMode = AvailabilityGroups_Stage.AvailabilityMode,
17 | FailoverMode = AvailabilityGroups_Stage.FailoverMode,
18 | ConnectionsToSecondary = AvailabilityGroups_Stage.ConnectionsToSecondary,
19 | LastRecorded = GETDATE()
20 | FROM Catalogue.AvailabilityGroups_Stage
21 | WHERE AvailabilityGroups.AGName = AvailabilityGroups_Stage.AGName
22 | AND AvailabilityGroups.ServerName = AvailabilityGroups_Stage.ServerName
23 |
24 | --insert AGs that are unknown to the catalogue
25 | INSERT INTO Catalogue.AvailabilityGroups
26 | (AGName, ServerName, Role, BackupPreference, AvailabilityMode, FailoverMode, ConnectionsToSecondary,FirstRecorded, LastRecorded)
27 | SELECT AGName,
28 | ServerName,
29 | Role,
30 | BackupPreference,
31 | AvailabilityMode,
32 | FailoverMode,
33 | ConnectionsToSecondary,
34 | GETDATE(),
35 | GETDATE()
36 | FROM Catalogue.AvailabilityGroups_Stage AvailabilityGroups_Stage
37 | WHERE NOT EXISTS
38 | (SELECT 1 FROM Catalogue.AvailabilityGroups
39 | WHERE AGName = AvailabilityGroups_Stage.AGName
40 | AND ServerName = AvailabilityGroups_Stage.ServerName)
41 | --AND AGName IN ( SELECT AvailabilityGroups_Stage_sub.AGName
42 | -- FROM AvailabilityGroups_Stage AvailabilityGroups_Stage_sub
43 | -- WHERE AvailabilityGroups_Stage_sub.ServerName = AvailabilityGroups_Stage.ServerName
44 | -- AND Role = 'Primary')
45 |
46 | END
47 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateCluster.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.2 - 7 February 2020
4 | --Module: Cluster
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update cluster flags where they are known to the catalogue
11 | UPDATE Catalogue.Cluster
12 | SET ClusterName = Cluster_Stage.ClusterName,
13 | QuorumType = Cluster_Stage.QuorumType,
14 | QuorumState = Cluster_Stage.QuorumState,
15 | MemberName = Cluster_Stage.MemberName,
16 | MemberType = Cluster_Stage.MemberType,
17 | QuorumVotes = Cluster_Stage.QuorumVotes,
18 | LastRecorded = GETDATE()
19 | FROM Catalogue.Cluster_Stage
20 | WHERE Cluster_Stage.ClusterName = Cluster.ClusterName
21 | AND Cluster_Stage.MemberName = Cluster.MemberName
22 |
23 |
24 | --insert cluster flags that are unknown to the catlogue
25 | INSERT INTO Catalogue.Cluster (ClusterName,QuorumType,QuorumState,MemberName,MemberType,QuorumVotes,FirstRecorded,LastRecorded)
26 | SELECT ClusterName,
27 | QuorumType,
28 | QuorumState,
29 | MemberName,
30 | MemberType,
31 | QuorumVotes,
32 | GETDATE(),
33 | GETDATE()
34 | FROM Catalogue.Cluster_Stage
35 | WHERE NOT EXISTS
36 | (SELECT 1 FROM Catalogue.Cluster
37 | WHERE Cluster_Stage.ClusterName = Cluster.ClusterName
38 | AND Cluster_Stage.MemberName = Cluster.MemberName)
39 |
40 | END
41 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateDatabases.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.4 - 15 April 2024
4 | --Module: Databases
5 | --Script: Update
6 | BEGIN
7 | --update databases where they are known to the catalogue
8 | UPDATE Catalogue.Databases
9 | SET ServerName = Databases_Stage.ServerName
10 | ,DBName = Databases_Stage.DBName
11 | ,DatabaseID = Databases_Stage.DatabaseID
12 | ,OwnerName = Databases_Stage.OwnerName
13 | ,CompatibilityLevel = Databases_Stage.CompatibilityLevel
14 | ,CollationName = Databases_Stage.CollationName
15 | ,RecoveryModelDesc = Databases_Stage.RecoveryModelDesc
16 | ,AGName = Databases_Stage.AGName
17 | ,FilePaths = Databases_Stage.FilePaths
18 | ,DatabaseSizeMB = Databases_Stage.DatabaseSizeMB
19 | ,LastRecorded = GETDATE()
20 | ,StateDesc = Databases_Stage.StateDesc
21 | ,LastAccessDate = Databases_Stage.LastAccessDate
22 | FROM Catalogue.Databases_Stage
23 | WHERE Databases.ServerName = Databases_Stage.ServerName
24 | AND Databases.DBName = Databases_Stage.DBName
25 |
26 | --insert jobs that are unknown to the catlogue
27 | INSERT INTO Catalogue.Databases (
28 | ServerName
29 | ,DBName
30 | ,DatabaseID
31 | ,OwnerName
32 | ,CompatibilityLevel
33 | ,CollationName
34 | ,RecoveryModelDesc
35 | ,AGName
36 | ,FilePaths
37 | ,DatabaseSizeMB
38 | ,FirstRecorded
39 | ,LastRecorded
40 | ,StateDesc
41 | ,LastAccessDate
42 | )
43 | SELECT ServerName
44 | ,DBName
45 | ,DatabaseID
46 | ,OwnerName
47 | ,CompatibilityLevel
48 | ,CollationName
49 | ,RecoveryModelDesc
50 | ,AGName
51 | ,FilePaths
52 | ,DatabaseSizeMB
53 | ,GETDATE()
54 | ,GETDATE()
55 | ,StateDesc
56 | ,LastAccessDate
57 | FROM Catalogue.Databases_Stage
58 | WHERE NOT EXISTS (
59 | SELECT 1
60 | FROM Catalogue.Databases
61 | WHERE DBName = Databases_Stage.DBName
62 | AND Databases.ServerName = Databases_Stage.ServerName
63 | )
64 | END
65 |
66 |
67 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateDatabases2008.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Databases (2008 Compatability)
5 | --Script: Update
6 |
7 | --Please note that this is an unsupported module and is provided as is
8 |
9 | BEGIN
10 |
11 | --update databases where they are known to the catalogue
12 | UPDATE Catalogue.Databases
13 | SET ServerName = Databases_Stage.ServerName,
14 | DBName = Databases_Stage.DBName,
15 | DatabaseID = Databases_Stage.DatabaseID,
16 | OwnerName = Databases_Stage.OwnerName,
17 | CompatibilityLevel = Databases_Stage.CompatibilityLevel,
18 | CollationName = Databases_Stage.CollationName,
19 | RecoveryModelDesc = Databases_Stage.RecoveryModelDesc,
20 | AGName = Databases_Stage.AGName,
21 | FilePaths = Databases_Stage.FilePaths,
22 | DatabaseSizeMB= Databases_Stage.DatabaseSizeMB,
23 | LastRecorded = GETDATE(),
24 | StateDesc = Databases_Stage.StateDesc
25 | FROM Catalogue.Databases_Stage
26 | WHERE Databases.ServerName = Databases_Stage.ServerName
27 | AND Databases.DBName = Databases_Stage.DBName
28 |
29 | --insert jobs that are unknown to the catlogue
30 | INSERT INTO Catalogue.Databases
31 | (ServerName, DBName, DatabaseID, OwnerName, CompatibilityLevel, CollationName, RecoveryModelDesc, AGName,FilePaths,DatabaseSizeMB,FirstRecorded,LastRecorded, StateDesc)
32 | SELECT ServerName,
33 | DBName,
34 | DatabaseID,
35 | OwnerName,
36 | CompatibilityLevel,
37 | CollationName,
38 | RecoveryModelDesc,
39 | AGName,
40 | FilePaths,
41 | DatabaseSizeMB,
42 | GETDATE(),
43 | GETDATE(),
44 | StateDesc
45 | FROM Catalogue.Databases_Stage
46 | WHERE NOT EXISTS
47 | (SELECT 1 FROM Catalogue.Databases
48 | WHERE DBName = Databases_Stage.DBName
49 | AND Databases.ServerName = Databases_Stage.ServerName)
50 |
51 | END
52 |
53 |
54 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateExplicitPermissions.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: ExplicitPermissions
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update permissions where they are known
11 | UPDATE Catalogue.ExplicitPermissions
12 | SET Name = ExplicitPermissions_Stage.Name,
13 | PermissionName = ExplicitPermissions_Stage.PermissionName,
14 | StateDesc = ExplicitPermissions_Stage.StateDesc,
15 | ServerName = ExplicitPermissions_Stage.ServerName,
16 | DBName = ExplicitPermissions_Stage.DBName,
17 | MajorObject = ExplicitPermissions_Stage.MajorObject,
18 | MinorObject = ExplicitPermissions_Stage.MinorObject,
19 | LastRecorded = GETDATE()
20 | FROM Catalogue.ExplicitPermissions_Stage
21 | WHERE ExplicitPermissions.Name = ExplicitPermissions_Stage.Name
22 | AND ExplicitPermissions.PermissionName = ExplicitPermissions_Stage.PermissionName
23 | AND ExplicitPermissions.StateDesc = ExplicitPermissions_Stage.StateDesc
24 | AND ExplicitPermissions.ServerName = ExplicitPermissions_Stage.ServerName
25 | AND ExplicitPermissions.DBName = ExplicitPermissions_Stage.DBName
26 | AND ISNULL(ExplicitPermissions.MajorObject,'') = ISNULL(ExplicitPermissions_Stage.MajorObject,'')
27 | AND ISNULL(ExplicitPermissions.MinorObject,'') = ISNULL(ExplicitPermissions_Stage.MinorObject,'')
28 |
29 | --insert permissions that are unknown to the catlogue
30 | INSERT INTO Catalogue.ExplicitPermissions
31 | (Name, PermissionName,StateDesc,ServerName,DBName,MajorObject,MinorObject,FirstRecorded,LastRecorded)
32 | SELECT Name,
33 | PermissionName,
34 | StateDesc,
35 | ServerName,
36 | DBName,
37 | MajorObject,
38 | MinorObject,
39 | GETDATE(),
40 | GETDATE()
41 | FROM Catalogue.ExplicitPermissions_Stage
42 | WHERE NOT EXISTS
43 | (SELECT 1 FROM Catalogue.ExplicitPermissions
44 | WHERE ExplicitPermissions.Name = ExplicitPermissions_Stage.Name
45 | AND ExplicitPermissions.PermissionName = ExplicitPermissions_Stage.PermissionName
46 | AND ExplicitPermissions.StateDesc = ExplicitPermissions_Stage.StateDesc
47 | AND ExplicitPermissions.ServerName = ExplicitPermissions_Stage.ServerName
48 | AND ExplicitPermissions.DBName = ExplicitPermissions_Stage.DBName
49 | AND ISNULL(ExplicitPermissions.MajorObject,'') = ISNULL(ExplicitPermissions_Stage.MajorObject,'')
50 | AND ISNULL(ExplicitPermissions.MinorObject, '') = ISNULL(ExplicitPermissions_Stage.MinorObject,''))
51 |
52 |
53 | END
54 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateLinkedServers.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Linked Server
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --temp table used to prevent duplicate entries from the denormalised stage table
11 | IF OBJECT_ID('tempdb.dbo.#LinkedServers') IS NOT NULL
12 | DROP TABLE #LinkedServers
13 |
14 | CREATE TABLE #LinkedServers(
15 | Server nvarchar(128) NOT NULL
16 | ,LinkedServerName nvarchar(128) NOT NULL
17 | ,DataSource nvarchar(4000) NULL
18 | ,Provider nvarchar(128) NULL
19 | ,Product nvarchar(128) NULL
20 | ,Location nvarchar(4000) NULL
21 | ,ProviderString nvarchar(4000) NULL
22 | ,Catalog nvarchar(128) NULL)
23 |
24 | --populate #LinkedServers
25 | INSERT INTO #LinkedServers
26 | SELECT DISTINCT Server,
27 | LinkedServerName,
28 | DataSource,
29 | Provider,
30 | Product,
31 | Location,
32 | ProviderString,
33 | Catalog
34 | FROM Catalogue.LinkedServers_Stage
35 |
36 | --update servers table where servers are known to the catalogue
37 |
38 | UPDATE Catalogue.LinkedServers_Server
39 | SET Server = LinkedServers.Server
40 | ,LinkedServerName = LinkedServers.LinkedServerName
41 | ,DataSource = LinkedServers.DataSource
42 | ,Provider = LinkedServers.Provider
43 | ,Product = LinkedServers.Product
44 | ,Location = LinkedServers.Location
45 | ,ProviderString = LinkedServers.ProviderString
46 | ,Catalog = LinkedServers.Catalog
47 | ,LastRecorded = GETDATE()
48 | FROM #LinkedServers LinkedServers
49 | WHERE LinkedServers_Server.Server = LinkedServers.Server
50 | AND LinkedServers_Server.LinkedServerName = LinkedServers.LinkedServerName
51 |
52 | --insert into servers table where servers are not known to the catalogue
53 |
54 | INSERT INTO Catalogue.LinkedServers_Server(Server ,LinkedServerName,DataSource,Provider,Product,Location,ProviderString,Catalog,FirstRecorded,LastRecorded,Notes)
55 | SELECT Server
56 | ,LinkedServerName
57 | ,DataSource
58 | ,Provider
59 | ,Product
60 | ,Location
61 | ,ProviderString
62 | ,Catalog
63 | ,GETDATE()
64 | ,GETDATE()
65 | ,NULL
66 | FROM #LinkedServers LinkedServers
67 | WHERE NOT EXISTS
68 | (SELECT 1
69 | FROM Catalogue.LinkedServers_Server
70 | WHERE LinkedServers_Server.Server = LinkedServers.Server
71 | AND LinkedServers_Server.LinkedServerName = LinkedServers.LinkedServerName)
72 |
73 | --update users table where users are known to the catalogue
74 |
75 | UPDATE Catalogue.LinkedServers_Users
76 | SET Server = LinkedServers_Stage.Server
77 | ,LinkedServerName = LinkedServers_Stage.LinkedServerName
78 | ,LocalUser = LinkedServers_Stage.LocalUser
79 | ,Impersonate = LinkedServers_Stage.Impersonate
80 | ,RemoteUser = LinkedServers_Stage.RemoteUser
81 | ,LastRecorded = GETDATE()
82 | FROM Catalogue.LinkedServers_Stage
83 | WHERE LinkedServers_Users.Server = LinkedServers_Stage.Server
84 | AND LinkedServers_Users.LinkedServerName = LinkedServers_Stage.LinkedServerName
85 | AND ISNULL(LinkedServers_Users.LocalUser, '') = ISNULL(LinkedServers_Stage.LocalUser,'')
86 |
87 | --insert into users table where users are unkown to the catalogue
88 |
89 | INSERT INTO Catalogue.LinkedServers_Users (Server,LinkedServerName,LocalUser,Impersonate,RemoteUser,FirstRecorded,LastRecorded,Notes)
90 | SELECT Server
91 | ,LinkedServerName
92 | ,LocalUser
93 | ,Impersonate
94 | ,RemoteUser
95 | ,GETDATE()
96 | ,GETDATE()
97 | ,NULL
98 | FROM Catalogue.LinkedServers_Stage
99 | WHERE NOT EXISTS
100 | (SELECT 1
101 | FROM Catalogue.LinkedServers_Users
102 | WHERE LinkedServers_Users.Server = LinkedServers_Stage.Server
103 | AND LinkedServers_Users.LinkedServerName = LinkedServers_Stage.LinkedServerName
104 | AND ISNULL(LinkedServers_Users.LocalUser,'') = ISNULL(LinkedServers_Stage.LocalUser,''))
105 |
106 | END
107 |
108 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateLogins.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Logins
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update logins where they are known
11 | UPDATE Catalogue.Logins
12 | SET ServerName = [Logins_Stage].ServerName,
13 | LoginName = [Logins_Stage].LoginName,
14 | SID = [Logins_Stage].SID,
15 | RoleName = [Logins_Stage].RoleName,
16 | PasswordHash = [Logins_Stage].PasswordHash,
17 | LastRecorded = GETDATE(),
18 | IsDisabled = [Logins_Stage].IsDisabled,
19 | LoginType = [Logins_Stage].LoginType
20 | FROM [Catalogue].[Logins_Stage]
21 | WHERE Logins.ServerName = [Logins_Stage].ServerName
22 | AND Logins.LoginName = [Logins_Stage].LoginName
23 | AND ISNULL(Logins.RoleName, '') = ISNULL([Logins_Stage].RoleName, '')
24 |
25 | --insert logins that are unknown to the catlogue
26 | INSERT INTO Catalogue.Logins
27 | (ServerName,LoginName,SID,RoleName,FirstRecorded,LastRecorded, IsDisabled, PasswordHash,LoginType)
28 | SELECT ServerName,
29 | LoginName,
30 | SID,
31 | RoleName,
32 | GETDATE(),
33 | GETDATE(),
34 | IsDisabled,
35 | PasswordHash,
36 | LoginType
37 | FROM [Catalogue].[Logins_Stage]
38 | WHERE NOT EXISTS
39 | (SELECT 1 FROM Catalogue.Logins
40 | WHERE Logins.ServerName = [Logins_Stage].ServerName
41 | AND Logins.LoginName = [Logins_Stage].LoginName
42 | AND ISNULL(Logins.RoleName, '') = ISNULL([Logins_Stage].RoleName, ''))
43 |
44 | END
45 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateServerConfig.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.1 - 14 January 2020
4 | --Module: ServerConfig
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update settings where known to the catalogue
11 | UPDATE Catalogue.ServerConfig
12 | SET ServerName = ServerConfig_Stage.ServerName,
13 | SettingName = ServerConfig_Stage.SettingName,
14 | SettingValue = ServerConfig_Stage.SettingValue,
15 | SettingValueInUse = ServerConfig_Stage.SettingValueInUse,
16 | LastRecorded = GETDATE()
17 | FROM Catalogue.ServerConfig_Stage
18 | WHERE ServerConfig.ServerName = ServerConfig_Stage.ServerName
19 | AND ServerConfig.SettingName = ServerConfig_Stage.SettingName
20 |
21 | --insert settings where unknown to the catalogue
22 | INSERT INTO Catalogue.ServerConfig
23 | (ServerName, SettingName, SettingValue, SettingValueInUse, FirstRecorded, LastRecorded)
24 | SELECT ServerName,
25 | SettingName,
26 | SettingValue,
27 | SettingValueInUse,
28 | GETDATE(),
29 | GETDATE()
30 | FROM Catalogue.ServerConfig_Stage
31 | WHERE NOT EXISTS (SELECT 1
32 | FROM Catalogue.ServerConfig
33 | WHERE ServerConfig.ServerName = ServerConfig_Stage.ServerName
34 | AND ServerConfig.SettingName = ServerConfig_Stage.SettingName)
35 |
36 | END
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateServers.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Servers
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 | --update servers where they are known to the catalogue
10 | UPDATE Catalogue.Servers
11 | SET ServerName = Servers_Stage.ServerName,
12 | Collation = Servers_Stage.Collation,
13 | Edition = Servers_Stage.Edition,
14 | VersionNo = Servers_Stage.VersionNo,
15 | LastRecorded = GETDATE(),
16 | ServerStartTime = Servers_Stage.ServerStartTime,
17 | CostThreshold = Servers_Stage.CostThreshold,
18 | MaxWorkerThreads = Servers_Stage.MaxWorkerThreads,
19 | [MaxDOP] = Servers_Stage.[MaxDOP],
20 | CPUCount = Servers_Stage.CPUCount,
21 | NUMACount = Servers_Stage.NUMACount,
22 | PhysicalMemoryMB = Servers_Stage.PhysicalMemoryMB,
23 | MaxMemoryMB = Servers_Stage.MaxMemoryMB,
24 | MinMemoryMB = Servers_Stage.MinMemoryMB,
25 | MemoryModel = Servers_Stage.MemoryModel,
26 | IsClustered = Servers_Stage.IsClustered,
27 | VMType = Servers_Stage.VMType
28 | FROM Catalogue.Servers_Stage
29 | WHERE Servers.ServerName = Servers_Stage.ServerName
30 |
31 | --insert jobs that are unknown to the catlogue
32 | INSERT INTO Catalogue.Servers
33 | ([ServerName],
34 | [Collation],
35 | [Edition],
36 | [VersionNo],
37 | FirstRecorded,
38 | LastRecorded,
39 | ServerStartTime,
40 | CostThreshold,
41 | MaxWorkerThreads,
42 | [MaxDOP],
43 | CPUCount,
44 | NUMACount,
45 | PhysicalMemoryMB,
46 | MaxMemoryMB,
47 | MinMemoryMB,
48 | MemoryModel,
49 | IsClustered,
50 | VMType)
51 | SELECT [ServerName],
52 | [Collation],
53 | [Edition],
54 | [VersionNo],
55 | GETDATE(),
56 | GETDATE(),
57 | ServerStartTime,
58 | CostThreshold,
59 | MaxWorkerThreads,
60 | [MaxDOP],
61 | CPUCount,
62 | NUMACount,
63 | PhysicalMemoryMB,
64 | MaxMemoryMB,
65 | MinMemoryMB,
66 | MemoryModel,
67 | IsClustered,
68 | VMType
69 | FROM Catalogue.Servers_Stage
70 | WHERE NOT EXISTS
71 | (SELECT 1 FROM Catalogue.Servers
72 | WHERE Servers.ServerName = Servers_Stage.ServerName)
73 | END
74 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateServices.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 10 December 2019
4 | --Module: Services
5 | --Script: Update
6 |
7 | --update where known to catalogue
8 | UPDATE Catalogue.Services
9 | SET ServerName = Services_Stage.ServerName,
10 | ServiceName = Services_Stage.ServiceName,
11 | StartupType = Services_Stage.StartupType,
12 | StatusDesc = Services_Stage.StatusDesc,
13 | ServiceAccount = Services_Stage.ServiceAccount,
14 | InstantFileInit = Services_Stage.InstantFileInit,
15 | LastRecorded = GETDATE()
16 | FROM Catalogue.Services_Stage
17 | WHERE Services.ServerName = Services_Stage.ServerName
18 | AND Services.ServiceName = Services_Stage.ServiceName
19 |
20 | --insert where not known to catalogue
21 | INSERT INTO Catalogue.Services
22 | (ServerName, ServiceName, StartupType,StatusDesc, ServiceAccount, InstantFileInit, FirstRecorded, LastRecorded)
23 | SELECT ServerName,
24 | ServiceName,
25 | StartupType,
26 | StatusDesc,
27 | ServiceAccount,
28 | InstantFileInit,
29 | GETDATE(),
30 | GETDATE()
31 | FROM Catalogue.Services_Stage
32 | WHERE NOT EXISTS
33 | (SELECT 1 FROM Catalogue.Services
34 | WHERE Services.ServerName = Services_Stage.ServerName
35 | AND Services.ServiceName = Services_Stage.ServiceName)
36 |
37 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateServicesEnhanced.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 11 December 2019
4 | --Module: ServicesEnhanced
5 | --Script: Update
6 |
7 | --update where known to catalogue
8 | UPDATE Catalogue.Services
9 | SET ServerName = Services_Stage.ServerName,
10 | ServiceName = Services_Stage.ServiceName,
11 | StartupType = Services_Stage.StartupType,
12 | StatusDesc = Services_Stage.StatusDesc,
13 | ServiceAccount = Services_Stage.ServiceAccount,
14 | InstantFileInit = Services_Stage.InstantFileInit,
15 | LastRecorded = GETDATE()
16 | FROM Catalogue.Services_Stage
17 | WHERE Services.ServerName = Services_Stage.ServerName
18 | AND Services.ServiceName = Services_Stage.ServiceName
19 |
20 | --insert where not known to catalogue
21 | INSERT INTO Catalogue.Services
22 | (ServerName, ServiceName, StartupType,StatusDesc, ServiceAccount, InstantFileInit, FirstRecorded, LastRecorded)
23 | SELECT ServerName,
24 | ServiceName,
25 | StartupType,
26 | StatusDesc,
27 | ServiceAccount,
28 | InstantFileInit,
29 | GETDATE(),
30 | GETDATE()
31 | FROM Catalogue.Services_Stage
32 | WHERE NOT EXISTS
33 | (SELECT 1 FROM Catalogue.Services
34 | WHERE Services.ServerName = Services_Stage.ServerName
35 | AND Services.ServiceName = Services_Stage.ServiceName)
36 |
37 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateSnapshots.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.4 - 15 April 2024
4 | --Module: Snapshots
5 | --Script: Update
6 |
7 | BEGIN
8 | --Update snapshots where they're known to the catalogue
9 | UPDATE Catalogue.Snapshots
10 | SET ServerName = Snapshots_Stage.ServerName,
11 | DatabaseID = Snapshots_Stage.DatabaseID,
12 | SnapshotName = Snapshots_Stage.SnapshotName,
13 | SourceDBName = Snapshots_Stage.SourceDBName,
14 | CreateDate = Snapshots_Stage.CreateDate,
15 | LastRecorded = GETDATE()
16 | FROM Catalogue.Snapshots_Stage
17 | WHERE Snapshots.ServerName = Snapshots_Stage.ServerName
18 | AND Snapshots.SnapshotName = Snapshots_Stage.SnapshotName
19 |
20 | --Insert snapshots that are unknown to the catalogue
21 | INSERT INTO Catalogue.Snapshots
22 | (ServerName,
23 | DatabaseID,
24 | SnapshotName,
25 | SourceDBName,
26 | CreateDate,
27 | FirstRecorded,
28 | LastRecorded)
29 | SELECT ServerName,
30 | DatabaseID,
31 | SnapshotName,
32 | SourceDBName,
33 | CreateDate,
34 | GETDATE(),
35 | GETDATE()
36 | FROM Catalogue.Snapshots_Stage
37 | WHERE NOT EXISTS
38 | (SELECT 1 FROM Catalogue.Snapshots
39 | WHERE Snapshots.ServerName = Snapshots_Stage.ServerName
40 | AND Snapshots.SnapshotName = Snapshots_Stage.SnapshotName)
41 | END
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateTables.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.3 - 04 May 2020
4 | --Module: Tables
5 | --Script: Update
6 |
7 |
8 |
9 | BEGIN
10 |
11 | --update tables where they are known to the catalogue
12 | UPDATE Catalogue.Tables
13 | SET ServerName = Tables_Stage.ServerName
14 | ,DatabaseName = Tables_Stage.DatabaseName
15 | ,SchemaName = Tables_Stage.SchemaName
16 | ,TableName = Tables_Stage.TableName
17 | ,Columns = Tables_Stage.Columns
18 | ,LastRecorded = GETDATE()
19 | ,Rows = Tables_Stage.Rows
20 | ,TotalSizeMB = Tables_Stage.TotalSizeMB
21 | ,UsedSizeMB = Tables_Stage.UsedSizeMB
22 | FROM Catalogue.Tables_Stage
23 | WHERE Tables.ServerName = Tables_Stage.ServerName
24 | AND Tables.SchemaName = Tables_Stage.SchemaName
25 | AND Tables.TableName = Tables_Stage.TableName
26 | AND Tables.DatabaseName = Tables_Stage.DatabaseName
27 |
28 |
29 |
30 | --insert tables that are unknown to the catlogue
31 | INSERT INTO Catalogue.Tables
32 | (ServerName,DatabaseName,SchemaName,TableName,Columns,FirstRecorded,LastRecorded, Rows, TotalSizeMB, UsedSizeMB)
33 | SELECT ServerName,
34 | DatabaseName,
35 | SchemaName,
36 | TableName,
37 | Columns,
38 | GETDATE(),
39 | GETDATE()
40 | ,Rows
41 | ,TotalSizeMB
42 | ,UsedSizeMB
43 | FROM Catalogue.Tables_Stage
44 | WHERE NOT EXISTS
45 | (SELECT 1 FROM Catalogue.Tables
46 | WHERE Tables.ServerName = Tables_Stage.ServerName
47 | AND Tables.SchemaName = Tables_Stage.SchemaName
48 | AND Tables.TableName = Tables_Stage.TableName
49 | AND Tables.DatabaseName = Tables_Stage.DatabaseName)
50 |
51 | END
52 |
53 |
54 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateTraceFlags.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.2 - 6 February 2020
4 | --Module: Databases
5 | --Script: Update
6 |
7 |
8 | BEGIN
9 |
10 | --update trace flags where they are known to the catalogue
11 | UPDATE Catalogue.TraceFlags
12 | SET ServerName = TraceFlags_Stage.ServerName,
13 | TraceFlag = TraceFlags_Stage.TraceFlag,
14 | LastRecorded = GETDATE()
15 | FROM Catalogue.TraceFlags_Stage
16 | WHERE TraceFlags_Stage.ServerName = TraceFlags.ServerName
17 | AND TraceFlags_Stage.TraceFlag = TraceFlags.TraceFlag
18 |
19 | --insert trace flags that are unknown to the catlogue
20 | INSERT INTO Catalogue.TraceFlags (ServerName, TraceFlag, FirstRecorded, LastRecorded)
21 | SELECT ServerName,
22 | TraceFlag,
23 | GETDATE(),
24 | GETDATE()
25 | FROM Catalogue.TraceFlags_Stage
26 | WHERE NOT EXISTS
27 | (SELECT 1 FROM Catalogue.TraceFlags
28 | WHERE TraceFlags_Stage.ServerName = TraceFlags.ServerName
29 | AND TraceFlags_Stage.TraceFlag = TraceFlags.TraceFlag)
30 |
31 | END
32 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/ModuleDefinitions/UpdateUsers.sql:
--------------------------------------------------------------------------------
1 | --Undercover Catalogue
2 | --David Fowler
3 | --Version 0.4.0 - 25 November 2019
4 | --Module: Users
5 | --Script: Update
6 |
7 |
8 |
9 | BEGIN
10 |
11 | --update users where they are known
12 | UPDATE Catalogue.Users
13 | SET ServerName = Users_Stage.ServerName,
14 | DBName = Users_Stage.DBName,
15 | UserName = Users_Stage.UserName,
16 | SID = Users_Stage.SID,
17 | LastRecorded = GETDATE(),
18 | MappedLoginName = Users_Stage.MappedLoginName
19 | FROM Catalogue.Users_Stage
20 | WHERE Users.UserName = Users_Stage.UserName
21 | AND Users.ServerName = Users_Stage.ServerName
22 | AND Users.DBName = Users_Stage.DBName
23 | AND ISNULL(Users.RoleName ,'') = ISNULL(Users_Stage.RoleName,'')
24 |
25 | --insert users that are unknown to the catlogue
26 | INSERT INTO Catalogue.Users
27 | (ServerName, DBName, UserName, SID, RoleName,MappedLoginName,FirstRecorded,LastRecorded)
28 | SELECT ServerName,
29 | DBName,
30 | UserName,
31 | SID,
32 | RoleName,
33 | MappedLoginName,
34 | GETDATE(),
35 | GETDATE()
36 | FROM Catalogue.Users_Stage
37 | WHERE NOT EXISTS
38 | (SELECT 1 FROM Catalogue.Users
39 | WHERE UserName = Users_Stage.UserName
40 | AND ServerName= Users_Stage.ServerName
41 | AND DBName = Users_Stage.DBName
42 | AND ISNULL(RoleName,'') = ISNULL(RoleName,''))
43 |
44 | END
45 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/UndercoverCatalogue.pbit:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverCatalogue/UndercoverCatalogue.pbit
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/UndercoverCatalogueSetup_040.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverCatalogue/UndercoverCatalogueSetup_040.sql
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Updates/.vs/slnx.sqlite:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverCatalogue/Updates/.vs/slnx.sqlite
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Updates/Catalogue_UD041.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | @ ,@
4 | #@@ @@@
5 | @@@@@@@@@;
6 | @@@@@@@@@@
7 | :@@@@@@@@@@
8 | @@@@@@@@@@@
9 | @@@@@@@@@@@;
10 | @@@@@@@@@@@@
11 | @@@@@@@@@@@@
12 | `+@@@@@@@@@@+
13 |
14 |
15 | .@@` #@,
16 | .@@@@@@@@@@@@@@@@@@@@@@@@:
17 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@ @@ @@ #@ @ @
18 | #@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@@@ @@@@ @# #@ @ @
19 | ;@@@@@@@@@@@@@@@@@@@@@@@@@@' @ @ @# @# #@ @ #@@@ @@@@ @@@ @@@@@ @@@ @@ @ @ @@ @ @@
20 | .+@@@@@@@@@@@@@@@@+. @@@@ @ @@ @# #@ @ #@ @ @@ @ @ @ @@ @ @ @ `@ @ @ @ @ @@
21 | '` `,# @@@@ @ @@ @# #@ @ #@ @ @# @ @@@@@ @ @ @ @ @ @ @@@@ @`
22 | ,@@@@ '@@@@@@@@@@@@@ .@@@@; @ @ @@ @# #@ @ #@ @ @@ @ @@ @ ` @ @ @ @@@ @ @
23 | #@@@@@@ @@@@@ +@@@@ +@@@@@@ @@@@ @@@@ @@@@@ `@@@@@ #@ @ #@ @@ @ @ @ @@ @ @ @ @ @ @ @
24 | @@@@@@@@ ,#. `#; @@@@@@@@' @@ @@ @@@@@ @@, #@ @ @@ @ @@ @@ #@ @@ @ @@ @
25 | ;#@@@@@@@@ @@@@@@@@@#, @
26 | ,@@@@+ @@@@@+`
27 | .@@` `@@@@ ? www.sqlundercover.com
28 | +@@@@ @@@@@+
29 | @@@@@@@ @@@@@@@@#
30 | @@@@@@@ @@@@@@,
31 | @@@@@@@ @@@@@@,
32 | :@@@@@' ;@@@@`
33 | `@@@@ @@@+
34 | @#:@@
35 | @@
36 | @`
37 | #
38 |
39 | Sequential Upgrade - 0.4.1
40 | David Fowler
41 | 14/01/2020
42 |
43 | MIT License
44 | ------------
45 |
46 | Copyright 2019 Sql Undercover
47 |
48 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
49 | (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
50 | publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
51 | subject to the following conditions:
52 |
53 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
54 |
55 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
56 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
57 | FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
58 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
59 |
60 | */
61 |
62 | --schema changes
63 |
64 | --create upgrade history table
65 | CREATE TABLE Catalogue.UpgradeHistory
66 | (ID INT IDENTITY(1,1),
67 | UpgradeVersion VARCHAR(20),
68 | UpgradeDate DATETIME,
69 | CONSTRAINT PK_UpgradeHistory PRIMARY KEY(ID))
70 | GO
71 |
72 | --create ServerConfig module tables
73 |
74 | CREATE TABLE Catalogue.ServerConfig_Stage
75 | (
76 | ServerName SYSNAME,
77 | SettingName NVARCHAR(35),
78 | SettingValue INT,
79 | SettingValueInUse INT,
80 | CONSTRAINT PK_ServerConfig_Stage PRIMARY KEY(ServerName, SettingName)
81 | )
82 | GO
83 |
84 | CREATE TABLE Catalogue.ServerConfig
85 | (
86 | ServerName SYSNAME,
87 | SettingName NVARCHAR(35),
88 | SettingValue INT,
89 | SettingValueInUse INT,
90 | Notes VARCHAR(255),
91 | FirstRecorded DATETIME,
92 | LastRecorded DATETIME,
93 | CONSTRAINT PK_ServerConfig PRIMARY KEY(ServerName, SettingName)
94 | )
95 | GO
96 |
97 | CREATE TABLE Catalogue.ServerConfig_Audit
98 | (
99 | ServerName SYSNAME,
100 | SettingName NVARCHAR(35),
101 | SettingValue INT,
102 | SettingValueInUse INT,
103 | Notes VARCHAR(255),
104 | AuditDate DATETIME
105 | )
106 | GO
107 |
108 | --new modules
109 |
110 | --insert into module config tables
111 |
112 | INSERT INTO Catalogue.ConfigModules (ModuleName, GetProcName, UpdateProcName, StageTableName, MainTableName, Active)
113 | VALUES ('ServerConfig','DEPRECATED','DEPRECATED','ServerConfig_Stage','ServerConfig',1)
114 | GO
115 |
116 | DECLARE @ModuleID INT
117 |
118 | SELECT @ModuleID = ID
119 | FROM Catalogue.ConfigModules
120 | WHERE ModuleName = 'ServerConfig'
121 |
122 | INSERT INTO Catalogue.ConfigModulesDefinitions (ModuleID,Online,GetDefinition,UpdateDefinition,GetURL,UpdateURL)
123 | VALUES (@ModuleID,
124 | 1,
125 | '--Undercover Catalogue
126 | --David Fowler
127 | --Version 0.4.1 - 14 January 2020
128 | --Module: ServerConfig
129 | --Script: Get
130 |
131 | BEGIN
132 | --get server configuration settings
133 |
134 | SELECT @@SERVERNAME AS ServerName,
135 | [name] AS SettingName,
136 | CAST([value] AS INT) AS SettingValue,
137 | CAST(value_in_use AS int) AS SettingValueInUse
138 | FROM sys.configurations
139 |
140 | END',
141 | '--Undercover Catalogue
142 | --David Fowler
143 | --Version 0.4.1 - 14 January 2020
144 | --Module: ServerConfig
145 | --Script: Update
146 |
147 |
148 | BEGIN
149 |
150 | --update settings where known to the catalogue
151 | UPDATE Catalogue.ServerConfig
152 | SET ServerName = ServerConfig_Stage.ServerName,
153 | SettingName = ServerConfig_Stage.SettingName,
154 | SettingValue = ServerConfig_Stage.SettingValue,
155 | SettingValueInUse = ServerConfig_Stage.SettingValueInUse,
156 | LastRecorded = GETDATE()
157 | FROM Catalogue.ServerConfig_Stage
158 | WHERE ServerConfig.ServerName = ServerConfig_Stage.ServerName
159 | AND ServerConfig.SettingName = ServerConfig_Stage.SettingName
160 |
161 | --insert settings where unknown to the catalogue
162 | INSERT INTO Catalogue.ServerConfig
163 | (ServerName, SettingName, SettingValue, SettingValueInUse, FirstRecorded, LastRecorded)
164 | SELECT ServerName,
165 | SettingName,
166 | SettingValue,
167 | SettingValueInUse,
168 | GETDATE(),
169 | GETDATE()
170 | FROM Catalogue.ServerConfig_Stage
171 | WHERE NOT EXISTS (SELECT 1
172 | FROM Catalogue.ServerConfig
173 | WHERE ServerConfig.ServerName = ServerConfig_Stage.ServerName
174 | AND ServerConfig.SettingName = ServerConfig_Stage.SettingName)
175 |
176 | END',
177 | 'https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverCatalogue/ModuleDefinitions/GetServerConfig.sql',
178 | 'https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverCatalogue/ModuleDefinitions/UpdateServerConfig.sql')
179 |
180 | GO
181 |
182 |
183 | --ServerConfig Audit Trigger
184 | CREATE TRIGGER [Catalogue].[AuditServerConfig]
185 | ON [Catalogue].[ServerConfig]
186 | AFTER UPDATE
187 | AS
188 | BEGIN
189 | --audit old record
190 | INSERT INTO [Catalogue].[ServerConfig_Audit]
191 | ([ServerName], [SettingName], [SettingValue], [SettingValueInUse], [Notes], [AuditDate])
192 | SELECT ServerName,
193 | [SettingName],
194 | [SettingValue],
195 | [SettingValueInUse],
196 | [Notes],
197 | GETDATE()
198 | FROM deleted
199 | WHERE EXISTS (SELECT 1
200 | FROM inserted
201 | WHERE CHECKSUM(inserted.[SettingValue],
202 | inserted.[SettingValueInUse],
203 | inserted.[Notes])
204 | !=
205 | CHECKSUM(deleted.[SettingValue],
206 | deleted.[SettingValueInUse],
207 | deleted.[Notes])
208 | AND deleted.ServerName = inserted.ServerName
209 | AND deleted.[SettingName] = inserted.[SettingName])
210 | END
211 | GO
212 |
213 |
214 | --Update upgrade history
215 | INSERT INTO Catalogue.UpgradeHistory (UpgradeVersion,UpgradeDate)
216 | VALUES ('0.4.1',GETDATE())
217 | GO
218 |
219 | --Update ConfigPoSH
220 | UPDATE Catalogue.ConfigPoSH
221 | SET ParameterValue = '0.4.1'
222 | WHERE ParameterName = 'CatalogueVersion'
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Updates/Catalogue_UD042.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | @ ,@
4 | #@@ @@@
5 | @@@@@@@@@;
6 | @@@@@@@@@@
7 | :@@@@@@@@@@
8 | @@@@@@@@@@@
9 | @@@@@@@@@@@;
10 | @@@@@@@@@@@@
11 | @@@@@@@@@@@@
12 | `+@@@@@@@@@@+
13 |
14 |
15 | .@@` #@,
16 | .@@@@@@@@@@@@@@@@@@@@@@@@:
17 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@ @@ @@ #@ @ @
18 | #@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@@@ @@@@ @# #@ @ @
19 | ;@@@@@@@@@@@@@@@@@@@@@@@@@@' @ @ @# @# #@ @ #@@@ @@@@ @@@ @@@@@ @@@ @@ @ @ @@ @ @@
20 | .+@@@@@@@@@@@@@@@@+. @@@@ @ @@ @# #@ @ #@ @ @@ @ @ @ @@ @ @ @ `@ @ @ @ @ @@
21 | '` `,# @@@@ @ @@ @# #@ @ #@ @ @# @ @@@@@ @ @ @ @ @ @ @@@@ @`
22 | ,@@@@ '@@@@@@@@@@@@@ .@@@@; @ @ @@ @# #@ @ #@ @ @@ @ @@ @ ` @ @ @ @@@ @ @
23 | #@@@@@@ @@@@@ +@@@@ +@@@@@@ @@@@ @@@@ @@@@@ `@@@@@ #@ @ #@ @@ @ @ @ @@ @ @ @ @ @ @ @
24 | @@@@@@@@ ,#. `#; @@@@@@@@' @@ @@ @@@@@ @@, #@ @ @@ @ @@ @@ #@ @@ @ @@ @
25 | ;#@@@@@@@@ @@@@@@@@@#, @
26 | ,@@@@+ @@@@@+`
27 | .@@` `@@@@ ? www.sqlundercover.com
28 | +@@@@ @@@@@+
29 | @@@@@@@ @@@@@@@@#
30 | @@@@@@@ @@@@@@,
31 | @@@@@@@ @@@@@@,
32 | :@@@@@' ;@@@@`
33 | `@@@@ @@@+
34 | @#:@@
35 | @@
36 | @`
37 | #
38 |
39 | Sequential Upgrade - 0.4.2
40 | David Fowler
41 | 06/02/2020
42 |
43 | MIT License
44 | ------------
45 |
46 | Copyright 2019 Sql Undercover
47 |
48 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
49 | (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
50 | publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
51 | subject to the following conditions:
52 |
53 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
54 |
55 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
56 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
57 | FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
58 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
59 |
60 | */
61 |
62 | --new modules - Trace Flags
63 |
64 | CREATE TABLE Catalogue.TraceFlags
65 | (ServerName SYSNAME NOT NULL,
66 | TraceFlag INT NOT NULL,
67 | Notes VARCHAR(MAX) NULL,
68 | FirstRecorded DATETIME NOT NULL,
69 | LastRecorded DATETIME NOT NULL
70 | CONSTRAINT PK_TraceFlags PRIMARY KEY (ServerName, TraceFlag)
71 | )
72 | GO
73 |
74 | CREATE TABLE Catalogue.TraceFlags_Stage
75 | (ServerName SYSNAME NOT NULL,
76 | TraceFlag INT NOT NULL)
77 | GO
78 |
79 | CREATE TABLE Catalogue.TraceFlags_Audit
80 | (ServerName SYSNAME NOT NULL,
81 | TraceFlag INT NOT NULL,
82 | Notes VARCHAR(MAX) NULL,
83 | AuditDate DATETIME NOT NULL)
84 | GO
85 |
86 | INSERT INTO Catalogue.ConfigModules (ModuleName,GetProcName,UpdateProcName,StageTableName,MainTableName,Active)
87 | VALUES ('TraceFlags','DEPRECATED','DEPRECATED','TraceFlags_Stage','TraceFlags',1)
88 | GO
89 |
90 | DECLARE @ModuleID INT
91 |
92 | SELECT @ModuleID = ID
93 | FROM Catalogue.ConfigModules
94 | WHERE ModuleName = 'TraceFlags'
95 |
96 | INSERT INTO Catalogue.ConfigModulesDefinitions (ModuleID,Online,GetDefinition,UpdateDefinition,GetURL,UpdateURL)
97 | VALUES (@ModuleID,
98 | 1,
99 | '--Undercover Catalogue
100 | --David Fowler
101 | --Version 0.4.2 - 06 February 2020
102 | --Module: TraceFlags
103 | --Script: Get
104 |
105 | CREATE TABLE #TraceFlags
106 | (
107 | TraceFlag INT,
108 | Status BIT,
109 | Global BIT,
110 | Session BIT
111 | )
112 |
113 | INSERT INTO #TraceFlags
114 | EXEC sp_executesql N''DBCC tracestatus''
115 |
116 | SELECT @@SERVERNAME AS ServerName, TraceFlag
117 | FROM #TraceFlags',
118 | '--Undercover Catalogue
119 | --David Fowler
120 | --Version 0.4.2 - 6 February 2020
121 | --Module: Databases
122 | --Script: Update
123 |
124 |
125 | BEGIN
126 |
127 | --update trace flags where they are known to the catalogue
128 | UPDATE Catalogue.TraceFlags
129 | SET ServerName = TraceFlags_Stage.ServerName,
130 | TraceFlag = TraceFlags_Stage.TraceFlag,
131 | LastRecorded = GETDATE()
132 | FROM Catalogue.TraceFlags_Stage
133 | WHERE TraceFlags_Stage.ServerName = TraceFlags.ServerName
134 | AND TraceFlags_Stage.TraceFlag = TraceFlags.TraceFlag
135 |
136 | --insert trace flags that are unknown to the catlogue
137 | INSERT INTO Catalogue.TraceFlags (ServerName, TraceFlag, FirstRecorded, LastRecorded)
138 | SELECT ServerName,
139 | TraceFlag,
140 | GETDATE(),
141 | GETDATE()
142 | FROM Catalogue.TraceFlags_Stage
143 | WHERE NOT EXISTS
144 | (SELECT 1 FROM Catalogue.TraceFlags
145 | WHERE TraceFlags_Stage.ServerName = TraceFlags.ServerName
146 | AND TraceFlags_Stage.TraceFlag = TraceFlags.TraceFlag)
147 | END',
148 | 'https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverCatalogue/ModuleDefinitions/GetTraceFlags.sql',
149 | 'https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverCatalogue/ModuleDefinitions/UpdateTraceFlags.sql')
150 | GO
151 |
152 |
153 |
154 | --cluster module
155 |
156 | CREATE TABLE Catalogue.Cluster
157 | (ClusterName NVARCHAR(128),
158 | QuorumType VARCHAR(50),
159 | QuorumState VARCHAR(50),
160 | MemberName NVARCHAR(128),
161 | MemberType NVARCHAR(50),
162 | QuorumVotes TINYINT,
163 | Notes VARCHAR(MAX),
164 | FirstRecorded DATETIME,
165 | LastRecorded DATETIME,
166 | CONSTRAINT PK_Cluster PRIMARY KEY (ClusterName, MemberName))
167 | GO
168 |
169 | CREATE TABLE Catalogue.Cluster_Stage
170 | (ClusterName NVARCHAR(128),
171 | QuorumType VARCHAR(50),
172 | QuorumState VARCHAR(50),
173 | MemberName NVARCHAR(128),
174 | MemberType NVARCHAR(50),
175 | QuorumVotes TINYINT)
176 | GO
177 |
178 | CREATE TABLE Catalogue.Cluster_Audit
179 | (ClusterName NVARCHAR(128),
180 | QuorumType VARCHAR(50),
181 | QuorumState VARCHAR(50),
182 | MemberName NVARCHAR(128),
183 | MemberType NVARCHAR(50),
184 | QuorumVotes TINYINT,
185 | AuditDate DATETIME)
186 | GO
187 |
188 | CREATE TRIGGER [Catalogue].[AuditCluster]
189 | ON [Catalogue].[Cluster]
190 | AFTER UPDATE
191 | AS
192 | BEGIN
193 | --audit old record
194 | INSERT INTO [Catalogue].[Cluster_Audit]
195 | ([ClusterName], [QuorumType], [QuorumState], [MemberName], [MemberType], [QuorumVotes], [AuditDate])
196 | SELECT [ClusterName],
197 | [QuorumType],
198 | [QuorumState],
199 | [MemberName],
200 | [MemberType],
201 | [QuorumVotes],
202 | GETDATE()
203 | FROM deleted
204 | WHERE EXISTS (SELECT 1
205 | FROM inserted
206 | WHERE CHECKSUM( inserted.[ClusterName],
207 | inserted.[QuorumType],
208 | inserted.[QuorumState],
209 | inserted.[MemberName],
210 | inserted.[MemberType],
211 | inserted.[QuorumVotes])
212 | !=
213 | CHECKSUM( deleted.[ClusterName],
214 | deleted.[QuorumType],
215 | deleted.[QuorumState],
216 | deleted.[MemberName],
217 | deleted.[MemberType],
218 | deleted.[QuorumVotes])
219 | AND deleted.[ClusterName] = inserted.[ClusterName]
220 | AND deleted.[MemberName] = inserted.[MemberName])
221 | END
222 | GO
223 |
224 | ALTER TABLE [Catalogue].[Cluster] ENABLE TRIGGER [AuditCluster]
225 | GO
226 |
227 |
228 |
229 |
230 | INSERT INTO Catalogue.ConfigModules (ModuleName,GetProcName,UpdateProcName,StageTableName,MainTableName,Active)
231 | VALUES ('Cluster','DEPRECATED','DEPRECATED','Cluster_Stage','Cluster',1)
232 | GO
233 |
234 | DECLARE @ModuleID INT
235 |
236 | SELECT @ModuleID = ID
237 | FROM Catalogue.ConfigModules
238 | WHERE ModuleName = 'Cluster'
239 |
240 | INSERT INTO Catalogue.ConfigModulesDefinitions (ModuleID,Online,GetDefinition,UpdateDefinition,GetURL,UpdateURL)
241 | VALUES (@ModuleID,
242 | 1,
243 | '--Undercover Catalogue
244 | --David Fowler
245 | --Version 0.4.2 - 07 February 2020
246 | --Module: Cluster
247 | --Script: Get
248 |
249 | SELECT cluster_name AS ClusterName,
250 | quorum_type_desc AS QuorumType,
251 | quorum_state_desc AS QuorumState,
252 | member_name AS MemberName,
253 | member_type_desc AS MemberType,
254 | number_of_quorum_votes AS QuorumVotes
255 | FROM sys.dm_hadr_cluster
256 | ,sys.dm_hadr_cluster_members',
257 | '--Undercover Catalogue
258 | --David Fowler
259 | --Version 0.4.2 - 7 February 2020
260 | --Module: Cluster
261 | --Script: Update
262 |
263 |
264 | BEGIN
265 |
266 | --update cluster flags where they are known to the catalogue
267 | UPDATE Catalogue.Cluster
268 | SET ClusterName = Cluster_Stage.ClusterName,
269 | QuorumType = Cluster_Stage.QuorumType,
270 | QuorumState = Cluster_Stage.QuorumState,
271 | MemberName = Cluster_Stage.MemberName,
272 | MemberType = Cluster_Stage.MemberType,
273 | QuorumVotes = Cluster_Stage.QuorumVotes,
274 | LastRecorded = GETDATE()
275 | FROM Catalogue.Cluster_Stage
276 | WHERE Cluster_Stage.ClusterName = Cluster.ClusterName
277 | AND Cluster_Stage.MemberName = Cluster.MemberName
278 |
279 |
280 | --insert cluster flags that are unknown to the catlogue
281 | INSERT INTO Catalogue.Cluster (ClusterName,QuorumType,QuorumState,MemberName,MemberType,QuorumVotes,FirstRecorded,LastRecorded)
282 | SELECT ClusterName,
283 | QuorumType,
284 | QuorumState,
285 | MemberName,
286 | MemberType,
287 | QuorumVotes,
288 | GETDATE(),
289 | GETDATE()
290 | FROM Catalogue.Cluster_Stage
291 | WHERE NOT EXISTS
292 | (SELECT 1 FROM Catalogue.Cluster
293 | WHERE Cluster_Stage.ClusterName = Cluster.ClusterName
294 | AND Cluster_Stage.MemberName = Cluster.MemberName)
295 |
296 | END',
297 | 'https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverCatalogue/ModuleDefinitions/GetCluster.sql',
298 | 'https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverCatalogue/ModuleDefinitions/UpdateCluster.sql')
299 | GO
300 |
301 |
302 |
303 |
304 | --update versions tables
305 |
306 | UPDATE Catalogue.ConfigPoSH
307 | SET ParameterValue = '0.4.2'
308 | WHERE ParameterName = 'CatalogueVersion'
309 |
310 | --update history
311 |
312 | INSERT INTO Catalogue.UpgradeHistory (UpgradeVersion, UpgradeDate)
313 | VALUES ('0.4.2', GETDATE())
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Updates/Catalogue_UD045.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | @ ,@
4 | #@@ @@@
5 | @@@@@@@@@;
6 | @@@@@@@@@@
7 | :@@@@@@@@@@
8 | @@@@@@@@@@@
9 | @@@@@@@@@@@;
10 | @@@@@@@@@@@@
11 | @@@@@@@@@@@@
12 | `+@@@@@@@@@@+
13 |
14 |
15 | .@@` #@,
16 | .@@@@@@@@@@@@@@@@@@@@@@@@:
17 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@ @@ @@ #@ @ @
18 | #@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@@@ @@@@ @# #@ @ @
19 | ;@@@@@@@@@@@@@@@@@@@@@@@@@@' @ @ @# @# #@ @ #@@@ @@@@ @@@ @@@@@ @@@ @@ @ @ @@ @ @@
20 | .+@@@@@@@@@@@@@@@@+. @@@@ @ @@ @# #@ @ #@ @ @@ @ @ @ @@ @ @ @ `@ @ @ @ @ @@
21 | '` `,# @@@@ @ @@ @# #@ @ #@ @ @# @ @@@@@ @ @ @ @ @ @ @@@@ @`
22 | ,@@@@ '@@@@@@@@@@@@@ .@@@@; @ @ @@ @# #@ @ #@ @ @@ @ @@ @ ` @ @ @ @@@ @ @
23 | #@@@@@@ @@@@@ +@@@@ +@@@@@@ @@@@ @@@@ @@@@@ `@@@@@ #@ @ #@ @@ @ @ @ @@ @ @ @ @ @ @ @
24 | @@@@@@@@ ,#. `#; @@@@@@@@' @@ @@ @@@@@ @@, #@ @ @@ @ @@ @@ #@ @@ @ @@ @
25 | ;#@@@@@@@@ @@@@@@@@@#, @
26 | ,@@@@+ @@@@@+`
27 | .@@` `@@@@ www.sqlundercover.com
28 | +@@@@ @@@@@+
29 | @@@@@@@ @@@@@@@@#
30 | @@@@@@@ @@@@@@,
31 | @@@@@@@ @@@@@@,
32 | :@@@@@' ;@@@@`
33 | `@@@@ @@@+
34 | @#:@@
35 | @@
36 | @`
37 | #
38 |
39 | Sequential Upgrade - 0.4.5
40 | David Fowler
41 | 15/04/2024
42 |
43 | MIT License
44 | ------------
45 |
46 | Copyright 2024 Sql Undercover
47 |
48 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
49 | (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
50 | publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
51 | subject to the following conditions:
52 |
53 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
54 |
55 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
56 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
57 | FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
58 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
59 |
60 | Change Log
61 | ----------
62 |
63 | BUG FIX: Bug causing problems representing file path in Databases moule
64 |
65 | */
66 |
67 |
68 | ----------------------------------------------------
69 | --Module Definition Changes
70 | ----------------------------------------------------
71 |
72 | DECLARE @ModuleID INT
73 |
74 | SELECT @ModuleID = ID
75 | FROM Catalogue.ConfigModules
76 | WHERE ModuleName = 'Databases'
77 |
78 | UPDATE Catalogue.ConfigModulesDefinitions
79 | SET GetDefinition = '--Undercover Catalogue
80 | --David Fowler
81 | --Version 0.4.5 - 10 September 2024
82 | --Module: Databases
83 | --Script: Get
84 | BEGIN
85 | --get all databases on server
86 | SELECT @@SERVERNAME AS ServerName
87 | ,databases.name AS DBName
88 | ,databases.database_id AS DatabaseID
89 | ,server_principals.name AS OwnerName
90 | ,databases.compatibility_level AS CompatibilityLevel
91 | ,databases.collation_name AS CollationName
92 | ,databases.recovery_model_desc AS RecoveryModelDesc
93 | ,availability_groups.name AS AGName
94 | ,files.FilePaths
95 | ,files.DatabaseSizeMB
96 | ,databases.state_desc AS StateDesc
97 | ,lastaccess.last_user_access
98 | FROM sys.databases
99 | LEFT OUTER JOIN sys.server_principals ON server_principals.sid = databases.owner_sid
100 | LEFT OUTER JOIN sys.availability_replicas ON availability_replicas.replica_id = databases.replica_id
101 | LEFT OUTER JOIN sys.availability_groups ON availability_groups.group_id = availability_replicas.group_id
102 | JOIN (
103 | SELECT database_id
104 | ,(SUM(CAST(size AS BIGINT)) * 8) / 1024 AS DatabaseSizeMB
105 | ,STUFF((
106 | SELECT '' ,'' + files2.physical_name
107 | FROM sys.master_files files2
108 | WHERE files2.database_id = files1.database_id
109 | FOR XML PATH('''')
110 | ), 1, 2, '''') AS FilePaths
111 | FROM sys.master_files files1
112 | GROUP BY database_id
113 | ) files ON files.database_id = databases.database_id
114 | JOIN (
115 | SELECT db_name(databases.database_id) AS DBName
116 | ,(
117 | SELECT MAX(last_user_access)
118 | FROM (
119 | VALUES (MAX(last_user_seek))
120 | ,(MAX(last_user_scan))
121 | ,(MAX(last_user_lookup))
122 | ) AS value(last_user_access)
123 | ) AS last_user_access
124 | FROM sys.dm_db_index_usage_stats indexstats
125 | RIGHT OUTER JOIN sys.databases databases ON indexstats.database_id = databases.database_id
126 | GROUP BY databases.database_id
127 | ) AS lastaccess ON databases.name = lastaccess.DBName
128 | WHERE databases.source_database_id IS NULL
129 | END'
130 | WHERE ModuleID = @ModuleID
131 |
132 |
133 |
134 | --update versions tables
135 |
136 | UPDATE Catalogue.ConfigPoSH
137 | SET ParameterValue = '0.4.5'
138 | WHERE ParameterName = 'CatalogueVersion'
139 |
140 | --update history
141 |
142 | INSERT INTO Catalogue.UpgradeHistory (UpgradeVersion, UpgradeDate)
143 | VALUES ('0.4.5', GETDATE())
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Updates/Catalogue_UD050.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | @ ,@
4 | #@@ @@@
5 | @@@@@@@@@;
6 | @@@@@@@@@@
7 | :@@@@@@@@@@
8 | @@@@@@@@@@@
9 | @@@@@@@@@@@;
10 | @@@@@@@@@@@@
11 | @@@@@@@@@@@@
12 | `+@@@@@@@@@@+
13 |
14 |
15 | .@@` #@,
16 | .@@@@@@@@@@@@@@@@@@@@@@@@:
17 | @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@ @@ @@ #@ @ @
18 | #@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@ @@@@ @@@@ @# #@ @ @
19 | ;@@@@@@@@@@@@@@@@@@@@@@@@@@' @ @ @# @# #@ @ #@@@ @@@@ @@@ @@@@@ @@@ @@ @ @ @@ @ @@
20 | .+@@@@@@@@@@@@@@@@+. @@@@ @ @@ @# #@ @ #@ @ @@ @ @ @ @@ @ @ @ `@ @ @ @ @ @@
21 | '` `,# @@@@ @ @@ @# #@ @ #@ @ @# @ @@@@@ @ @ @ @ @ @ @@@@ @`
22 | ,@@@@ '@@@@@@@@@@@@@ .@@@@; @ @ @@ @# #@ @ #@ @ @@ @ @@ @ ` @ @ @ @@@ @ @
23 | #@@@@@@ @@@@@ +@@@@ +@@@@@@ @@@@ @@@@ @@@@@ `@@@@@ #@ @ #@ @@ @ @ @ @@ @ @ @ @ @ @ @
24 | @@@@@@@@ ,#. `#; @@@@@@@@' @@ @@ @@@@@ @@, #@ @ @@ @ @@ @@ #@ @@ @ @@ @
25 | ;#@@@@@@@@ @@@@@@@@@#, @
26 | ,@@@@+ @@@@@+`
27 | .@@` `@@@@ www.sqlundercover.com
28 | +@@@@ @@@@@+
29 | @@@@@@@ @@@@@@@@#
30 | @@@@@@@ @@@@@@,
31 | @@@@@@@ @@@@@@,
32 | :@@@@@' ;@@@@`
33 | `@@@@ @@@+
34 | @#:@@
35 | @@
36 | @`
37 | #
38 |
39 | Sequential Upgrade - 0.5.0
40 | David Fowler
41 | 25/07/2024
42 |
43 | MIT License
44 | ------------
45 |
46 | Copyright 2024 Sql Undercover
47 |
48 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
49 | (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
50 | publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
51 | subject to the following conditions:
52 |
53 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
54 |
55 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
56 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
57 | FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
58 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
59 |
60 | Change Log
61 | ----------
62 |
63 | NEW TABLE - EventLog, used to store a detailed runtime event log - requires the SQLUndercover Interrogator service
64 |
65 | */
66 |
67 | ---------------------------------------------------
68 | --Schema Changes
69 | ---------------------------------------------------
70 |
71 | CREATE TABLE Catalogue.EventLog
72 | (ID INT IDENTITY(1,1),
73 | LogDate Datetime,
74 | Message VARCHAR(200))
75 |
76 | --update versions tables
77 |
78 | UPDATE Catalogue.ConfigPoSH
79 | SET ParameterValue = '0.5.0'
80 | WHERE ParameterName = 'CatalogueVersion'
81 |
82 | --update history
83 |
84 | INSERT INTO Catalogue.UpgradeHistory (UpgradeVersion, UpgradeDate)
85 | VALUES ('0.5.0', GETDATE())
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Updates/Manifest.csv:
--------------------------------------------------------------------------------
1 | Latest Version,0.4.4,
2 | Minimum PoSH Version,0.4.0,
3 | Update,0.4.0,Catalogue_UD040.sql
4 | Update,0.4.1,Catalogue_UD041.sql
5 | Update,0.4.2,Catalogue_UD042.sql
6 | Update,0.4.3,Catalogue_UD043.sql
7 | Update,0.4.4,Catalogue_UD044.sql
8 | Update,0.4.5,Catalogue_UD045.sql
9 |
--------------------------------------------------------------------------------
/SQLUndercoverCatalogue/Useful Scripts/Find Missing and Mismatched Logins.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverCatalogue/Useful Scripts/Find Missing and Mismatched Logins.sql
--------------------------------------------------------------------------------
/SQLUndercoverInspector/Deprecated/V1 - Additional files/Inspector_Template.pbit:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/Deprecated/V1 - Additional files/Inspector_Template.pbit
--------------------------------------------------------------------------------
/SQLUndercoverInspector/Deprecated/V1 - Additional files/Install-Inspector.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | MIT License
3 | ------------
4 |
5 | Copyright 2019 Sql Undercover
6 |
7 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files
8 | (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge,
9 | publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so,
10 | subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
13 |
14 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
15 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE
16 | FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION
17 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
18 | #>
19 |
20 | #THIS SCRIPT IS STILL A WORK IN PROGRESS!
21 |
22 | #set variables
23 | $ScriptURL="https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverInspector/SQLUndercoverinspectorV1.sql"
24 | $CentralServer = "SQL02"
25 | $SQLInstances = "SQL01,SQL03"
26 | $DefaultDatabase = "SQLUndercoverDB"
27 | $TempDir = "C:\Temp\InspectorInstall"
28 | $DataDrive = "S,U"
29 | $LogDrive = "T,V"
30 | #Optional Parameters
31 | $BackupsPath = "NULL" #"NULL" or backups Path
32 | $LinkedServername = "NULL" #"NULL" or Linked server name
33 |
34 |
35 | IF ($BackupsPath -ne "NULL") {
36 | $BackupsPath = "'"+$BackupsPath+"'";
37 | }
38 |
39 | IF ($LinkedServername -ne "NULL") {
40 | $LinkedServername = "'"+$LinkedServername+"'";
41 | }
42 |
43 | $InstallScript = "
44 | EXEC [Inspector].[InspectorSetup]
45 | --Required Parameters (No defaults)
46 | @Databasename = '$DefaultDatabase',
47 | @DataDrive = '$DataDrive',
48 | @LogDrive = '$LogDrive',
49 | --Optional Parameters (Defaults Specified), ignored when @InitialSetup = 0
50 | @BackupsPath = $BackupsPath,
51 | @LinkedServername = $LinkedServername,
52 | @StackNameForEmailSubject = 'SQLUndercover',
53 | @EmailRecipientList = NULL,
54 | @DriveSpaceHistoryRetentionInDays = 90,
55 | @DaysUntilDriveFullThreshold = 56,
56 | @FreeSpaceRemainingPercent = 10,
57 | @DriveLetterExcludes = NULL,
58 | @DatabaseGrowthsAllowedPerDay = 1,
59 | @MAXDatabaseGrowthsAllowedPerDay = 10,
60 | @AgentJobOwnerExclusions = 'sa',
61 | @FullBackupThreshold = 8,
62 | @DiffBackupThreshold = 2,
63 | @LogBackupThreshold = 20,
64 | @DatabaseOwnerExclusions = 'sa',
65 | @LongRunningTransactionThreshold = 300,
66 | @InitialSetup = 0;
67 | "
68 |
69 | #Retrieve the Inspector Installation SQL
70 | Try {
71 | Invoke-WebRequest $ScriptURL -Outfile $TempDir -ContentType 'sql'
72 | }
73 | Catch {
74 | write-host $_.Exception.Message -ForegroundColor Red
75 | Return;
76 | }
77 |
78 |
79 | #For The Central server create the InspectorSetup stored proc and execute it to install
80 |
81 | Try {
82 | write-host "Creating [Inspector].[InspectorSetup] on [$CentralServer]";
83 | Invoke-Sqlcmd -InputFile $TempDir -ServerInstance $CentralServer -database $DefaultDatabase
84 | write-host "Running [Inspector].[InspectorSetup] on [$CentralServer]";
85 | Invoke-Sqlcmd -Query $InstallScript -ServerInstance $CentralServer -database $DefaultDatabase
86 | }
87 | Catch {
88 | write-host $_.Exception.Message
89 | write-host "Inspector install failed on [$CentralServer]" -ForegroundColor Red
90 | Return;
91 | }
92 |
93 |
94 | write-host "Inspector install successful on [$CentralServer]" -ForegroundColor Green
95 |
96 |
97 |
98 |
99 | #For Each server create the InspectorSetup stored proc and execute it to install
100 | ForEach ($SQLInstance in $SQLInstances.Split(","))
101 | {
102 |
103 | Try {
104 | write-host "Creating [Inspector].[InspectorSetup] on [$SQLInstance]";
105 | Invoke-Sqlcmd -InputFile $TempDir -ServerInstance $SQLInstance -database $DefaultDatabase
106 | write-host "Running [Inspector].[InspectorSetup] on [$SQLInstance]";
107 | Invoke-Sqlcmd -Query $InstallScript -ServerInstance $SQLInstance -database $DefaultDatabase
108 | }
109 | Catch {
110 | write-host $_.Exception.Message
111 | write-host "Inspector install failed on [$SQLInstance]" -ForegroundColor Red
112 | Break;
113 | }
114 |
115 | write-host "Inspector install successful on [$SQLInstance]" -ForegroundColor Green
116 |
117 |
118 | }
119 |
120 |
121 | #Remove the Installation file
122 | Remove-Item -Path $TempDir
123 |
124 |
125 |
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/All Inspector custom modules.zip:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/V2 - Additional files/All Inspector custom modules.zip
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/All Powershell Inspector files.zip:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/V2 - Additional files/All Powershell Inspector files.zip
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/InspectorV2.pbit:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/V2 - Additional files/InspectorV2.pbit
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/Inspector_BlitzFileStats_CustomModule.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/V2 - Additional files/Inspector_BlitzFileStats_CustomModule.sql
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/Inspector_BlitzWaits_CustomModule.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/V2 - Additional files/Inspector_BlitzWaits_CustomModule.sql
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/Manifest.csv:
--------------------------------------------------------------------------------
1 | Modulename,LastUpdated,URL
2 | SQLUndercoverinspectorV2.sql,06/12/2021,https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverInspector/SQLUndercoverinspectorV2.sql
3 | Inspector_CPU_CustomModule.sql,20/07/2021,https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverInspector/V2%20-%20Additional%20files/Inspector_CPU_CustomModule.sql
4 | Inspector_Catalogue_CustomModule.sql,03/12/2020,https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverInspector/V2%20-%20Additional%20files/Inspector_Catalogue_CustomModule.sql
5 | Inspector_BlitzWaits_CustomModule.sql,03/12/2020,https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverInspector/V2%20-%20Additional%20files/Inspector_BlitzWaits_CustomModule.sql
6 | Inspector_BlitzFileStats_CustomModule.sql,03/12/2020,https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/master/SQLUndercoverInspector/V2%20-%20Additional%20files/Inspector_BlitzFileStats_CustomModule.sql
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/Offline Auto Updates.zip:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/SQLUndercoverInspector/V2 - Additional files/Offline Auto Updates.zip
--------------------------------------------------------------------------------
/SQLUndercoverInspector/V2 - Additional files/Swap view MultiWarningModules for table.sql:
--------------------------------------------------------------------------------
1 | IF EXISTS (SELECT * FROM sys.views WHERE [schema_id] = SCHEMA_ID(N'Inspector') AND [name]= N'MultiWarningModules')
2 | BEGIN
3 | DROP VIEW [Inspector].[MultiWarningModules];
4 | END
5 |
6 | IF OBJECT_ID('Inspector.MultiWarningModules',N'U') IS NULL
7 | BEGIN
8 | CREATE TABLE [Inspector].[MultiWarningModules] (
9 | [Modulename] VARCHAR(50) NULL
10 | );
11 | END
12 |
13 | IF NOT EXISTS(SELECT 1 FROM [Inspector].[MultiWarningModules] WHERE [Modulename] IN ('DriveSpace','DatabaseGrowths','DatabaseStates'))
14 | BEGIN
15 | EXEC sp_executesql N'INSERT INTO [Inspector].[MultiWarningModules] ([Modulename])
16 | VALUES(''DriveSpace''),(''DatabaseGrowths''),(''DatabaseStates'');';
17 | END
--------------------------------------------------------------------------------
/SnapshotRestoreHistory.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 14/08/2023
5 | Version: 1
6 |
7 | Audit restores from snapshot
8 |
9 | © www.sqlundercover.com
10 |
11 |
12 | This script is for personal, educational, and internal
13 | corporate purposes, provided that this header is preserved. Redistribution or sale
14 | of this script,in whole or in part, is prohibited without the author's express
15 | written consent.
16 |
17 | The software is provided "as is", without warranty of any kind, express or
18 | implied, including but not limited to the warranties of merchantability,
19 | fitness for a particular purpose and noninfringement. in no event shall the
20 | authors or copyright holders be liable for any claim, damages or other
21 | liability, whether in an action of contract, tort or otherwise, arising from,
22 | out of or in connection with the software or the use or other dealings in the
23 | software.
24 |
25 | ******************************************************************/
26 |
27 | CREATE TABLE SnapshotRestoreHistory
28 | (LogDate DATETIME,
29 | ProcessInfo VARCHAR(10),
30 | [Text] VARCHAR(500) NOT NULL)
31 | GO
32 |
33 |
34 | CREATE PROC PopulateSnapshotRestoreHistory
35 |
36 | AS
37 |
38 | BEGIN
39 | --create temp holding table for log entries
40 | IF OBJECT_ID('tempdb.dbo.#SnapshotLogs') IS NOT NULL
41 | DROP TABLE #SnapshotLogs
42 |
43 | CREATE TABLE #SnapshotLogs
44 | (LogDate DATETIME,
45 | ProcessInfo VARCHAR(10),
46 | [Text] VARCHAR(500) NOT NULL)
47 |
48 |
49 | --temp table to be userd by Log sursor
50 | IF OBJECT_ID('tempdb.dbo.#LogFiles') IS NOT NULL
51 | DROP TABLE #LogFiles
52 |
53 | CREATE TABLE #LogFiles (LogNumber INT, StartDate DATETIME, SizeInBytes INT)
54 |
55 | INSERT INTO #LogFiles
56 | EXEC xp_enumerrorlogs
57 |
58 | DECLARE @LogNumber INT
59 | DECLARE LogCur CURSOR LOCAL FAST_FORWARD FOR
60 | SELECT LogNumber
61 | FROM #LogFiles
62 |
63 | OPEN LogCur
64 |
65 | FETCH NEXT FROM LogCur INTO @LogNumber
66 |
67 | WHILE @@FETCH_STATUS = 0
68 |
69 | BEGIN
70 | --get entries from log file
71 | INSERT INTO #SnapshotLogs
72 | EXEC [sys].[sp_readerrorlog] @LogNumber,1,'Reverting database'
73 |
74 | --merge log entries in to history table
75 | MERGE SnapshotRestoreHistory AS Target
76 | USING #SnapshotLogs
77 | ON Target.LogDate = #SnapshotLogs.LogDate
78 | AND Target.[Text] = #SnapshotLogs.[Text]
79 | WHEN NOT MATCHED BY Target THEN
80 | INSERT (LogDate,ProcessInfo,[Text])
81 | VALUES (#SnapshotLogs.LogDate,#SnapshotLogs.ProcessInfo,#SnapshotLogs.[Text]);
82 |
83 | FETCH NEXT FROM LogCur INTO @LogNumber
84 | END
85 |
86 | CLOSE LogCur
87 |
88 | DEALLOCATE LogCur
89 |
90 | END
--------------------------------------------------------------------------------
/Undercover Academy/SQL Server Backup and Recovery/1 Taking and Restoring a Backup/Taking and Restoring a Backup.sql:
--------------------------------------------------------------------------------
1 | /*
2 | SQL Undercover Academy
3 | https://sqlundercover.com
4 |
5 | SQL Server Backup and Recovery
6 |
7 | Module 1: Taking and Restoring a Backup
8 | David Fowler
9 | */
10 |
11 |
12 | --Taking a full backup
13 | BACKUP DATABASE SQLUndercover
14 | TO DISK = 'C:\SQLBackups\SQLUndercover.bak'
15 | WITH STATS, CHECKSUM, COMPRESSION
16 |
17 |
18 |
19 |
20 | --Restoring a backup to the same database
21 | RESTORE DATABASE SQLUndercover
22 | FROM DISK = 'C:\SQLBackups\SQLUndercover.bak'
23 | WITH STATS, REPLACE
24 |
25 |
26 |
27 | --Taking a differential backup
28 | BACKUP DATABASE SQLUndercover
29 | TO DISK = 'C:\SQLBackups\SQLUndercover.dif'
30 | WITH DIFFERENTIAL
31 |
32 |
33 |
34 | --Restoring a differential backup
35 | --first we need to restore the last full backup
36 |
37 | RESTORE DATABASE SQLUndercover
38 | FROM DISK = 'C:\SQLBackups\SQLUndercover.bak'
39 | WITH STATS, REPLACE
40 |
41 | RESTORE DATABASE SQLUndercover
42 | FROM DISK = 'C:\SQLBackups\SQLUndercover.dif'
43 | WITH STATS
44 |
45 |
46 |
47 |
48 |
49 |
50 | --we need to remember to restore using NORECOVERY
51 | RESTORE DATABASE SQLUndercover
52 | FROM DISK = 'C:\SQLBackups\SQLUndercover.bak'
53 | WITH STATS, REPLACE, NORECOVERY
54 |
55 | RESTORE DATABASE SQLUndercover
56 | FROM DISK = 'C:\SQLBackups\SQLUndercover.dif'
57 | WITH STATS
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/01-LoadAssembly.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Loading the assembly
3 |
4 | In order to use SMO you need to load the assembly.
5 | An assembly is basically a fancy way of saying a .net DLL
6 | that gets loaded into memory.
7 |
8 | #>
9 |
10 | ##Now you'll notice that we're using LoadWithPartialName here.
11 | ##The PS team doesn't like us using that anymore because they prefer
12 | ##that we load the full assembly name. It avoids problems with
13 | ##multiple versions of DLLs that may be loaded into the GAC.
14 | ##As DBAs we usually don't have those types of issues cause we tend
15 | ##to only have 1 version of SQL loaded at a time.
16 | ##So I believe that it's ok when dealing with SMO unless you
17 | ##specifically have issues.
18 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
19 |
20 | ##Here's an example of loading with the full name.
21 | ##You can see why we prefer the other way.
22 | [reflection.assembly]::load("Microsoft.SqlServer.SMO, Version=10.0.0.0, culture=neutral, publickeytoken=89845dcd8080cc91")
23 |
24 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/02-BasicConn.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Basic Connection
3 |
4 | Connecting to a server is easy, so don't make it any harder
5 | than it is.
6 | There are a number of considerations when connecting, but the
7 | basics are easy. We'll be discussing some of these throughout
8 | the session.
9 |
10 | #>
11 |
12 | ##Load the assembly.
13 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
14 |
15 | ##Create a var as an SMO server object.
16 | #$srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server');
17 | ##It took me a long time to fully understand this, but it's
18 | ##basic OOP. Here's what I hope is a good explanation.
19 |
20 | ##Vars have to have a datatype. In fact, all vars are objects.
21 | ##Let's take a look at this real quick.
22 |
23 | $a = 5;
24 | $b = "Hello";
25 | $c = dir .\*.ps1;
26 |
27 | ##Now let's run this in PS with dot-sourcing.
28 | ##We can now run a gm on each of the vars and see their members.
29 | ##You'll notice that each one of them had completely diff members
30 | ##and they're also listed as different types.
31 |
32 | ##Also, if we just print the $srv var to the screen, we can see
33 | ##its properties. Pay special attention to the ConnectionContext
34 | ##property and you can see that it makes a default conn in the
35 | ##absence of any other params being passed in. It also defaults
36 | ##to SSPI.
37 |
38 | ##Here are examples of connecting to remote servers.
39 | $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server') "bendycon";
40 | # $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server') "Server1\Inst1";
41 |
42 | # $Instance = "bendycon";
43 | # $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server') $Instance;
44 |
45 |
46 |
47 |
48 |
49 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/03-SQLAuth.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | SQL Authentication
3 |
4 | Sometimes you may need to use sql auth.
5 |
6 | !!!And despite what I do here, you shouldn't keep pwords in scripts.
7 | You should keep it encrypted somewhere and decrypt it in the
8 | script instead.!!!
9 |
10 | #>
11 |
12 | ##Load the assembly.
13 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
14 |
15 | ##Create a var as an SMO server object.
16 | $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server');
17 | $srv.ConnectionContext.LoginSecure = false;
18 | $srv.ConnectionContext.Login = "sa";
19 | $srv.ConnectionContext.Password = "Silversurfer1!";
20 | $srv.ConnectionContext.ApplicationName = "SMO from PS";
21 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/04-ExploringObjectModel.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Exploring the Object Model
3 |
4 | Now let's get busy actually looking around the object model.
5 | You can see a diagram of it here:
6 | https://docs.microsoft.com/en-us/sql/relational-databases/server-management-objects-smo/smo-object-model-diagram?view=sql-server-2017
7 |
8 | #>
9 |
10 | ##Load the assembly.
11 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
12 |
13 | ##Create a var as an SMO server object.
14 | $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server');
15 |
16 | ###Start with gm on $srv.
17 | #$srv | gm;
18 | #$srv.connectioncontext
19 | ###Now gm on databases.
20 | #$srv.databases | gm;
21 |
22 | ###Get info on all DBs.
23 | #$srv.databases | FT Name, Size, DataSpaceUsage, IndexSpaceUsage, SpaceAvailable -auto;
24 |
25 | ###Get info on a single DB.
26 | #$srv.databases["Minion"] | FT Name, Size, DataSpaceUsage, IndexSpaceUsage, SpaceAvailable -auto;
27 |
28 | ###Get info on a single DB with var. This lets you pass it into the script.
29 | #$DB = "Minion";
30 | #$srv.databases[$DB] | FT Name, Size, DataSpaceUsage, IndexSpaceUsage, SpaceAvailable -auto;
31 |
32 | ###Get info on a list of specific DBs and put into grid.
33 | #$srv.databases | ?{ $_.Name -match "^Min" } | select Name, Size, DataSpaceUsage, IndexSpaceUsage, SpaceAvailable | out-gridView;
34 |
35 | ###!!!The problem with the above is that SMO is horribly documented.
36 | ###Look at the sizes above. They're in diff metrics.
37 | ###Size is MB. Rest are in KB.
38 |
39 | ###Combine methods and get a list of all tables.
40 | #$srv.databases["Minion"].Tables.Name;
41 | ###Now get the index names.
42 | #$srv.databases["Minion"].Tables.Indexes.Name;
43 | ###Now get the names of the indexes for a single table.
44 | ###Notice it doesn't find the table cause it's not in dbo.
45 | #$srv.databases["Minion"].Tables["TableProperties"].Indexes.Script();
46 | ###There's an overload for the tables collection that adds schema.
47 | ###However, I don't like it cause it comes after the table instead of before.
48 | #$srv.databases["Minion"].Tables["TableProperties", "Collector"].Indexes.Script();
49 | ###Finally, script a single index for that table.
50 | #$srv.databases["Minion"].Tables["TableProperties", "Collector"].Indexes["nonDBName"].Script();
51 |
52 | ###################Exploring Jobs##################
53 | ###See where it is in the OM... notice it's a collection.
54 | #$srv | gm
55 | ###See everything the JobServer has to offer.
56 | #$srv.JobServer | gm;
57 | ###Get names of all jobs.
58 | #$srv.JobServer.Jobs.Name;
59 |
60 | <#
61 | This has just been a walkthrough of the model and some of the syntax.
62 | There are obvious problems with this:
63 | -You can't list schemas along with the objects
64 | -You can't limit by schema or object name.
65 | -Since you're dealing with entire collections it can take longer
66 | to get going and it may take up lots more memory on the server
67 | to hold all of the scripted objects before it spits them out.
68 |
69 | Next we're going to look at some more useful methods for working
70 | with SMO.
71 | #>
72 |
73 |
74 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/05-LimitingObjects.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Limiting Objects
3 |
4 | Here we're going to work on limiting the info we're bringing back.
5 | Some methods are better than others, but oddly, for pulling from multiple
6 | objects, there's no obviously fast method.
7 | #>
8 |
9 | ##Load the assembly.
10 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
11 |
12 | ##Create a var as an SMO server object.
13 | $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server');
14 |
15 | $Begin = Get-Date;
16 |
17 | ###Get info on a single DB.
18 | ###We've already seen this but it's a good review.
19 | $srv.databases["SSISDB"] | FT Name, Size, DataSpaceUsage, IndexSpaceUsage, SpaceAvailable -auto;
20 |
21 | #$srv.databases | ?{$_.Name -eq "MinionTest"} | FT Name, Size, DataSpaceUsage, IndexSpaceUsage, SpaceAvailable -auto;
22 |
23 |
24 | ###What if you need to pull from a list of DBs?
25 | ###Like everything else, there's more than 1 way.
26 | ###Here we're seeing which of these DBs has a specific table.
27 | #$DBList = "Minion", "MinionDev", "MM11", "MinionDemoOld";
28 | #$DBList | %{
29 | # $DBName = $_;
30 | #
31 | # IF ($srv.databases[$DBName].Tables.Contains("Servers", "dbo"))
32 | # {
33 | # "$DBName";
34 | # }
35 | #
36 | #}
37 |
38 | ###What if you need to pull from a list of DBs?
39 | ###Here we're seeing which of these DBs DON'T have a specific table.
40 | #$DBList = "Minion", "MinionDev", "MM11", "MinionDemoOld";
41 | #$DBList | %{
42 | # $DBName = $_;
43 | #
44 | # IF (!($srv.databases[$DBName].Tables.Contains("Servers", "dbo")))
45 | # {
46 | # "$DBName";
47 | # #$srv.databases[$DBName].Tables.Contains("Servers", "dbo")
48 | # }
49 | #
50 | #}
51 |
52 | ###Let's get all the DBs and whether they contain that table.
53 | ###While we're at it, let's get some sizing info.
54 | $DBList = "Minion", "MinionDev", "MM11", "MinionDemoOld";
55 | $results = @();
56 | $DBList | %{
57 | $DBName = $_;
58 | [int]$Exists = $srv.databases[$DBName].Tables.Contains("Servers", "dbo");
59 | [int]$Size = $srv.databases[$DBName].Tables["Servers", "dbo"].Size;
60 | [int]$DataSpace = $srv.databases[$DBName].Tables["Servers", "dbo"].DataSpaceUsed;
61 | $row = @{ }
62 |
63 | $row["DBName"] = $DBName;
64 | $row["Exists"] = $Exists;
65 | $row["Size"] = $Size;
66 | $row["DataSpace"] = $DataSpace;
67 |
68 | $results += new-object psobject -property $row;
69 | }
70 | $results | select DBName, Exists, DataSpace, Size;
71 |
72 |
73 |
74 | $End = Get-Date;
75 | #New-TimeSpan $Begin $End;
76 | <#
77 | This has just been a walkthrough of the model and some of the syntax.
78 | There are obvious problems with this:
79 | -You can't list schemas along with the objects
80 | -You can't limit by schema or object name.
81 | -Since you're dealing with entire collections it can take longer
82 | to get going and it may take up lots more memory on the server
83 | to hold all of the scripted objects before it spits them out.
84 |
85 | Next we're going to look at some more useful methods for working
86 | with SMO.
87 | #>
88 |
89 |
90 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/06-Methods.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Calling Methods
3 |
4 | Now it's time to do some work. Until now we've only been
5 | looking at things... auditing. But now we're going to be making
6 | changes.
7 |
8 | !!Legal Disclaimer: Don't do anything on a production system
9 | without testing it first and you know the ramifications.
10 | I am NOT responsible for any use or misuse of anything you
11 | see here.
12 | #>
13 |
14 | ##Load the assembly.
15 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
16 |
17 | ##Create a var as an SMO server object.
18 | $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server');
19 | $so = New-Object ('Microsoft.SqlServer.Management.Smo.ScriptingOptions');
20 | $s = New-Object ('Microsoft.SqlServer.Management.Smo.Scripter') ($srv);
21 |
22 | $Begin = Get-Date;
23 |
24 | ###Again, as usual we'll start with gm on databases.
25 | #$srv.databases | gm;
26 |
27 | ###Let's see the RecoveryModel for all DBs.
28 | #$srv.Databases | FT Name, RecoveryModel -auto;
29 |
30 | ### It's too convoluted to look through all the objects,
31 | ###so let's limit it to what we're interested in.
32 | #$srv.databases | gm | ?{$_.Name -eq "RecoveryModel"};
33 |
34 | ###Change all RecoveryModels to Full/Simple, whichever it needs.
35 | ###Depending on the version you're on, you may need to use the
36 | ###number.
37 | ###It's easy to figure out which one it is because they go in order
38 | ###from most protective to least.
39 | ##1 - Full
40 | ##2 - Bulk
41 | ##3 - Simple
42 | #$srv.Databases | %{
43 | # $_.RecoveryModel = "Simple";
44 | # #$_.RecoveryModel = 1;
45 | # $_.Name;
46 | #}
47 |
48 | #$srv.Databases | FT Name, RecoveryModel -auto;
49 |
50 | ###So if we restart the PS shell and query again, you'll see
51 | ###that the changes don't appear to have been made. Why not?
52 | ###
53 | ###Notice there's a method called ALTER().
54 | ###Let's have a look.
55 | #$srv.databases | gm;
56 | #$srv.databases | gm | ?{$_.Name -eq "Alter"} | FL;
57 |
58 | ###Now let's try again.
59 | #$srv.Databases | %{
60 | # $_.RecoveryModel = "Simple";
61 | # #$_.RecoveryModel = 1;
62 | # $_.Alter();
63 | # $_.Name;
64 | #}
65 |
66 | ###Restart the shell and try again.
67 | #$srv.Databases | FT Name, RecoveryModel -auto;
68 |
69 | ###Basic scripting
70 | del C:\MyDBs\Tables.txt;
71 | $so.ScriptDrops = 1;
72 | $so.EnforceScriptingOptions = 0;
73 | $so.Indexes = 1;
74 | $TableList = $srv.databases["Minion"].Tables;
75 |
76 | #$s.Options.ScriptData = $true;
77 | $TableList | ?{$_.Name -eq "DBUsers" } | %{
78 | # $_.Script($so) | Out-File "C:\MyDBs\Tables.txt" -Append;
79 | # $so.ScriptDrops = 0;
80 | # $so.IncludeIfNotExists = 0;
81 | # $_.Script($so) | Out-File "C:\MyDBs\Tables.txt" -Append;
82 | $so.ScriptData = 1;
83 | $s.EnumScript($_) | Out-File "C:\MyDBs\Tables.txt" -Append;
84 | #$s.script($_)
85 |
86 | $_.Name;
87 | }
88 | $so
89 | notepad.exe C:\MyDBs\Tables.txt;
90 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/07-ScriptData1.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Scripting Data 1
3 |
4 | Here we're going to use the scripter class for some basic data
5 | scripting. It never gets more complicated than this using this
6 | class, but as scripts go, it's not very good.
7 |
8 | !!Legal Disclaimer: Don't do anything on a production system
9 | without testing it first and you know the ramifications.
10 | I am NOT responsible for any use or misuse of anything you
11 | see here.
12 | #>
13 |
14 | ##Load the assembly.
15 | [reflection.assembly]::loadwithpartialname("Microsoft.SqlServer.Smo") | out-null
16 |
17 | ##Create a var as an SMO server object.
18 | $srv = New-Object ('Microsoft.SqlServer.Management.Smo.Server');
19 | ##Create a var to hold the scripting options.
20 | $so = New-Object ('Microsoft.SqlServer.Management.Smo.ScriptingOptions');
21 | ##Create a var as a Scripter object.
22 | ##Notice that we have to pass it the $srv object so it knows
23 | ##which server to connect to so it can fetch the data.
24 | $s = New-Object ('Microsoft.SqlServer.Management.Smo.Scripter') ($srv);
25 |
26 | $BasePath = "C:\MyDBs";
27 | $FileName = "$BasePath\Tables.txt";
28 | $Begin = Get-Date;
29 |
30 | ###Basic scripting
31 | IF (Test-Path $FileName)
32 | {
33 | del $FileName;
34 | }
35 |
36 | $TableList = $srv.databases["Minion"].Tables;
37 |
38 | $s.Options.ScriptData = 1;
39 | $TableList | ?{$_.Name -eq "DBUsers" } | %{
40 |
41 | $s.EnumScript($_) | Out-File "$FileName" -Append;
42 | $_.Name;
43 | }
44 |
45 | notepad.exe $FileName;
46 |
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/08-ScriptData2.ps1:
--------------------------------------------------------------------------------
1 |
2 | [string]$Server = 'localhost';
3 | [string]$DBName = 'Minion';
4 | [string]$SchemaName = 'Collector';
5 | [string]$TableName = 'DBUsers';
6 | [string]$FileBase = "C:\MyDBs"
7 |
8 | <#
9 | Scripting Data 2
10 |
11 | You can also separate the schema and data collections by putting them
12 | in separate scripts.
13 |
14 | !!Legal Disclaimer: Don't do anything on a production system
15 | without testing it first and you know the ramifications.
16 | I am NOT responsible for any use or misuse of anything you
17 | see here.
18 | #>
19 |
20 | ##Load the assembly.
21 | [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SMO") | out-null;
22 |
23 | $srv = New-Object "Microsoft.SqlServer.Management.SMO.Server" #$server
24 | ##Create a var to hold the scripting options.
25 | $so = New-Object ('Microsoft.SqlServer.Management.Smo.ScriptingOptions');
26 |
27 | $so.ScriptDrops = 1;
28 | $so.IncludeIfNotExists = 1;
29 |
30 | # Get the database and table objects
31 | $DBList = $srv.Databases[$DBName]
32 | $TableList = $DBList.Tables | ?{ $_.Schema -eq $SchemaName -and $_.name -eq $TableName }
33 | $TableList | %{
34 |
35 | ###Script Exists and Drop.
36 | "-- $(Get-Date)" | Out-File "$FileBase\$SchemaName`.$TableName.txt";
37 | $so.ScriptDrops = 1;
38 | $so.IncludeIfNotExists = 1;
39 | $_.Script($so) | Out-File "$FileBase\$SchemaName`.$TableName.txt" -Append;
40 | ###Script Schema.
41 | $so.ScriptDrops = 0;
42 | $so.IncludeIfNotExists = 0;
43 | $_.Script($so) | Out-File "$FileBase\$SchemaName`.$TableName.txt" -Append;
44 |
45 | ###Script data. Calling external script.
46 | ##Set the path cause we're calling the script from a diff path.
47 | ##If we were calling the script from it's path we wouldn't
48 | ##need to do this.
49 | $Path = Split-Path -parent $PSCommandPath;
50 | Set-Location "$Path";
51 | ./DataScripter.ps1 $Server $DBName $SchemaName $TableName $FileBase;
52 | }
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/Beginning SMO.docx:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/Undercover TV Scripts/BeginningSMO/Beginning SMO.docx
--------------------------------------------------------------------------------
/Undercover TV Scripts/BeginningSMO/DataScripter.ps1:
--------------------------------------------------------------------------------
1 | param
2 | (
3 | [string]$Server = 'localhost',
4 | [string]$DBName = 'Minion',
5 | [string]$SchemaName = 'Collector',
6 | [string]$TableName = 'DBUsers',
7 | [string]$FileBase = "C:\MyDBs"
8 | )
9 | <#
10 | Data Scripter
11 |
12 | You can also separate the schema and data collections by putting them
13 | in separate scripts.
14 | This can be used as a plugin for many processes so you don't
15 | have to keep re-writing the code.
16 |
17 | !!Legal Disclaimer: Don't do anything on a production system
18 | without testing it first and you know the ramifications.
19 | I am NOT responsible for any use or misuse of anything you
20 | see here.
21 | #>
22 |
23 | $FileName = "$FileBase\$SchemaName`.$TableName`.txt";
24 | ##Load the assembly.
25 | [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SMO") | out-null;
26 |
27 | $srv = New-Object "Microsoft.SqlServer.Management.SMO.Server" $Server
28 | $scripter = New-Object ("Microsoft.SqlServer.Management.SMO.Scripter") ($srv)
29 |
30 | # Get the database and table objects
31 | $DBList = $srv.Databases[$DBName]
32 | $TableList = $DBList.Tables | ?{ $_.Schema -eq $SchemaName -and $_.Name -eq $TableName }
33 |
34 | # Set scripter options to ensure only data is scripted
35 | $scripter.Options.ScriptSchema = $false;
36 | $scripter.Options.ScriptData = $true;
37 |
38 | #$scripter.Options.FileName = "$FileName";
39 | $scripter.Options.ToFileOnly = $true
40 |
41 | # Output the script
42 | foreach ($s in $scripter.EnumScript($TableList.Urn))
43 | {
44 | write-host $s;
45 | $s | Out-File $FileName -Append;
46 |
47 | }
48 |
--------------------------------------------------------------------------------
/UpdateStaticstics.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/UpdateStaticstics.sql
--------------------------------------------------------------------------------
/Use Python to copy a SQL Login.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 26/10/2017
5 | Version: 1
6 |
7 | --Description: Copy logins from source server that don't exist on destination server
8 | @RecreateSIDOnMismatch = 1, Users with a mismatching SID are dropped and recreated with the same SID as on the source server
9 |
10 | © www.sqlundercover.com
11 |
12 |
13 | This script is for personal, educational, and internal
14 | corporate purposes, provided that this header is preserved. Redistribution or sale
15 | of this script,in whole or in part, is prohibited without the author's express
16 | written consent.
17 |
18 | The software is provided "as is", without warranty of any kind, express or
19 | implied, including but not limited to the warranties of merchantability,
20 | fitness for a particular purpose and noninfringement. in no event shall the
21 | authors or copyright holders be liable for any claim, damages or other
22 | liability, whether in an action of contract, tort or otherwise, arising from,
23 | out of or in connection with the software or the use or other dealings in the
24 | software.
25 |
26 | ******************************************************************/
27 |
28 |
29 | EXEC sp_execute_external_script
30 | @language = N'python',
31 | @script =
32 | N'import pyodbc
33 | import pandas as pa
34 |
35 | #build where clause
36 | if includes != "%":
37 | WhereClause = " AND name IN (''" + includes.replace(",","'',''") + "'')"
38 | elif excludes != "%":
39 | WhereClause = " AND name NOT IN (''" + excludes.replace(",","'',''") + "'')"
40 | else:
41 | WhereClause = ""
42 |
43 | #add WhereClause to the query
44 | query = query + WhereClause
45 |
46 | #get source connection
47 | SourceConnection = pyodbc.connect(sourceConnectionString)
48 | SourceLogins = pa.read_sql(query,SourceConnection)
49 |
50 | #get destination connection
51 | DestinationConnection = pyodbc.connect(destinationConnectionString)
52 | DestinationLogins = pa.read_sql(query,DestinationConnection)
53 |
54 | #get all logins that exist in source but not in destination, if RecreateOnSIDMismatch =1, also get logins where the SIDs are different
55 | if RecreateOnSIDMismatch == 0:
56 | MissingLogins = SourceLogins[~SourceLogins[''name''].isin(DestinationLogins[''name''])].dropna()
57 | else:
58 | MissingLogins = SourceLogins[~SourceLogins[''sid''].isin(DestinationLogins[''sid''])].dropna()
59 |
60 | #get accounts where SIDs differ but exist on both servers
61 | MismatchingLogins = DestinationLogins[DestinationLogins[''name''].isin(MissingLogins[''name''])].dropna()
62 |
63 | #drop mismatching logins
64 | for counter in range(len(MismatchingLogins.index)):
65 | Statement = "DROP LOGIN [" + MismatchingLogins.values[counter][0] + "]"
66 | DropLoginCursor = DestinationConnection.cursor()
67 | DropLoginCursor.execute(Statement)
68 | DropLoginCursor.commit()
69 |
70 | counter = 0
71 |
72 | #loop through and create logins on the destination server
73 | for counter in range(len(MissingLogins.index)):
74 | if MissingLogins.values[counter][0].find("\\") >= 0:
75 | Statement = "CREATE LOGIN [" + MissingLogins.values[counter][0] + "] FROM WINDOWS"
76 | else:
77 | Statement = "CREATE LOGIN [" + MissingLogins.values[counter][0] + "] WITH PASSWORD = 0x" + MissingLogins.values[counter][2].hex() + '' HASHED, SID = 0x'' + MissingLogins.values[counter][1].hex()
78 | NewLoginCursor = DestinationConnection.cursor()
79 | print(Statement)
80 | NewLoginCursor.execute(Statement)
81 | NewLoginCursor.commit()
82 |
83 | OutputDataSet = MissingLogins
84 | ',
85 | @params = N'@query VARCHAR(MAX),@includes VARCHAR(4000), @excludes VARCHAR(4000), @destinationConnectionString VARCHAR(4000), @sourceConnectionString VARCHAR(4000), @RecreateOnSIDMismatch BIT',
86 | @includes = '%',
87 | @excludes = '%',
88 | @destinationConnectionString = 'DRIVER={SQL Server};SERVER=laptop-fowlerd\sql2017;UID=PythonUser;PWD=P4ssw0rd',
89 | @sourceConnectionString = 'DRIVER={SQL Server};SERVER=laptop-fowlerd\sql2016;UID=PythonUser;PWD=P4ssw0rd',
90 | @RecreateOnSIDMismatch = 0,
91 | @query = 'select name, CAST(sid AS VARBINARY(256)) AS sid, ISNULL(CAST(LOGINPROPERTY(name,''PasswordHash'') AS VARBINARY(256)),0x0) AS PasswordHash FROM sys.syslogins WHERE name NOT LIKE ''NT AUTHORITY%'' AND name NOT LIKE ''NT SERVICE%'' AND name NOT LIKE ''sa'' AND name NOT LIKE ''#%##'''
92 | WITH RESULT SETS UNDEFINED
--------------------------------------------------------------------------------
/What if it all grows out.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/What if it all grows out.sql
--------------------------------------------------------------------------------
/When was my last backup taken.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 19/07/2017
5 | Version: 1
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | This script is for personal, educational, and internal
11 | corporate purposes, provided that this header is preserved. Redistribution or sale
12 | of this script,in whole or in part, is prohibited without the author's express
13 | written consent.
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 |
23 | ******************************************************************/
24 |
25 |
26 | SELECT name, [FULL], [DIFF], [LOG]
27 | FROM
28 | (SELECT databases.name, backup_start_date,
29 | CASE type
30 | WHEN 'D' THEN 'FULL'
31 | WHEN 'I' THEN 'DIFF'
32 | WHEN 'L' THEN 'LOG'
33 | END AS type
34 | FROM msdb..backupset backupset
35 | RIGHT OUTER JOIN sys.databases databases ON databases.name = backupset.database_name) rawtab
36 | PIVOT
37 | (MAX(backup_start_date)
38 | FOR type IN ([FULL],[DIFF],[LOG])) pivottab
--------------------------------------------------------------------------------
/fn_SplitString.sql:
--------------------------------------------------------------------------------
1 |
2 | /******************************************************************
3 |
4 | Author: David Fowler
5 | Revision date: 01/06/2017
6 | Version: 1
7 |
8 | Table valued function that breaks a delimited string into a table of discrete values
9 | URL: //sqlundercover.com/2017/06/01/undercover-toolbox-fn_splitstring-its-like-string_split-but-for-luddites-or-those-who-havent-moved-to-sql-2016-yet/
10 |
11 | © www.sqlundercover.com
12 |
13 |
14 | This script is for personal, educational, and internal
15 | corporate purposes, provided that this header is preserved. Redistribution or sale
16 | of this script,in whole or in part, is prohibited without the author's express
17 | written consent.
18 |
19 | The software is provided "as is", without warranty of any kind, express or
20 | implied, including but not limited to the warranties of merchantability,
21 | fitness for a particular purpose and noninfringement. in no event shall the
22 | authors or copyright holders be liable for any claim, damages or other
23 | liability, whether in an action of contract, tort or otherwise, arising from,
24 | out of or in connection with the software or the use or other dealings in the
25 | software.
26 |
27 | ******************************************************************/
28 |
29 |
30 | USE master
31 | GO
32 |
33 | CREATE FUNCTION fn_SplitString(@DelimitedString VARCHAR(MAX), @Delimiter CHAR(1) = ',')
34 | RETURNS @SplitStrings TABLE (StringElement VARCHAR(255))
35 |
36 | AS
37 |
38 | BEGIN
39 |
40 | WITH Split(XMLSplit)
41 | AS
42 | (SELECT CAST('' + REPLACE(@DelimitedString,@Delimiter,'') + '' AS XML))
43 | INSERT INTO @SplitStrings
44 | SELECT p.value('.', 'VARCHAR(255)')
45 | FROM Split
46 | CROSS APPLY XMLSplit.nodes('/element') t(p)
47 |
48 | RETURN
49 |
50 | END
--------------------------------------------------------------------------------
/move SQL files in bulk.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/move SQL files in bulk.sql
--------------------------------------------------------------------------------
/sp_AGFailover.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/sp_AGFailover.sql
--------------------------------------------------------------------------------
/sp_AGReconfigure.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/sp_AGReconfigure.sql
--------------------------------------------------------------------------------
/sp_ChangeAgentJobOperator.sql:
--------------------------------------------------------------------------------
1 | USE [master]
2 | GO
3 |
4 |
5 | /******************************************************************
6 |
7 | Author: Adrian Buckman
8 | Revision date: 14/09/2017
9 | Version: 1
10 |
11 | © www.sqlundercover.com
12 |
13 | http://sqlundercover.com/2017/09/14/undercover-toolbox-sp_changeagentjoboperator-scripting-out-change-of-notification-operator-deleting-andor-creating/
14 |
15 | This script is for personal, educational, and internal
16 | corporate purposes, provided that this header is preserved. Redistribution or sale
17 | of this script,in whole or in part, is prohibited without the author's express
18 | written consent.
19 |
20 | The software is provided "as is", without warranty of any kind, express or
21 | implied, including but not limited to the warranties of merchantability,
22 | fitness for a particular purpose and noninfringement. in no event shall the
23 | authors or copyright holders be liable for any claim, damages or other
24 | liability, whether in an action of contract, tort or otherwise, arising from,
25 | out of or in connection with the software or the use or other dealings in the
26 | software.
27 |
28 | ******************************************************************/
29 |
30 | SET ANSI_NULLS ON
31 | GO
32 |
33 | SET QUOTED_IDENTIFIER ON
34 | GO
35 |
36 | CREATE PROCEDURE [dbo].[sp_ChangeAgentJobOperator]
37 | (
38 | @OldOperatorName NVARCHAR(128),
39 | @NewOperatorName NVARCHAR(128),
40 | @CreateNewOperatorIfNotExists BIT = 0,
41 | @EmailAddress NVARCHAR(128) = NULL,
42 | @DeleteOldOperator BIT = 0
43 | )
44 | AS
45 | BEGIN
46 | SET NOCOUNT ON;
47 |
48 | IF EXISTS (SELECT Name FROM msdb.dbo.sysoperators WHERE name = @OldOperatorName)
49 | BEGIN
50 | IF EXISTS (SELECT Name FROM msdb.dbo.sysoperators WHERE name = @NewOperatorName) OR @NewOperatorName IS NULL
51 | BEGIN
52 |
53 | IF OBJECT_ID('TempDB..#AgentJobs') IS NOT NULL
54 | DROP TABLE #AgentJobs;
55 |
56 | CREATE TABLE #AgentJobs
57 | (
58 | job_id uniqueidentifier NOT NULL
59 | ,name nvarchar(128) NOT NULL
60 | ,notify_level_email int NOT NULL
61 | ,notify_level_netsend int NOT NULL
62 | ,notify_level_page int NOT NULL
63 | );
64 |
65 | INSERT INTO #AgentJobs
66 | EXEC msdb.dbo.sp_help_operator_jobs @Operator_name= @OldOperatorName;
67 |
68 | IF @DeleteOldOperator = 1
69 | BEGIN
70 |
71 | DECLARE @FailSafeOperator NVARCHAR(128)
72 | EXEC SYS.XP_INSTANCE_REGREAD N'HKEY_LOCAL_MACHINE', N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent', N'AlertFailSafeOperator',
73 | @FailSafeOperator output
74 |
75 | IF (@FailSafeOperator != @OldOperatorName OR @FailSafeOperator IS NULL)
76 | BEGIN
77 | INSERT INTO #AgentJobs (job_id,name,notify_level_email,notify_level_netsend,notify_level_page)
78 | VALUES ('00000000-0000-0000-0000-000000000000','','','','')
79 | END
80 | ELSE
81 | BEGIN
82 | RAISERROR('@OldOperatorName Specified is set as the Failsafe Operator - change this in SQL Server Agent > Properties > Alert system. SET @DeleteOldOperator = 0 if you do not want to output the Delete Operator Statement',11,0)
83 | END
84 | END
85 |
86 | SELECT #AgentJobs.name AS JobName,
87 | CASE WHEN @NewOperatorName IS NULL THEN
88 | 'EXEC msdb.dbo.sp_update_job @job_id=N'''+CAST(#AgentJobs.Job_id AS VARCHAR(36))+''',
89 | @notify_level_netsend=0,
90 | @notify_level_page=0,
91 | @notify_level_email=0,
92 | @notify_email_operator_name=N''''' + CHAR(13)+CHAR(10)
93 | WHEN @NewOperatorName IS NOT NULL THEN
94 | 'EXEC msdb.dbo.sp_update_job @job_id=N'''+CAST(#AgentJobs.Job_id AS VARCHAR(36))+''',
95 | @notify_email_operator_name=N'''+@NewOperatorName+'''' + CHAR(13)+CHAR(10)
96 | END AS ChangeToNewOperator,
97 | 'EXEC msdb.dbo.sp_update_job @job_id=N'''+CAST(#AgentJobs.Job_id AS VARCHAR(36))+''',
98 | @notify_email_operator_name=N'''+@OldOperatorName+'''' + CHAR(13)+CHAR(10) AS RevertBackToOldOperator,
99 | CASE
100 | #AgentJobs.Notify_Level_email
101 | WHEN 0 THEN 'Never'
102 | WHEN 1 THEN 'On success'
103 | WHEN 2 THEN 'On failure'
104 | WHEN 3 THEN 'Always'
105 | END AS EmailNotification,
106 | CASE
107 | #AgentJobs.Notify_Level_netsend
108 | WHEN 0 THEN 'Never'
109 | WHEN 1 THEN 'On success'
110 | WHEN 2 THEN 'On failure'
111 | WHEN 3 THEN 'Always'
112 | END AS NetSendNotification,
113 | CASE
114 | #AgentJobs.Notify_Level_page
115 | WHEN 0 THEN 'Never'
116 | WHEN 1 THEN 'On success'
117 | WHEN 2 THEN 'On failure'
118 | WHEN 3 THEN 'Always'
119 | END AS PageNotification,
120 | CAST(sysjobs.[Enabled] AS CHAR(1)) AS [Enabled]
121 | FROM #AgentJobs
122 | INNER JOIN msdb..sysjobs ON #AgentJobs.job_id = sysjobs.job_id
123 | WHERE #AgentJobs.job_id != '00000000-0000-0000-0000-000000000000'
124 | UNION ALL
125 | SELECT
126 | '',
127 | CASE WHEN @DeleteOldOperator = 1 THEN '--EXEC msdb.dbo.sp_delete_operator @name=N'''+@OldOperatorName+''''
128 | ELSE ''
129 | END,
130 | '',
131 | '',
132 | '',
133 | '',
134 | ''
135 | FROM #AgentJobs
136 | WHERE #AgentJobs.job_id = '00000000-0000-0000-0000-000000000000'
137 | ORDER BY JobName ASC
138 | END
139 | ELSE IF @NewOperatorName IS NOT NULL
140 | BEGIN
141 | RAISERROR('@NewOperatorName Specified does not exist SET @CreateNewOperatorIfNotExists = 1 or create via the Operators folder',1,0)
142 | IF @CreateNewOperatorIfNotExists = 1 AND @NewOperatorName IS NOT NULL
143 | BEGIN
144 | SELECT '/** Run the following Add Operator command then run the procedure again to see the list of agent jobs associated with the Old Operator **/'
145 | AS Create_NewOperator
146 | UNION ALL
147 | SELECT 'EXEC msdb.dbo.sp_add_operator @name=N'''+@NewOperatorName+''',
148 | @enabled=1,
149 | @weekday_pager_start_time=90000,
150 | @weekday_pager_end_time=180000,
151 | @saturday_pager_start_time=90000,
152 | @saturday_pager_end_time=180000,
153 | @sunday_pager_start_time=90000,
154 | @sunday_pager_end_time=180000,
155 | @pager_days=0,
156 | @category_name=N''[Uncategorized]''
157 | '+CASE WHEN @EmailAddress IS NOT NULL THEN ',@email_address=N'''+@EmailAddress+''''
158 | ELSE ''
159 | END
160 | AS Create_NewOperator
161 | END
162 | END
163 |
164 | END
165 | ELSE
166 | BEGIN
167 | RAISERROR('@OldOperatorName Specified does not exist',1,0)
168 | END
169 |
170 | END
171 | GO
--------------------------------------------------------------------------------
/sp_ChangeDatabaseOwnerShip.sql:
--------------------------------------------------------------------------------
1 | USE [master]
2 | go
3 |
4 |
5 | /******************************************************************
6 |
7 | Author: Adrian Buckman
8 | Revision date: 05/04/2019
9 |
10 | Description: Produce a script that will provide ALTER statements to change the database
11 | ownership to the new owner and also ALTER statements to revert back to the old owner
12 |
13 | © www.sqlundercover.com
14 |
15 |
16 | This script is for personal, educational, and internal
17 | corporate purposes, provided that this header is preserved. Redistribution or sale
18 | of this script,in whole or in part, is prohibited without the author's express
19 | written consent.
20 |
21 | The software is provided "as is", without warranty of any kind, express or
22 | implied, including but not limited to the warranties of merchantability,
23 | fitness for a particular purpose and noninfringement. in no event shall the
24 | authors or copyright holders be liable for any claim, damages or other
25 | liability, whether in an action of contract, tort or otherwise, arising from,
26 | out of or in connection with the software or the use or other dealings in the
27 | software.
28 |
29 | ******************************************************************/
30 |
31 |
32 |
33 | CREATE PROCEDURE sp_ChangeDatabaseOwnerShip
34 | (
35 | @DBOwner NVARCHAR(128) = NULL,
36 | @Help BIT = 0
37 | )
38 | AS
39 |
40 | IF @Help = 1
41 | BEGIN
42 | PRINT 'Parameters:
43 | @DBOwner NVARCHAR(128) - Set the new owner name here'
44 | END
45 |
46 | IF @Help = 0
47 | BEGIN
48 | DECLARE @UserSid VARBINARY = SUSER_SID(@DBOwner)
49 |
50 | IF @UserSid IS NOT NULL
51 | BEGIN
52 |
53 | SELECT DIstINCT
54 | sys.databases.name AS Databasename,
55 | COALESCE(SUSER_SNAME(sys.databases.owner_sid),'') AS CurrentOwner,
56 | 'ALTER AUTHORIZATION ON DATABASE::['+sys.databases.name +'] TO ['+@DBOwner+'];' AS ChangeToNewOwner,
57 | 'ALTER AUTHORIZATION ON DATABASE::['+sys.databases.name +'] TO ['+COALESCE(SUSER_SNAME(sys.databases.owner_sid),'')+'];' AS RevertToOriginalOwner
58 | FROM
59 | sys.databases
60 | LEFT JOIN sys.availability_databases_cluster ADC ON sys.databases.name = ADC.database_name
61 | LEFT JOIN sys.dm_hadr_availability_group_states st ON st.group_id = ADC.group_id
62 | LEFT JOIN master.sys.availability_groups ag ON st.group_id = ag.group_id
63 | WHERE (primary_replica = @@Servername
64 | AND sys.databases.owner_sid != @UserSid)
65 | OR (sys.databases.owner_sid != @UserSid
66 | AND sys.databases.state = 0
67 | AND sys.databases.source_database_id IS NULL
68 | AND sys.databases.replica_id IS NULL)
69 |
70 | END
71 | ELSE
72 | BEGIN
73 | RAISERROR('No SID found for the owner name you have provided - please check the owner name and try again',11,1)
74 | END
75 |
76 | END
--------------------------------------------------------------------------------
/sp_ChangeJobOwnerShip.sql:
--------------------------------------------------------------------------------
1 | USE [master]
2 | GO
3 |
4 | /******************************************************************
5 |
6 | Author: Adrian Buckman
7 | Revision date: 22/09/2017
8 | Version: 1
9 |
10 | © www.sqlundercover.com
11 |
12 | Description: Produce a script that will provide ALTER statements to change the Agent Job
13 | ownerships to the new owner and also ALTER statements to revert back to the old owner
14 |
15 |
16 | This script is for personal, educational, and internal
17 | corporate purposes, provided that this header is preserved. Redistribution or sale
18 | of this script,in whole or in part, is prohibited without the author's express
19 | written consent.
20 |
21 | The software is provided "as is", without warranty of any kind, express or
22 | implied, including but not limited to the warranties of merchantability,
23 | fitness for a particular purpose and noninfringement. in no event shall the
24 | authors or copyright holders be liable for any claim, damages or other
25 | liability, whether in an action of contract, tort or otherwise, arising from,
26 | out of or in connection with the software or the use or other dealings in the
27 | software.
28 |
29 | ******************************************************************/
30 |
31 |
32 |
33 | CREATE PROCEDURE [dbo].[sp_ChangeJobOwnerShip]
34 | (@JobOwner NVARCHAR(128) = NULL,
35 | @Help BIT = 0
36 | )
37 | AS
38 | IF @Help = 1
39 | BEGIN
40 | PRINT 'Parameters:
41 | @@JobOwner NVARCHAR(128) - Set the new owner name here';
42 | END;
43 | IF @Help = 0
44 | BEGIN
45 |
46 | DECLARE @UserSid VARBINARY= SUSER_SID(@JobOwner);
47 |
48 | IF @UserSid IS NOT NULL
49 | BEGIN
50 |
51 | SELECT [Name] AS [JobName],
52 | COALESCE(SUSER_SNAME([Jobs].[owner_sid]),'') AS [CurrentOwner],
53 | 'EXEC msdb.dbo.sp_update_job @job_name=N'''+[Name]+''', @owner_login_name=N'''+@JobOwner+''';' AS [ChangeToNewOwner],
54 | 'EXEC msdb.dbo.sp_update_job @job_name=N'''+[Name]+''', @owner_login_name=N'''+COALESCE(SUSER_SNAME([Jobs].[owner_sid]),'')+''';' AS [RevertToOriginalOwner]
55 | FROM [MSDB].[dbo].[sysjobs] [Jobs]
56 | WHERE [Jobs].[owner_sid] != @UserSid;
57 |
58 | END;
59 | ELSE
60 | BEGIN
61 | RAISERROR('No SID found for the owner name you have provided - please check the owner name and try again',11,1);
62 | END;
63 |
64 | END;
--------------------------------------------------------------------------------
/sp_FailedJobs.sql:
--------------------------------------------------------------------------------
1 | USE [master]
2 | GO
3 |
4 |
5 | /******************************************************************
6 |
7 | Author: Adrian Buckman
8 | Last Revision: David Fowler
9 | Revision date: 12/08/2019
10 | Version: 3
11 |
12 | © www.sqlundercover.com
13 |
14 |
15 | This script is for personal, educational, and internal
16 | corporate purposes, provided that this header is preserved. Redistribution or sale
17 | of this script,in whole or in part, is prohibited without the author's express
18 | written consent.
19 |
20 | The software is provided "as is", without warranty of any kind, express or
21 | implied, including but not limited to the warranties of merchantability,
22 | fitness for a particular purpose and noninfringement. in no event shall the
23 | authors or copyright holders be liable for any claim, damages or other
24 | liability, whether in an action of contract, tort or otherwise, arising from,
25 | out of or in connection with the software or the use or other dealings in the
26 | software.
27 |
28 | ******************************************************************/
29 |
30 |
31 |
32 | CREATE PROCEDURE sp_FailedJobs
33 | (
34 | @FromDate DATETIME = NULL,
35 | @ToDate DATETIME = NULL
36 | )
37 | AS
38 | BEGIN
39 |
40 | IF @FromDate IS NULL BEGIN SET @FromDate = DATEADD(Minute,-720,GETDATE()) END
41 | IF @ToDate IS NULL BEGIN SET @ToDate = GETDATE() END
42 |
43 | SELECT
44 | Jobs.name,
45 | Jobs.job_id,
46 | JobHistory.step_id,
47 | JobHistory.FailedRunDate,
48 | CAST(JobHistory.LastError AS VARCHAR(250)) AS LastError
49 | FROM msdb.dbo.sysjobs Jobs
50 | --Get the most recent Failure Datetime for each failed job within @FromDate and @ToDate
51 | CROSS APPLY (Select TOP 1
52 | JobHistory.step_id,
53 | JobHistory.run_date,
54 | CASE JobHistory.run_date WHEN 0 THEN NULL ELSE
55 | CONVERT(datetime,
56 | STUFF(STUFF(CAST(JobHistory.run_date as nchar(8)), 7, 0, '-'), 5, 0, '-') + N' ' +
57 | STUFF(STUFF(SUBSTRING(CAST(1000000 + JobHistory.run_time as nchar(7)), 2, 6), 5, 0, ':'), 3, 0, ':'),
58 | 120) END AS [FailedRunDate] ,
59 | [message] AS LastError
60 | FROM msdb.dbo.sysjobhistory JobHistory
61 | WHERE
62 | run_status = 0
63 | AND Jobs.job_id = JobHistory.job_id
64 | ORDER BY
65 | [FailedRunDate] DESC,step_id DESC) JobHistory
66 |
67 | WHERE Jobs.enabled = 1
68 | AND JobHistory.FailedRunDate >= @FromDate AND JobHistory.FailedRunDate <= @ToDate
69 | --Check that each job has not succeeded since the last failure
70 | AND NOT EXISTS (SELECT [LastSuccessfulrunDate]
71 | FROM(
72 | SELECT CASE JobHistory.run_date WHEN 0 THEN NULL ELSE
73 | convert(datetime,
74 | stuff(stuff(cast(JobHistory.run_date as nchar(8)), 7, 0, '-'), 5, 0, '-') + N' ' +
75 | stuff(stuff(substring(cast(1000000 + JobHistory.run_time as nchar(7)), 2, 6), 5, 0, ':'), 3, 0, ':'),
76 | 120) END AS [LastSuccessfulrunDate]
77 | FROM msdb.dbo.sysjobhistory JobHistory
78 | WHERE
79 | run_status = 1
80 | AND Jobs.job_id = JobHistory.job_id
81 | ) JobHistory2
82 | WHERE JobHistory2.[LastSuccessfulrunDate] > JobHistory.[FailedRunDate])
83 | --Ensure that the job is not currently running
84 | AND NOT EXISTS (SELECT session_id
85 | From msdb.dbo.sysjobactivity JobActivity
86 | where Jobs.job_id = JobActivity.job_id
87 | AND stop_execution_date is null
88 | AND session_id = (Select MAX(session_id) From msdb.dbo.sysjobactivity JobActivity
89 | where Jobs.job_id = JobActivity.job_id)
90 | )
91 | --Only show failed jobs where the Failed step is NOT configured to quit reporting success on error
92 | AND NOT EXISTS (SELECT 1
93 | FROM msdb..sysjobsteps ReportingSuccessSteps
94 | WHERE Jobs.job_id = ReportingSuccessSteps.job_id
95 | AND JobHistory.step_id = ReportingSuccessSteps.step_id
96 | AND on_fail_action = 1 -- quit job reporting success
97 | )
98 |
99 |
100 | ORDER BY name ASC
101 | END
--------------------------------------------------------------------------------
/sp_FailedLogins.sql:
--------------------------------------------------------------------------------
1 | USE [master]
2 | GO
3 |
4 |
5 | /******************************************************************
6 |
7 | Author: Adrian Buckman
8 | Revision date: 06/06/2017
9 | Version: 1
10 |
11 | © www.sqlundercover.com
12 |
13 |
14 | This script is for personal, educational, and internal
15 | corporate purposes, provided that this header is preserved. Redistribution or sale
16 | of this script,in whole or in part, is prohibited without the author's express
17 | written consent.
18 |
19 | The software is provided "as is", without warranty of any kind, express or
20 | implied, including but not limited to the warranties of merchantability,
21 | fitness for a particular purpose and noninfringement. in no event shall the
22 | authors or copyright holders be liable for any claim, damages or other
23 | liability, whether in an action of contract, tort or otherwise, arising from,
24 | out of or in connection with the software or the use or other dealings in the
25 | software.
26 |
27 | ******************************************************************/
28 |
29 | CREATE PROCEDURE [dbo].[sp_FailedLogins]
30 |
31 | (
32 | @FromDate DATETIME = NULL,
33 | @ToDate DATETIME = NULL
34 | )
35 | AS
36 |
37 | BEGIN
38 | --Failed login attempts in the last 60 minutes
39 |
40 | IF @FromDate IS NULL BEGIN SET @FromDate = DATEADD(MINUTE,-60,GETDATE()) END
41 | IF @ToDate IS NULL BEGIN SET @ToDate = GETDATE() END
42 |
43 | IF OBJECT_ID('Tempdb..#Errors') IS NOT NULL
44 | DROP TABLE #Errors
45 |
46 | CREATE TABLE #Errors
47 | (
48 | Logdate Datetime,
49 | Processinfo Varchar(30),
50 | Text Varchar (255)
51 | )
52 | INSERT INTO #Errors
53 | EXEC xp_ReadErrorLog 0, 1, N'FAILED',N'login',@FromDate,@ToDate;
54 |
55 | SELECT
56 | REPLACE(LoginErrors.Username,'''','') AS Username,
57 | CAST(LoginErrors.Attempts AS NVARCHAR(6)) AS Attempts,
58 | LatestDate.Logdate,
59 | Latestdate.LastError
60 | from (
61 | Select SUBSTRING(text,Patindex('%''%''%',Text),charindex('.',Text)-(Patindex('%''%''%',Text))) as Username,Count(*) AS Attempts
62 | From #Errors Errors
63 | GROUP BY SUBSTRING(text,Patindex('%''%''%',Text),charindex('.',Text)-(Patindex('%''%''%',Text)))
64 | ) LoginErrors
65 | CROSS APPLY (SELECT TOP 1 Logdate,text as LastError
66 | FROM #Errors LatestDate
67 | where LoginErrors.Username = SUBSTRING(text,Patindex('%''%''%',Text),charindex('.',Text)-(Patindex('%''%''%',Text)))
68 | ORDER by Logdate DESC) LatestDate
69 |
70 | Order by LoginErrors.Attempts DESC
71 |
72 | END
73 | GO
--------------------------------------------------------------------------------
/sp_LockDetails.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/sp_LockDetails.sql
--------------------------------------------------------------------------------
/sp_RunningJobs.sql:
--------------------------------------------------------------------------------
1 | USE [master];
2 | GO
3 |
4 | SET ANSI_NULLS ON;
5 | GO
6 | SET QUOTED_IDENTIFIER ON;
7 | GO
8 |
9 | /******************************************************************
10 |
11 | Author: Adrian Buckman
12 | Revision date: 07/08/2017
13 | Version: 2
14 |
15 | Description: Show all currently running agent jobs including:
16 | Started by
17 | Date and time the job started
18 | Date and time the current job step started
19 | Total job duration
20 | Current step duration
21 | Currently running step
22 |
23 | © www.sqlundercover.com
24 |
25 |
26 | This script is for personal, educational, and internal
27 | corporate purposes, provided that this header is preserved. Redistribution or sale
28 | of this script,in whole or in part, is prohibited without the author's express
29 | written consent.
30 |
31 | The software is provided "as is", without warranty of any kind, express or
32 | implied, including but not limited to the warranties of merchantability,
33 | fitness for a particular purpose and noninfringement. in no event shall the
34 | authors or copyright holders be liable for any claim, damages or other
35 | liability, whether in an action of contract, tort or otherwise, arising from,
36 | out of or in connection with the software or the use or other dealings in the
37 | software.
38 |
39 | ******************************************************************/
40 |
41 |
42 | CREATE PROCEDURE [dbo].[sp_RunningJobs]
43 | AS
44 | BEGIN
45 | DECLARE @CurrentDatetime DATETIME= GETDATE();
46 | IF OBJECT_ID('TempDB..#CurrentlyRunningJobs') IS NOT NULL
47 | DROP TABLE #CurrentlyRunningJobs;
48 | CREATE TABLE #CurrentlyRunningJobs
49 | (job_id UNIQUEIDENTIFIER NOT NULL,
50 | last_run_date INT NOT NULL,
51 | last_run_time INT NOT NULL,
52 | next_run_date INT NOT NULL,
53 | next_run_time INT NOT NULL,
54 | next_run_schedule_id INT NOT NULL,
55 | requested_to_run INT NOT NULL,
56 | request_source INT NOT NULL,
57 | request_source_id SYSNAME NULL,
58 | running INT NOT NULL,
59 | current_step INT NOT NULL,
60 | current_retry_attempt INT NOT NULL,
61 | job_state INT NOT NULL
62 | );
63 | INSERT INTO #CurrentlyRunningJobs
64 | EXECUTE master.dbo.xp_sqlagent_enum_jobs 1,'';
65 | SELECT Jobs.Name AS JobName,
66 | CASE
67 | WHEN run_requested_source = 4
68 | THEN 'User '+ISNULL('('+StartedUser+')', '')
69 | ELSE 'Agent'
70 | END AS StartedBy,
71 | CONVERT(VARCHAR(20), start_execution_date, 113) AS DateTimeJobStarted,
72 | CONVERT(VARCHAR(20), DATEADD(SECOND, DATEDIFF(SECOND, DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(SECOND, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), @CurrentDatetime - start_execution_date), CAST('1900-01-01 00:00:00.000' AS DATETIME)), @CurrentDatetime), 113) AS DateTimeStepStarted,
73 | CASE
74 | WHEN DATEDIFF(Second, start_execution_date, @CurrentDatetime) >= 86400
75 | THEN CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) / 86400 AS VARCHAR(7))+' Days '+RIGHT('0'+CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) % 86400 / 3600 AS VARCHAR(2)), 2)+' Hours '+RIGHT('0'+CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) % 3600 / 60 AS VARCHAR(2)), 2)+' Minutes '+RIGHT('0'+CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) % 60 AS VARCHAR(2)), 2)+' Seconds '
76 | ELSE RIGHT('0'+CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) / 3600 AS VARCHAR(2)), 2)+' Hours '+RIGHT('0'+CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) % 3600 / 60 AS VARCHAR(2)), 2)+' Minutes '+RIGHT('0'+CAST(DATEDIFF(Second, start_execution_date, @CurrentDatetime) % 60 AS VARCHAR(2)), 2)+' Seconds '
77 | END AS TotalJobDuration,
78 | CASE
79 | WHEN DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME)))) >= 86400
80 | THEN CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))/86400 AS VARCHAR(7))+' Days '+RIGHT('0'+CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))%86400/3600 AS VARCHAR(2)), 2)+' Hours '+RIGHT('0'+CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))%3600/60 AS VARCHAR(2)), 2)+' Minutes '+RIGHT('0'+CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))%60 AS VARCHAR(2)), 2)+' Seconds '
81 | ELSE RIGHT('0'+CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))/3600 AS VARCHAR(2)), 2)+' Hours '+RIGHT('0'+CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))%3600/60 AS VARCHAR(2)), 2)+' Minutes '+RIGHT('0'+CAST(DATEDIFF(Second, '1900-01-01 00:00:00.000', DATEADD(SECOND, -ISNULL(PreviousStepDurationInSecs, DATEDIFF(Second, start_execution_date, ISNULL(last_executed_step_date, start_execution_date))), (CAST(@CurrentDatetime - start_execution_date AS DATETIME))))%60 AS VARCHAR(2)), 2)+' Seconds '
82 | END AS TotalStepDuration,
83 | CASE
84 | WHEN Start_Execution_Date IS NOT NULL
85 | AND Last_Executed_Step_ID IS NULL
86 | AND Last_Executed_Step_date IS NULL
87 | AND Stop_Execution_Date IS NULL
88 | THEN 'Job Started at step '+CAST(RunningJobs.Current_step AS VARCHAR(3))+' but not completed'
89 | WHEN Start_Execution_Date IS NOT NULL
90 | AND Last_Executed_Step_ID IS NOT NULL
91 | AND Last_Executed_Step_date IS NOT NULL
92 | AND Stop_Execution_Date IS NULL
93 | THEN 'Job Running on step '+CAST(RunningJobs.Current_step AS VARCHAR(2))
94 | ELSE 'Finished'
95 | END AS JobState
96 | FROM msdb.dbo.sysjobs Jobs
97 | INNER JOIN msdb.dbo.syscategories Categories ON Jobs.category_id = Categories.category_id
98 | INNER JOIN msdb.dbo.sysjobactivity Activity ON Jobs.job_id = Activity.job_id
99 | INNER JOIN
100 | (
101 | SELECT Job_id,
102 | Current_step,
103 | CASE
104 | WHEN Request_Source = 4
105 | THEN Request_Source_ID
106 | END AS StartedUser
107 | FROM #CurrentlyRunningJobs RunningJobs
108 | WHERE running = 1
109 | ) RunningJobs ON RunningJobs.job_id = Jobs.job_id
110 | CROSS APPLY
111 | (
112 | SELECT SUM(DATEPART(SECOND, Duration) + DATEPART(MINUTE, Duration) * 60 + DATEPART(HOUR, Duration) * 3600) AS PreviousStepDurationInSecs
113 | FROM
114 | (
115 | SELECT CAST(STUFF(STUFF(SUBSTRING(CAST(1000000+JobHistory.run_duration AS NCHAR(7)), 2, 6), 5, 0, ':'), 3, 0, ':') AS TIME) AS Duration
116 | FROM msdb..sysjobhistory JobHistory
117 | WHERE job_id = Jobs.job_id
118 | AND instance_ID >
119 | (
120 | SELECT TOP 1 instance_ID AS [LastJobCompletion]
121 | FROM msdb..sysjobhistory JobHistory
122 | WHERE job_id = Jobs.job_id
123 | AND step_id = 0
124 | ORDER BY instance_id DESC
125 | )
126 | ) Runtimes
127 | ) Runtimes
128 | WHERE start_execution_date IS NOT NULL
129 | AND stop_execution_date IS NULL
130 | AND session_id =
131 | (
132 | SELECT MAX(session_id)
133 | FROM msdb.dbo.syssessions
134 | )
135 | AND Categories.name NOT LIKE 'REPL%' --Ignore any Replication jobs
136 | ORDER BY TotalJobDuration DESC;
137 | END;
--------------------------------------------------------------------------------
/sp_Snapshot.sql:
--------------------------------------------------------------------------------
1 | /******************************************************************
2 |
3 | Author: David Fowler
4 | Revision date: 26 January 2024
5 | Version: 2
6 |
7 | © www.sqlundercover.com
8 |
9 |
10 | This script is for personal, educational, and internal
11 | corporate purposes, provided that this header is preserved. Redistribution or sale
12 | of this script,in whole or in part, is prohibited without the author's express
13 | written consent.
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 |
23 | ******************************************************************/
24 |
25 | CREATE OR ALTER PROC sp_snapshot (
26 | @DatabaseList NVARCHAR(4000)
27 | ,@Suffix NVARCHAR(100) = 'snapshot'
28 | ,@FilePath NVARCHAR(255) = ''
29 | ,@Timestamp BIT = 0
30 | ,@DateFormat INT = 126
31 | ,@ListOnly BIT = 0
32 | )
33 | AS
34 | BEGIN
35 | SET NOCOUNT ON
36 |
37 | IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL
38 | DROP TABLE #DatabaseList
39 |
40 | CREATE TABLE #DatabaseList (name NVARCHAR(4000))
41 |
42 | IF OBJECT_ID('tempdb..#DatabasesFinal') IS NOT NULL
43 | DROP TABLE #DatabasesFinal
44 |
45 | IF @Timestamp = 1
46 | BEGIN
47 | SET @Suffix += '_' + CONVERT(VARCHAR, GETDATE(), @DateFormat)
48 | END
49 |
50 | --we need to strip out certain characters from the file name that tend to occur in dates6
51 | SET @Suffix = REPLACE(@Suffix, ':', '')
52 | SET @Suffix = REPLACE(@Suffix, '\', '')
53 | SET @Suffix = REPLACE(@Suffix, '/', '')
54 |
55 | --select the database list into a temp table so that we can work with it
56 | INSERT INTO #DatabaseList
57 | SELECT value
58 | FROM STRING_SPLIT(@DatabaseList, ',')
59 |
60 | --get list of databases, including those covered by any wildcards
61 | SELECT QUOTENAME(name) AS name
62 | INTO #DatabasesFinal
63 | FROM sys.databases databases
64 | WHERE EXISTS (
65 | SELECT name
66 | FROM #DatabaseList
67 | WHERE databases.name LIKE #DatabaseList.name
68 | )
69 |
70 | IF @ListOnly = 1 --if @listonly set then only print the affected databases
71 | SELECT name
72 | FROM #DatabasesFinal
73 | ELSE
74 | BEGIN
75 | DECLARE @Databases VARCHAR(128)
76 |
77 | ------------------------------------------------------------------------------------------------------
78 | --Loop through each database creating snapshots
79 | DECLARE databases_curr CURSOR
80 | FOR
81 | SELECT name
82 | FROM #DatabasesFinal
83 |
84 | OPEN databases_curr
85 |
86 | FETCH NEXT
87 | FROM databases_curr
88 | INTO @Databases
89 |
90 | WHILE @@FETCH_STATUS = 0
91 | BEGIN
92 | --create snapshots
93 | DECLARE @SQL VARCHAR(MAX)
94 |
95 | SET @SQL = 'USE ' + @Databases + 'DECLARE @DatabaseName VARCHAR(128)
96 | DECLARE @SnapshotName VARCHAR(128)
97 | SET @DatabaseName = DB_NAME()
98 | SET @SnapshotName = DB_NAME() + ''_' + @Suffix +
99 | '''
100 |
101 | --table variable to hold file list
102 | DECLARE @DatabaseFiles TABLE (id INT identity(1,1),name VARCHAR(128), physical_name VARCHAR(400), ss_file_name VARCHAR(4000))
103 |
104 | --populate table variable with file information
105 | INSERT INTO @DatabaseFiles (name, physical_name, ss_file_name)
106 | SELECT name, physical_name, REVERSE(SUBSTRING(REVERSE(Physical_name),CHARINDEX(''\'', REVERSE(physical_name),0),LEN(physical_name)))
107 | FROM sys.master_files
108 | WHERE type != 1 AND database_id = DB_ID()
109 |
110 | --begin building snapshot script
111 | DECLARE @SnapshotScript VARCHAR(1000)
112 | SET @SnapshotScript = ''CREATE DATABASE '' + QUOTENAME(@SnapshotName) + '' ON ''
113 |
114 | --loop through datafile table variable
115 | DECLARE @LoopCounter INT = 0
116 |
117 | DECLARE @FileCount INT
118 | SELECT @FileCount = COUNT(*)
119 | FROM @DatabaseFiles
120 |
121 | WHILE @LoopCounter < @FileCount
122 | BEGIN
123 | SET @LoopCounter = @LoopCounter + 1
124 |
125 | IF ''' + @FilePath +
126 | ''' = ''''
127 | BEGIN
128 | SELECT @SnapshotScript = @SnapshotScript + ''(NAME = '' + QUOTENAME(name) + '', FILENAME = '''''' + ss_file_name + @SnapshotName + ''.ss''''),''
129 | FROM @DatabaseFiles
130 | WHERE id = @LoopCounter
131 | END
132 | ELSE
133 | BEGIN
134 | SELECT @SnapshotScript = @SnapshotScript + ''(NAME = '' + QUOTENAME(name) + '', FILENAME = ''''' + @FilePath + ''' + @SnapshotName + ''.ss''''),''
135 | FROM @DatabaseFiles
136 | WHERE id = @LoopCounter
137 | END
138 | END
139 |
140 | --loop will have added an unwanted comma at the end of the script, delete this comma
141 | SET @SnapshotScript = LEFT(@snapshotscript, LEN(@snapshotscript) -1)
142 |
143 | --add AS SNAPSHOT to script
144 | SET @SnapshotScript = @SnapshotScript + '' AS SNAPSHOT OF ['' + @DatabaseName + '']''
145 |
146 | --Generate the snapshot
147 | PRINT ''Creating Snapshot for ' + @Databases + '''
148 | --PRINT @SnapshotScript
149 | EXEC (@SnapshotScript)'
150 |
151 | EXEC (@SQL)
152 |
153 | FETCH NEXT
154 | FROM databases_curr
155 | INTO @Databases
156 | END
157 |
158 | CLOSE databases_curr
159 |
160 | DEALLOCATE databases_curr
161 | END
162 | END
--------------------------------------------------------------------------------
/sp_Tablecount.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/sp_Tablecount.sql
--------------------------------------------------------------------------------
/sp_WhatsmyAG.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/sp_WhatsmyAG.sql
--------------------------------------------------------------------------------
/sp_drivespace.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/SQLUndercover/UndercoverToolbox/8205b16cadec71a4cd52ab4f8481eae5b9a67083/sp_drivespace.sql
--------------------------------------------------------------------------------