'
40 | return
41 | end
42 | else
43 | begin
44 | insert into #spids
45 | select spid, last_batch, loginame
46 | from master.dbo.sysprocesses
47 | where dbid = (select dbid from master.dbo.sysdatabases
48 | where name = @DbName)
49 | and last_batch < @activedate
50 | and sid not in (select sid from master.dbo.syslogins where name in ('sa','tvguide\mssqlexec'))
51 |
52 | select @spid = min(spid) from #spids
53 | while @spid is not null
54 | begin
55 | if @spid <> @@spid
56 | begin
57 | select @loginame = loginame from #spids where spid = @spid
58 | select @cmd = 'use master; kill ' + ltrim(rtrim(str(@spid)))
59 | print 'Killing spid ' + ltrim(rtrim(str(@spid))) + ' - ' + @loginame
60 | begin try
61 | execute (@cmd)
62 | end try
63 | begin catch
64 | SELECT @_errorMSG = ERROR_MESSAGE(), @_errorNumber = ERROR_NUMBER();
65 |
66 | IF @_errorNumber = 6106
67 | PRINT @_errorMSG;
68 | ELSE
69 | BEGIN
70 | IF (select CAST(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS VARCHAR(50)),charindex('.',CAST(SERVERPROPERTY('ProductVersion') AS VARCHAR(50)))-1) AS INT)) >= 12
71 | EXECUTE sp_executesql N'THROW 50000,@_errorMSG,1',N'@_errorMSG VARCHAR(200)', @_errorMSG;
72 | ELSE
73 | EXECUTE sp_executesql N'RAISERROR (@_errorMSG, 16, 1)', N'@_errorMSG VARCHAR(200)', @_errorMSG;
74 | END
75 | end catch
76 | end
77 | select @spid = min(spid) from #spids where spid > @spid
78 | waitfor delay '00:00:02'
79 | end
80 | end
81 | end
82 |
83 |
84 | GO
85 |
86 |
87 |
--------------------------------------------------------------------------------
/SQLQueries/LogWalk_usp_Get_LogShip_Database_Restore_Status.sql:
--------------------------------------------------------------------------------
1 | USE DBA
2 | GO
3 |
4 | IF OBJECT_ID('dbo.usp_Get_LogShip_Database_Restore_Status') IS NULL
5 | EXEC ('CREATE PROCEDURE dbo.usp_Get_LogShip_Database_Restore_Status AS SELECT 1 as Dummy;')
6 | GO
7 |
8 | ALTER PROCEDURE dbo.usp_Get_LogShip_Database_Restore_Status @recipients VARCHAR(2000) = 'ajay.dwivedi@YourOrg.com; renuka.chopra@YourOrg.com', @threshold_hours int = 24
9 | AS
10 | BEGIN
11 | SET NOCOUNT ON;
12 |
13 | DECLARE @tableHTML NVARCHAR(MAX) ;
14 | DECLARE @mailSubject VARCHAR(500);
15 |
16 | if OBJECT_ID('tempdb..#log_shipping_status') is not null
17 | drop table #log_shipping_status;
18 | ;with t_log_ship_dbs as
19 | (
20 | select d.name as database_name from sys.databases as d where d.is_in_standby = 1 or d.is_read_only = 1
21 | )
22 | ,t_restore_history as
23 | (
24 | SELECT rs.[destination_database_name]
25 | ,bs.database_name as source_database_name
26 | ,bs.server_name as source_server_name
27 | ,bs.recovery_model
28 | ,rs.[restore_date]
29 | ,bs.backup_start_date
30 | ,bmf.physical_device_name
31 | ,rs.[user_name]
32 | ,rs.[backup_set_id]
33 | ,CASE rs.[restore_type]
34 | WHEN 'D' THEN 'Database'
35 | WHEN 'I' THEN 'Differential'
36 | WHEN 'L' THEN 'Log'
37 | WHEN 'F' THEN 'File'
38 | WHEN 'G' THEN 'Filegroup'
39 | WHEN 'V' THEN 'Verifyonlyl'
40 | END AS RestoreType
41 | ,rs.[replace]
42 | ,rs.[recovery]
43 | ,ROW_NUMBER()over(partition by rs.[destination_database_name] order by rs.[restore_date] desc) as RowID
44 | FROM [msdb].[dbo].[restorehistory] rs
45 | inner join [msdb].[dbo].[backupset] bs
46 | on rs.backup_set_id = bs.backup_set_id
47 | INNER JOIN msdb.dbo.backupmediafamily bmf
48 | ON bs.media_set_id = bmf.media_set_id
49 | where rs.restore_date >= DATEADD(DAY,-7,getdate())
50 | )
51 | select @@serverName as srvName, d.database_name as [destination_database_name] , case when datediff(hour,[restore_date],getdate()) > @threshold_hours then 'YES' else 'no' end as [Need_Attention], [source_database_name] ,[recovery_model] ,[restore_date] ,DATEDIFF(HOUR,[restore_date],GETDATE()) as [Last_Restore_Hours] , [RestoreType]
52 | into #log_shipping_status
53 | from t_log_ship_dbs as d
54 | left join t_restore_history as h
55 | on h.destination_database_name = d.database_name
56 | where h.RowID = 1
57 | and h.restore_date <= DATEADD(hour,-@threshold_hours,getdate())
58 |
59 | if OBJECT_ID('tempdb..#log_shipping_status') is not null and exists (select * from #log_shipping_status where recovery_model <> 'SIMPLE')
60 | begin
61 | SET @mailSubject = 'Restore History Report - '+@@SERVERNAME+' - '+CAST(GETDATE() AS VARCHAR(30));
62 | SET @tableHTML =
63 | N''+
72 | N'Restore History Report
' +
73 | N'' +
74 | N'srvName | destination_database_name | Need_Attention | source_database_name | recovery_model | restore_date | Last_Restore_Hours | RestoreType |
' +
75 | CAST ( ( SELECT td = srvName, '',
76 | td = destination_database_name, '',
77 | --td = (case when Need_Attention = 'YES' then ''+Need_Attention+'' else ''+Need_Attention+'' end), '',
78 | td = Need_Attention, '',
79 | td = source_database_name, '',
80 | td = recovery_model, '',
81 | td = restore_date, '',
82 | td = cast(Last_Restore_Hours as varchar(20)), '',
83 | td = RestoreType
84 | FROM #log_shipping_status as l
85 | WHERE recovery_model <> 'SIMPLE'
86 | ORDER BY restore_date ASC
87 | FOR XML PATH('tr'), TYPE
88 | ) AS NVARCHAR(MAX) ) +
89 | N'
' ;
90 |
91 | SET @tableHTML = @tableHTML + '
92 |
93 | Thanks & Regards,
94 | SQL Alerts
95 | dba-group@YourOrg.com
96 | -- Alert Coming from SQL Agent Job [DBA Log Walk Alerts]
97 |
98 | '
99 |
100 | EXEC msdb.dbo.sp_send_dbmail @recipients=@recipients,
101 | @subject = @mailSubject,
102 | @body = @tableHTML,
103 | @body_format = 'HTML' ;
104 | end
105 | END
106 | GO
107 |
108 |
109 |
--------------------------------------------------------------------------------
/SQLQueries/Operator.DBAGroup.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS(SELECT * FROM msdb..sysoperators o where o.name = 'DBAGroup')
2 | BEGIN
3 | EXEC msdb.dbo.sp_add_operator @name=N'DBAGroup',
4 | @enabled=1,
5 | @weekday_pager_start_time=90000,
6 | @weekday_pager_end_time=180000,
7 | @saturday_pager_start_time=90000,
8 | @saturday_pager_end_time=180000,
9 | @sunday_pager_start_time=90000,
10 | @sunday_pager_end_time=180000,
11 | @pager_days=0,
12 | @email_address=N'dba-group@YourCompany.com',
13 | @category_name=N'[Uncategorized]'
14 | END
15 |
16 |
--------------------------------------------------------------------------------
/SQLQueries/SelfServiceModules-Certificate Cleanup-DBA.sql:
--------------------------------------------------------------------------------
1 | USE DBA;
2 | GO
3 |
4 | IF OBJECT_ID('dbo.usp_WhoIsActive_Blocking') IS NOT NULL
5 | DROP PROCEDURE dbo.usp_WhoIsActive_Blocking
6 | GO
7 |
8 | IF EXISTS(select * from sys.database_principals as p where p.name = 'CodeSigningLogin')
9 | DROP USER [CodeSigningLogin];
10 | GO
11 |
12 | IF EXISTS (select * from sys.certificates as c where c.name = 'CodeSigningCertificate')
13 | DROP CERTIFICATE [CodeSigningCertificate];
14 | GO
15 |
16 |
17 |
--------------------------------------------------------------------------------
/SQLQueries/SelfServiceModules-Certificate Cleanup.sql:
--------------------------------------------------------------------------------
1 | USE master
2 | go
3 |
4 | IF OBJECT_ID('dbo.sp_WhoIsActive') IS NOT NULL
5 | DROP PROCEDURE [sp_WhoIsActive];
6 | GO
7 | IF OBJECT_ID('dbo.sp_kill') IS NOT NULL
8 | DROP PROCEDURE [sp_kill]
9 | GO
10 | IF OBJECT_ID('dbo.sp_HealthCheck') IS NOT NULL
11 | DROP PROCEDURE [sp_HealthCheck]
12 | GO
13 | IF EXISTS(select * from sys.database_principals as p where p.name = 'CodeSigningLogin')
14 | DROP USER [CodeSigningLogin];
15 | GO
16 | IF EXISTS(select * from sys.server_principals as p where p.name = 'CodeSigningLogin')
17 | DROP LOGIN [CodeSigningLogin];
18 | GO
19 | IF EXISTS (select * from sys.certificates as c where c.name = 'CodeSigningCertificate')
20 | DROP CERTIFICATE [CodeSigningCertificate];
21 | GO
22 |
23 |
24 | USE master
25 | GO
26 |
27 | IF EXISTS (select * from sys.configurations as c where c.name = 'xp_cmdshell' and c.value_in_use = 0)
28 | BEGIN
29 | -- To allow advanced options to be changed.
30 | EXEC sp_configure 'show advanced options', 1;
31 | -- To update the currently configured value for advanced options.
32 | RECONFIGURE;
33 | -- To enable the feature.
34 | EXEC sp_configure 'xp_cmdshell', 1;
35 | -- To update the currently configured value for this feature.
36 | RECONFIGURE;
37 | END
38 | GO
39 |
40 | USE master
41 | GO
42 | DECLARE @cmd NVARCHAR(MAX) = 'xp_cmdshell ''del "C:\temp\CodeSigningCertificate.cer"'', no_output'; EXEC (@cmd);
43 | SET @cmd = 'xp_cmdshell ''del "C:\temp\CodeSigningCertificate_WithKey.pvk"'', no_output'; EXEC (@cmd);
44 | GO
45 |
46 | USE DBA;
47 | GO
48 |
49 | IF OBJECT_ID('dbo.usp_WhoIsActive_Blocking') IS NOT NULL
50 | DROP PROCEDURE dbo.usp_WhoIsActive_Blocking
51 | GO
52 |
53 | IF EXISTS(select * from sys.database_principals as p where p.name = 'CodeSigningLogin')
54 | DROP USER [CodeSigningLogin];
55 | GO
56 |
57 | IF EXISTS (select * from sys.certificates as c where c.name = 'CodeSigningCertificate')
58 | DROP CERTIFICATE [CodeSigningCertificate];
59 | GO
60 |
61 |
62 |
--------------------------------------------------------------------------------
/SQLQueries/SelfServiceModules-Sign-Procedures.sql:
--------------------------------------------------------------------------------
1 | -- Minimum permissions required to run sp_Blitz
2 | -- https://dba.stackexchange.com/a/188193/98923
3 | -- Certificate Signing Stored Procedures in Multiple Databases
4 | -- https://www.sqlskills.com/blogs/jonathan/certificate-signing-stored-procedures-in-multiple-databases/
5 |
6 | USE master
7 | GO
8 |
9 | CREATE CERTIFICATE [CodeSigningCertificate] ENCRYPTION BY PASSWORD = 'Work@Y0urBest' WITH EXPIRY_DATE = '2099-01-01' ,SUBJECT = 'DBA Code Signing Cert'
10 | GO
11 |
12 | BACKUP CERTIFICATE [CodeSigningCertificate] TO FILE = 'C:\temp\CodeSigningCertificate.cer'
13 | WITH PRIVATE KEY (FILE = 'C:\temp\CodeSigningCertificate_WithKey.pvk', ENCRYPTION BY PASSWORD = 'Work@Y0urBest', DECRYPTION BY PASSWORD = 'Work@Y0urBest' );
14 | GO
15 |
16 | CREATE LOGIN [CodeSigningLogin] FROM CERTIFICATE [CodeSigningCertificate];
17 | GO
18 |
19 | GRANT AUTHENTICATE SERVER TO [CodeSigningLogin]
20 | GO
21 |
22 | EXEC master..sp_addsrvrolemember @loginame = N'CodeSigningLogin', @rolename = N'sysadmin'
23 | GO
24 |
25 | USE DBA
26 | GO
27 |
28 | CREATE CERTIFICATE [CodeSigningCertificate] FROM FILE = 'C:\temp\CodeSigningCertificate.cer'
29 | WITH PRIVATE KEY (FILE = 'C:\temp\CodeSigningCertificate_WithKey.pvk',
30 | ENCRYPTION BY PASSWORD = 'Work@Y0urBest',
31 | DECRYPTION BY PASSWORD = 'Work@Y0urBest'
32 | );
33 | GO
34 |
35 | CREATE USER [CodeSigningLogin] FROM CERTIFICATE [CodeSigningCertificate];
36 | GO
37 |
38 | EXEC sp_addrolemember N'db_owner', N'CodeSigningLogin'
39 | GO
40 |
41 | USE master
42 | go
43 |
44 | ADD SIGNATURE TO [dbo].[sp_Kill] BY CERTIFICATE [CodeSigningCertificate] WITH PASSWORD = 'Work@Y0urBest' -- 'Work@Y0urBest'
45 | GO
46 |
47 | GRANT EXECUTE ON OBJECT::[dbo].[sp_Kill] TO [public]
48 | GO
49 |
50 | ADD SIGNATURE TO [dbo].[sp_WhoIsActive] BY CERTIFICATE [CodeSigningCertificate] WITH PASSWORD = 'Work@Y0urBest' -- 'Work@Y0urBest'
51 | GO
52 |
53 | GRANT EXECUTE ON OBJECT::[dbo].[sp_WhoIsActive] TO [public]
54 | GO
55 |
56 | ADD SIGNATURE TO [dbo].[sp_HealthCheck] BY CERTIFICATE [CodeSigningCertificate] WITH PASSWORD = 'Work@Y0urBest' -- 'Work@Y0urBest'
57 | GO
58 |
59 | GRANT EXECUTE ON OBJECT::[dbo].[sp_HealthCheck] TO [public]
60 | GO
61 |
62 | USE DBA
63 | GO
64 |
65 | GRANT CONNECT TO [guest]
66 | GO
67 |
68 | ADD SIGNATURE TO [dbo].[usp_WhoIsActive_Blocking] BY CERTIFICATE [CodeSigningCertificate] WITH PASSWORD = 'Work@Y0urBest' -- 'Work@Y0urBest'
69 | GO
70 |
71 | GRANT EXECUTE ON OBJECT::[dbo].[usp_WhoIsActive_Blocking] TO [public]
72 | GO
--------------------------------------------------------------------------------
/SQLQueries/WhatIsRunning.sql:
--------------------------------------------------------------------------------
1 | SELECT s.session_id
2 | ,DB_NAME(r.database_id) as DBName
3 | ,r.STATUS
4 | ,r.percent_complete
5 | ,CAST(((DATEDIFF(s,start_time,GetDate()))/3600) as varchar) + ' hour(s), '
6 | + CAST((DATEDIFF(s,start_time,GetDate())%3600)/60 as varchar) + 'min, '
7 | + CAST((DATEDIFF(s,start_time,GetDate())%60) as varchar) + ' sec' as running_time
8 | ,CAST((estimated_completion_time/3600000) as varchar) + ' hour(s), '
9 | + CAST((estimated_completion_time %3600000)/60000 as varchar) + 'min, '
10 | + CAST((estimated_completion_time %60000)/1000 as varchar) + ' sec' as est_time_to_go
11 | ,dateadd(second,estimated_completion_time/1000, getdate()) as est_completion_time
12 | ,r.blocking_session_id 'blocked by'
13 | ,r.wait_type
14 | ,wait_resource
15 | ,r.wait_time / (1000.0) 'Wait Time (in Sec)'
16 | ,r.cpu_time
17 | ,r.logical_reads
18 | ,r.reads
19 | ,r.writes
20 | ,r.total_elapsed_time / (1000.0) 'Elapsed Time (in Sec)'
21 | ,Substring(st.TEXT, (r.statement_start_offset / 2) + 1, (
22 | (
23 | CASE r.statement_end_offset
24 | WHEN - 1
25 | THEN Datalength(st.TEXT)
26 | ELSE r.statement_end_offset
27 | END - r.statement_start_offset
28 | ) / 2
29 | ) + 1) AS statement_text
30 | ,st.text as Batch_Text
31 | ,r.sql_handle
32 | ,r.plan_handle
33 | ,r.query_hash
34 | ,r.query_plan_hash
35 | ,s.login_name
36 | ,s.host_name
37 | ,s.program_name
38 | ,r.open_transaction_count
39 | ,qp.query_plan
40 | FROM sys.dm_exec_sessions AS s
41 | INNER JOIN sys.dm_exec_requests AS r ON r.session_id = s.session_id
42 | CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) AS st
43 | OUTER APPLY sys.dm_exec_query_plan(r.plan_handle) AS qp
44 | WHERE r.session_id != @@SPID
45 | ORDER BY DBName, r.cpu_time DESC
46 | ,r.STATUS
47 | ,r.blocking_session_id
48 | ,s.session_id;
--------------------------------------------------------------------------------
/SQLQueries/migration.scriptout.database.permissions.sql:
--------------------------------------------------------------------------------
1 | DECLARE @_specificLoginName VARCHAR(250);
2 | SET @_specificLoginName = '';
3 |
4 | DECLARE
5 | @sql VARCHAR(2048)
6 | ,@sort INT
7 |
8 | DECLARE tmp CURSOR FOR
9 |
10 |
11 |
12 | -- DB CONTEXT STATEMENT
13 | SELECT '-- [-- DB CONTEXT --] --' AS [-- SQL STATEMENTS --],
14 | 1 AS [-- RESULT ORDER HOLDER --]
15 | UNION
16 | SELECT 'USE' + SPACE(1) + QUOTENAME(DB_NAME()) AS [-- SQL STATEMENTS --],
17 | 1 AS [-- RESULT ORDER HOLDER --]
18 |
19 | UNION
20 |
21 | SELECT '' AS [-- SQL STATEMENTS --],
22 | 2 AS [-- RESULT ORDER HOLDER --]
23 |
24 | UNION
25 |
26 | -- DB USER CREATION
27 |
28 | SELECT '-- [-- DB USERS --] --' AS [-- SQL STATEMENTS --],
29 | 3 AS [-- RESULT ORDER HOLDER --]
30 | UNION
31 | SELECT 'IF NOT EXISTS (SELECT [name] FROM sys.database_principals WHERE [name] = ' + SPACE(1) + '''' + [name] + '''' + ') BEGIN CREATE USER ' + SPACE(1) + QUOTENAME([name]) + ' FOR LOGIN ' + QUOTENAME([name]) + ' WITH DEFAULT_SCHEMA = ' + QUOTENAME([default_schema_name]) + SPACE(1) + 'END; ' AS [-- SQL STATEMENTS --],
32 | 4 AS [-- RESULT ORDER HOLDER --]
33 | FROM sys.database_principals AS rm
34 | WHERE [type] IN ('U', 'S', 'G') -- windows users, sql users, windows groups
35 |
36 | UNION
37 |
38 | -- DB ROLE PERMISSIONS
39 | SELECT '-- [-- DB ROLES --] --' AS [-- SQL STATEMENTS --],
40 | 5 AS [-- RESULT ORDER HOLDER --]
41 | UNION
42 | SELECT 'EXEC sp_addrolemember @rolename ='
43 | + SPACE(1) + QUOTENAME(USER_NAME(rm.role_principal_id), '''') + ', @membername =' + SPACE(1) + QUOTENAME(USER_NAME(rm.member_principal_id), '''') AS [-- SQL STATEMENTS --],
44 | 6 AS [-- RESULT ORDER HOLDER --]
45 | FROM sys.database_role_members AS rm
46 | WHERE USER_NAME(rm.member_principal_id) IN (
47 | --get user names on the database
48 | SELECT [name]
49 | FROM sys.database_principals
50 | WHERE [principal_id] > 4 -- 0 to 4 are system users/schemas
51 | and [type] IN ('G', 'S', 'U') -- S = SQL user, U = Windows user, G = Windows group
52 | )
53 | --ORDER BY rm.role_principal_id ASC
54 |
55 |
56 | UNION
57 |
58 | SELECT '' AS [-- SQL STATEMENTS --],
59 | 7 AS [-- RESULT ORDER HOLDER --]
60 |
61 | UNION
62 |
63 | -- OBJECT LEVEL PERMISSIONS
64 | SELECT '-- [-- OBJECT LEVEL PERMISSIONS --] --' AS [-- SQL STATEMENTS --],
65 | 8 AS [-- RESULT ORDER HOLDER --]
66 | UNION
67 | SELECT CASE
68 | WHEN perm.state <> 'W' THEN perm.state_desc
69 | ELSE 'GRANT'
70 | END
71 | + SPACE(1) + perm.permission_name + SPACE(1) + 'ON ' + QUOTENAME(SCHEMA_NAME(obj.schema_id)) + '.' + QUOTENAME(obj.name) --select, execute, etc on specific objects
72 | + CASE
73 | WHEN cl.column_id IS NULL THEN SPACE(0)
74 | ELSE '(' + QUOTENAME(cl.name) + ')'
75 | END
76 | + SPACE(1) + 'TO' + SPACE(1) + QUOTENAME(USER_NAME(usr.principal_id)) COLLATE database_default
77 | + CASE
78 | WHEN perm.state <> 'W' THEN SPACE(0)
79 | ELSE SPACE(1) + 'WITH GRANT OPTION'
80 | END
81 | AS [-- SQL STATEMENTS --],
82 | 9 AS [-- RESULT ORDER HOLDER --]
83 | FROM
84 | sys.database_permissions AS perm
85 | INNER JOIN
86 | sys.objects AS obj
87 | ON perm.major_id = obj.[object_id]
88 | INNER JOIN
89 | sys.database_principals AS usr
90 | ON perm.grantee_principal_id = usr.principal_id
91 | LEFT JOIN
92 | sys.columns AS cl
93 | ON cl.column_id = perm.minor_id AND cl.[object_id] = perm.major_id
94 | --WHERE usr.name = @OldUser
95 | --ORDER BY perm.permission_name ASC, perm.state_desc ASC
96 |
97 |
98 |
99 | UNION
100 |
101 | SELECT '' AS [-- SQL STATEMENTS --],
102 | 10 AS [-- RESULT ORDER HOLDER --]
103 |
104 | UNION
105 |
106 | -- DB LEVEL PERMISSIONS
107 | SELECT '-- [--DB LEVEL PERMISSIONS --] --' AS [-- SQL STATEMENTS --],
108 | 11 AS [-- RESULT ORDER HOLDER --]
109 | UNION
110 | SELECT CASE
111 | WHEN perm.state <> 'W' THEN perm.state_desc --W=Grant With Grant Option
112 | ELSE 'GRANT'
113 | END
114 | + SPACE(1) + perm.permission_name --CONNECT, etc
115 | + SPACE(1) + 'TO' + SPACE(1) + '[' + USER_NAME(usr.principal_id) + ']' COLLATE database_default --TO
116 | + CASE
117 | WHEN perm.state <> 'W' THEN SPACE(0)
118 | ELSE SPACE(1) + 'WITH GRANT OPTION'
119 | END
120 | AS [-- SQL STATEMENTS --],
121 | 12 AS [-- RESULT ORDER HOLDER --]
122 | FROM sys.database_permissions AS perm
123 | INNER JOIN
124 | sys.database_principals AS usr
125 | ON perm.grantee_principal_id = usr.principal_id
126 | --WHERE usr.name = @OldUser
127 |
128 | WHERE [perm].[major_id] = 0
129 | AND [usr].[principal_id] > 4 -- 0 to 4 are system users/schemas
130 | AND [usr].[type] IN ('G', 'S', 'U') -- S = SQL user, U = Windows user, G = Windows group
131 |
132 | UNION
133 |
134 | SELECT '' AS [-- SQL STATEMENTS --],
135 | 13 AS [-- RESULT ORDER HOLDER --]
136 |
137 | UNION
138 |
139 | SELECT '-- [--DB LEVEL SCHEMA PERMISSIONS --] --' AS [-- SQL STATEMENTS --],
140 | 14 AS [-- RESULT ORDER HOLDER --]
141 | UNION
142 | SELECT CASE
143 | WHEN perm.state <> 'W' THEN perm.state_desc --W=Grant With Grant Option
144 | ELSE 'GRANT'
145 | END
146 | + SPACE(1) + perm.permission_name --CONNECT, etc
147 | + SPACE(1) + 'ON' + SPACE(1) + class_desc + '::' COLLATE database_default --TO
148 | + QUOTENAME(SCHEMA_NAME(major_id))
149 | + SPACE(1) + 'TO' + SPACE(1) + QUOTENAME(USER_NAME(grantee_principal_id)) COLLATE database_default
150 | + CASE
151 | WHEN perm.state <> 'W' THEN SPACE(0)
152 | ELSE SPACE(1) + 'WITH GRANT OPTION'
153 | END
154 | AS [-- SQL STATEMENTS --],
155 | 15 AS [-- RESULT ORDER HOLDER --]
156 | from sys.database_permissions AS perm
157 | inner join sys.schemas s
158 | on perm.major_id = s.schema_id
159 | inner join sys.database_principals dbprin
160 | on perm.grantee_principal_id = dbprin.principal_id
161 | WHERE class = 3 --class 3 = schema
162 |
163 |
164 | ORDER BY [-- RESULT ORDER HOLDER --]
165 |
166 |
167 | OPEN tmp
168 | FETCH NEXT FROM tmp INTO @sql, @sort
169 | WHILE @@FETCH_STATUS = 0
170 | BEGIN
171 | PRINT @sql
172 | FETCH NEXT FROM tmp INTO @sql, @sort
173 | END
174 |
175 | CLOSE tmp
176 | DEALLOCATE tmp
--------------------------------------------------------------------------------
/SQLQueries/ola.hallengren.Job.DatabaseBackup.FULL.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM msdb..sysjobs j where j.name = 'DBA DatabaseBackup - ALL_DATABASES - FULL')
2 | BEGIN
3 | BEGIN TRANSACTION
4 | DECLARE @ReturnCode INT
5 | SELECT @ReturnCode = 0
6 |
7 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
8 | BEGIN
9 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
10 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
11 |
12 | END
13 |
14 | DECLARE @jobId BINARY(16)
15 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'DBA DatabaseBackup - ALL_DATABASES - FULL',
16 | @enabled=1,
17 | @notify_level_eventlog=0,
18 | @notify_level_email=2,
19 | @notify_level_netsend=0,
20 | @notify_level_page=0,
21 | @delete_level=0,
22 | @description=N'Source: https://ola.hallengren.com',
23 | @category_name=N'Database Maintenance',
24 | @owner_login_name=N'sa',
25 | @notify_email_operator_name=N'DBAGroup', @job_id = @jobId OUTPUT
26 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
27 | /****** Object: Step [DatabaseBackup - ALLDATABASES - FULL] Script Date: 10/23/2019 4:21:25 AM ******/
28 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DatabaseBackup - ALLDATABASES - FULL',
29 | @step_id=1,
30 | @cmdexec_success_code=0,
31 | @on_success_action=1,
32 | @on_success_step_id=0,
33 | @on_fail_action=2,
34 | @on_fail_step_id=0,
35 | @retry_attempts=0,
36 | @retry_interval=0,
37 | @os_run_priority=0, @subsystem=N'TSQL',
38 | @command=N'DECLARE @_dbNames VARCHAR(MAX);
39 |
40 | /* Get Comma Separated List of Database Names which are not on APPSYNC*/
41 | select @_dbNames = COALESCE(@_dbNames+'',''+DB_NAME(mf.database_id),DB_NAME(mf.database_id))
42 | --,mf.physical_name
43 | from sys.master_files as mf
44 | where mf.file_id = 1
45 | AND DB_NAME(mf.database_id) NOT IN (''tempdb'') --(''master'',''tempdb'',''model'',''msdb'',''resourcedb'')
46 | AND mf.physical_name not like ''C:\AppSyncMounts\%''
47 | AND mf.database_id not in (select d.database_id from sys.databases as d where d.is_in_standby = 1 or d.source_database_id IS NOT NULL);
48 |
49 | --select @_dbNames;
50 |
51 | EXECUTE [DBA].[dbo].[DatabaseBackup]
52 | @Databases = @_dbNames
53 | ,@Directory = N''SqlInstanceDefaultBackupDirectory''
54 | ,@FileName = N''{DatabaseName}_{BackupType}_{Partial}_{CopyOnly}_{Year}{Month}{Day}.{FileExtension}''
55 | ,@BackupType = ''FULL'',@Verify = ''N'',@Compress = ''Y'',@DirectoryStructure = NULL,
56 | @CleanupTime = 5,@CheckSum = ''N'',@LogToTable = ''Y'',@cleanupmode = BEFORE_BACKUP',
57 | @database_name=N'DBA',
58 | @flags=0
59 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
60 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
61 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
62 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'RUN',
63 | @enabled=1,
64 | @freq_type=4,
65 | @freq_interval=1,
66 | @freq_subday_type=1,
67 | @freq_subday_interval=0,
68 | @freq_relative_interval=0,
69 | @freq_recurrence_factor=0,
70 | @active_start_date=20180830,
71 | @active_end_date=99991231,
72 | @active_start_time=222000,
73 | @active_end_time=235959,
74 | @schedule_uid=N'd77c274c-7e9b-41a6-8a05-71981a5899a9'
75 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
76 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
77 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
78 | COMMIT TRANSACTION
79 | GOTO EndSave
80 | QuitWithRollback:
81 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
82 | EndSave:
83 | END
84 |
85 |
86 |
--------------------------------------------------------------------------------
/SQLQueries/ola.hallengren.Job.DatabaseBackup.LOG.sql:
--------------------------------------------------------------------------------
1 | IF NOT EXISTS (SELECT * FROM msdb..sysjobs j where j.name = 'DBA DatabaseBackup - USER_DATABASES - LOG')
2 | BEGIN
3 | BEGIN TRANSACTION
4 | DECLARE @ReturnCode INT
5 | SELECT @ReturnCode = 0
6 |
7 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
8 | BEGIN
9 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
10 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
11 |
12 | END
13 |
14 | DECLARE @jobId BINARY(16)
15 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'DBA DatabaseBackup - USER_DATABASES - LOG',
16 | @enabled=1,
17 | @notify_level_eventlog=0,
18 | @notify_level_email=2,
19 | @notify_level_netsend=0,
20 | @notify_level_page=0,
21 | @delete_level=0,
22 | @description=N'Source: https://ola.hallengren.com',
23 | @category_name=N'Database Maintenance',
24 | @owner_login_name=N'sa',
25 | @notify_email_operator_name=N'DBAGroup', @job_id = @jobId OUTPUT
26 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
27 | /****** Object: Step [DatabaseBackup - USER_DATABASES - LOG] Script Date: 10/23/2019 4:22:32 AM ******/
28 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DatabaseBackup - USER_DATABASES - LOG',
29 | @step_id=1,
30 | @cmdexec_success_code=0,
31 | @on_success_action=1,
32 | @on_success_step_id=0,
33 | @on_fail_action=2,
34 | @on_fail_step_id=0,
35 | @retry_attempts=0,
36 | @retry_interval=0,
37 | @os_run_priority=0, @subsystem=N'TSQL',
38 | @command=N'DECLARE @_dbNames VARCHAR(MAX);
39 |
40 | /* Get Comma Separated List of Database Names which are not on APPSYNC*/
41 | select @_dbNames = COALESCE(@_dbNames+'',''+DB_NAME(mf.database_id),DB_NAME(mf.database_id))
42 | --,mf.physical_name
43 | from sys.master_files as mf
44 | where mf.file_id = 1
45 | AND mf.database_id <> DB_ID(''tempdb'')
46 | AND mf.physical_name not like ''C:\AppSyncMounts\%''
47 | AND mf.database_id not in (select d.database_id from sys.databases as d where d.is_in_standby = 1 or d.source_database_id IS NOT NULL);
48 |
49 | --select @_dbNames;
50 |
51 | EXECUTE [DBA].[dbo].[DatabaseBackup]
52 | @Databases = @_dbNames
53 | ,@Directory = N''SqlInstanceDefaultBackupDirectory''
54 | ,@FileName = N''{DatabaseName}_{BackupType}_{Partial}_{CopyOnly}_{Year}{Month}{Day}_{Hour}{Minute}{Second}_{FileNumber}.{FileExtension}''
55 | ,@BackupType = ''LOG'',@Verify = ''N'',@Compress = ''Y'',@DirectoryStructure = NULL,
56 | @CleanupTime = 24,@CheckSum = ''N'',@LogToTable = ''Y''
57 | --,@Execute = ''N''
58 |
59 | ',
60 | @database_name=N'DBA',
61 | @flags=0
62 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
63 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
64 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
65 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'RUN',
66 | @enabled=1,
67 | @freq_type=4,
68 | @freq_interval=1,
69 | @freq_subday_type=4,
70 | @freq_subday_interval=30,
71 | @freq_relative_interval=0,
72 | @freq_recurrence_factor=0,
73 | @active_start_date=20180830,
74 | @active_end_date=99991231,
75 | @active_start_time=0,
76 | @active_end_time=235959,
77 | @schedule_uid=N'29d98d80-2d50-4917-b6e2-c9e1cc5c44c5'
78 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
79 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
80 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
81 | COMMIT TRANSACTION
82 | GOTO EndSave
83 | QuitWithRollback:
84 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
85 | EndSave:
86 | END
--------------------------------------------------------------------------------
/SQLQueries/ola.hallengren.Job.IndexOptimize_Modified.sql:
--------------------------------------------------------------------------------
1 | USE msdb
2 | GO
3 |
4 | /****** Object: Job [DBA - IndexOptimize_Modified - Staging/IDS] Script Date: 10/18/2019 3:50:14 AM ******/
5 | BEGIN TRANSACTION
6 | DECLARE @ReturnCode INT
7 | SELECT @ReturnCode = 0
8 | /****** Object: JobCategory [Database Maintenance] Script Date: 10/18/2019 3:50:14 AM ******/
9 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
10 | BEGIN
11 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
12 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
13 |
14 | END
15 |
16 | DECLARE @jobId BINARY(16)
17 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'DBA - IndexOptimize_Modified - Staging/IDS',
18 | @enabled=1,
19 | @notify_level_eventlog=0,
20 | @notify_level_email=2,
21 | @notify_level_netsend=0,
22 | @notify_level_page=0,
23 | @delete_level=0,
24 | @description=N'IndexOptimize for Staging & IDS using IndexOptimize_Modified procedure. Job is configured to run for 3 hours only. Will process indexes for all databases in Rotational Manner.
25 |
26 | select * from DBA.dbo.CommandLog as l
27 | where l.CommandType in (''UPDATE_STATISTICS'',''ALTER_INDEX'');
28 |
29 | SELECT * FROM DBA.dbo.IndexProcessing_IndexOptimize;',
30 | @category_name=N'Database Maintenance',
31 | @owner_login_name=N'sa',
32 | @notify_email_operator_name=N'DBAGroup', @job_id = @jobId OUTPUT
33 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
34 | /****** Object: Step [IndexOptimize_Modified] Script Date: 10/18/2019 3:50:14 AM ******/
35 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'IndexOptimize_Modified',
36 | @step_id=1,
37 | @cmdexec_success_code=0,
38 | @on_success_action=1,
39 | @on_success_step_id=0,
40 | @on_fail_action=2,
41 | @on_fail_step_id=0,
42 | @retry_attempts=0,
43 | @retry_interval=0,
44 | @os_run_priority=0, @subsystem=N'TSQL',
45 | @command=N'/* IndexOptimize ''Staging'',''IDS'' database for 3 hours */
46 | SET NOCOUNT ON;
47 |
48 | DECLARE @_dbNames VARCHAR(MAX);
49 |
50 | /* Get Comma Separated List of Database Names which are not on APPSYNC*/
51 | select @_dbNames = COALESCE(@_dbNames+'',''+DB_NAME(mf.database_id),DB_NAME(mf.database_id))
52 | --,mf.physical_name
53 | from sys.master_files as mf
54 | where mf.file_id = 1
55 | AND DB_NAME(mf.database_id) NOT IN (''tempdb'',''ArchiveDB'')
56 | AND mf.physical_name not like ''C:\AppSyncMounts\%''
57 | AND mf.database_id not in (select d.database_id from sys.databases as d where d.is_in_standby = 1 or d.source_database_id IS NOT NULL)
58 | AND DB_NAME(mf.database_id) in (''Staging'',''IDS'')
59 | ORDER BY name;
60 |
61 |
62 | EXECUTE DBA.dbo.IndexOptimize_Modified
63 | @Databases = @_dbNames,
64 | @TimeLimit = 3600, -- 1 hours
65 | @FragmentationLow = NULL,
66 | @FragmentationMedium = ''INDEX_REBUILD_ONLINE,INDEX_REORGANIZE,INDEX_REBUILD_OFFLINE'',
67 | @FragmentationHigh = ''INDEX_REBUILD_ONLINE,INDEX_REBUILD_OFFLINE'',
68 | @FragmentationLevel1 = 30,
69 | @FragmentationLevel2 = 50,
70 | @MinNumberOfPages = 1000,
71 | @SortInTempdb = ''Y'', /* Enable it when [Cosmo] production Server since [tempdb] & [Cosmo] database are on separate disks */
72 | @MaxDOP = 1, /* Default = 3 on Cosmo server */
73 | @FillFactor = 100, /* Recommendations says to start with 100, and keep decreasing based on Page Splits/Sec value of server. On Cosmo server, Page Splits/sec are very high. Avg 171 page splits/sec for Avg 354 Batch Requests/sec */
74 | @LOBCompaction = ''Y'',
75 | @UpdateStatistics = ''ALL'',
76 | @OnlyModifiedStatistics = ''Y'',
77 | @Indexes = ''ALL_INDEXES'', /* Default is not specified. Db1.Schema1.Tbl1.Idx1, Db2.Schema2.Tbl2.Idx2 */
78 | --@Delay = 120, /* Introduce 300 seconds of Delay b/w Indexes of Replicated Databases */
79 | @LogToTable = ''Y''
80 | --,@Execute = ''N''
81 | ,@forceReInitiate = 0',
82 | @database_name=N'DBA',
83 | @flags=0
84 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
85 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
86 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
87 | EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Daily-Once',
88 | @enabled=1,
89 | @freq_type=4,
90 | @freq_interval=1,
91 | @freq_subday_type=1,
92 | @freq_subday_interval=0,
93 | @freq_relative_interval=0,
94 | @freq_recurrence_factor=0,
95 | @active_start_date=20191018,
96 | @active_end_date=99991231,
97 | @active_start_time=163000,
98 | @active_end_time=235959,
99 | @schedule_uid=N'534dbb15-218e-42ed-b2f9-1e1ca7472715'
100 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
101 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
102 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
103 | COMMIT TRANSACTION
104 | GOTO EndSave
105 | QuitWithRollback:
106 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
107 | EndSave:
108 | GO
109 |
110 |
111 |
--------------------------------------------------------------------------------
/Sql-Installations/2014/AutoBuild.ps1:
--------------------------------------------------------------------------------
1 | [CmdletBinding()]
2 | param(
3 | [Parameter(Mandatory=$false)]
4 | [ValidateSet("Corporate\DevSQL", "Corporate\ProdSQL", "Corporate\QASQL")]
5 | [string] $SQLServiceAccount = 'Corporate\DevSQL',
6 |
7 | [Parameter(Mandatory=$false)]
8 | [string] $InstanceName = 'MSSQLSERVER',
9 |
10 | [Parameter(Mandatory=$false)]
11 | [string] $SQLServiceAccountPassword,
12 |
13 | [Parameter(Mandatory=$false)]
14 | [string] $SAPassword,
15 |
16 | [Parameter(Mandatory=$false)]
17 | [string] $Administrators = 'Corporate\SQL Admins'
18 | )
19 |
20 | #$PSScriptRoot = "C:\Users\adwivedi\Documents\WindowsPowerShell\Modules\SQLDBATools\Sql-Installations\2014";
21 | $ConfigFile = "$PSScriptRoot\ConfigurationFile.ini";
22 |
23 | if(Get-Content $ConfigFile | Where-Object {$_ -match "INSTALLSQLDATADIR=`"(?'INSTALLSQLDATADIR'.+)`""}) {
24 | $INSTALLSQLDATADIR = (($Matches['INSTALLSQLDATADIR']).split('\')[0])+'\';
25 | }
26 | if(Get-Content $ConfigFile | Where-Object {$_ -match "SQLBACKUPDIR=`"(?'SQLBACKUPDIR'.+)`""}) {
27 | $SQLBACKUPDIR = (($Matches['SQLBACKUPDIR']).split('\')[0])+'\';
28 | }
29 | if(Get-Content $ConfigFile | Where-Object {$_ -match "SQLUSERDBDIR=`"(?'SQLUSERDBDIR'.+)`""}) {
30 | $SQLUSERDBDIR = (($Matches['SQLUSERDBDIR']).split('\')[0])+'\';
31 | }
32 | if(Get-Content $ConfigFile | Where-Object {$_ -match "SQLUSERDBLOGDIR=`"(?'SQLUSERDBLOGDIR'.+)`""}) {
33 | $SQLUSERDBLOGDIR = (($Matches['SQLUSERDBLOGDIR']).split('\')[0])+'\';
34 | }
35 | if(Get-Content $ConfigFile | Where-Object {$_ -match "SQLTEMPDBDIR=`"(?'SQLTEMPDBDIR'.+)`""}) {
36 | $SQLTEMPDBDIR = (($Matches['SQLTEMPDBDIR']).split('\')[0])+'\';
37 | }
38 |
39 | if( -not ( (Test-Path $INSTALLSQLDATADIR) -and (Test-Path $SQLBACKUPDIR) -and (Test-Path $SQLUSERDBDIR) -and (Test-Path $SQLUSERDBLOGDIR) -and (Test-Path $SQLTEMPDBDIR) ) ) {
40 | Write-Host "Kindly make sure all reqired disk drives are present.`n$INSTALLSQLDATADIR, $SQLUSERDBDIR, $SQLUSERDBLOGDIR, $SQLBACKUPDIR & $SQLTEMPDBDIR" -ForegroundColor Red;
41 | if((Get-PSCallStack).Count -gt 1) {
42 | exit;
43 | }
44 | }
45 |
46 |
47 | # If SQLServiceAccountPassword or SAPassword is not provided in parameter
48 | if([string]::IsNullOrEmpty($SQLServiceAccountPassword) -or [string]::IsNullOrEmpty($SAPassword)) {
49 | $InventoryServer = $SdtInventoryInstance;
50 | $ssn = New-PSSession -ComputerName $InventoryServer -Name $InventoryServer;
51 |
52 | if([string]::IsNullOrEmpty($SQLServiceAccountPassword)) {
53 | # Get Password for SQLServiceAccount
54 | $ScriptBlock = { Import-Module SQLDBATools; Get-Password4Account -UserName $Using:SQLServiceAccount; }
55 | $SQLServiceAccountPassword = Invoke-Command -Session $ssn -ScriptBlock $ScriptBlock;
56 | }
57 |
58 | if([string]::IsNullOrEmpty($SAPassword)) {
59 | # Get Password for SA
60 | $ScriptBlock = { Import-Module SQLDBATools; Get-Password4Account -UserName "SA"; }
61 | $SAPassword = Invoke-Command -Session $ssn -ScriptBlock $ScriptBlock;
62 | }
63 | }
64 |
65 | Write-Host "Starting installation of SQL Server setup.." -ForegroundColor Yellow;
66 |
67 | if($InstanceName -ne 'MSSQLSERVER') {
68 | $configFileContent = Get-Content 'ConfigurationFile.ini';
69 | $configFileContent.Replace("MSSQLSERVER",$InstanceName) | Set-Content 'ConfigurationFile.ini';
70 | }
71 |
72 | .\SETUP.EXE /INSTANCENAME=$InstanceName /SQLSYSADMINACCOUNTS=$Administrators `
73 | /SQLSVCACCOUNT=$SQLServiceAccount /SQLSVCPASSWORD=$SQLServiceAccountPassword `
74 | /AGTSVCACCOUNT=$SQLServiceAccount /AGTSVCPASSWORD=$SQLServiceAccountPassword `
75 | /SAPWD=$SAPassword /CONFIGURATIONFILE="./ConfigurationFile.ini"
76 |
77 |
78 | $logFolder = 'C:\Program Files\Microsoft SQL Server\120\Setup Bootstrap\Log'
79 | <#
80 | 1) Open Summary.txt
81 | 2) Open folder with most recent Modified Date. Folder name would be like '20191016_135940'
82 | 3) If step 01 file not present, open file like 'Summary_TESTVM_20191016_135940' in step 02 folder
83 | #>
84 |
85 | $Summary = Get-Content "$logFolder\Summary.txt" | Select-Object -First 6;
86 | $Summary | Where-Object {$_ -match "Exit code \(Decimal\):\s*(?'ExitCode'\d+)"} | Out-Null
87 | $ExitCode = $Matches['ExitCode'];
88 | if($ExitCode -eq 0) {
89 | Write-Host "Installation completed Successfully" -ForegroundColor Green;
90 | Write-Host $Summary;
91 | }
92 | elseif($ExitCode -eq 3010) {
93 | Write-Host "Installation completed but REBOOT is required" -ForegroundColor Green;
94 | Write-Host $Summary;
95 | }
96 | else {
97 | Write-Host "Some Issue occurred. Kindly check summary page." -ForegroundColor Red;
98 | explorer $logFolder;
99 | notepad "$logFolder\Summary.txt";
100 | }
101 |
102 |
--------------------------------------------------------------------------------
/Sql-Installations/2014/AutoUninstall.ps1:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2014/AutoUninstall.ps1
--------------------------------------------------------------------------------
/Sql-Installations/2014/ConfigurationFile.ini:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2014/ConfigurationFile.ini
--------------------------------------------------------------------------------
/Sql-Installations/2014/ConfigurationFile_2014.ini:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2014/ConfigurationFile_2014.ini
--------------------------------------------------------------------------------
/Sql-Installations/2014/Developer/ConfigurationFile.ini:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2014/Developer/ConfigurationFile.ini
--------------------------------------------------------------------------------
/Sql-Installations/2014/Standard/ConfigurationFile.ini:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2014/Standard/ConfigurationFile.ini
--------------------------------------------------------------------------------
/Sql-Installations/2016/Developer/ConfigurationFile.ini:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2016/Developer/ConfigurationFile.ini
--------------------------------------------------------------------------------
/Sql-Installations/2016/Standard/ConfigurationFile.ini:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Sql-Installations/2016/Standard/ConfigurationFile.ini
--------------------------------------------------------------------------------
/Sql-Installations/Configuration/GrantSqlAccountRequiredPrivileges.ps1:
--------------------------------------------------------------------------------
1 | [CmdletBinding()]
2 | Param(
3 | [Parameter(Mandatory=$true)]
4 | [ValidateSet("Corporate\DevSQL", "Corporate\ProdSQL", "Corporate\QASQL")]
5 | [string] $SQLServiceAccount = 'Corporate\DevSQL',
6 |
7 | [Parameter(Mandatory=$false)]
8 | [string] $InstanceName = 'MSSQLSERVER'
9 | )
10 |
11 | # Find temp File path
12 | $tmp = [System.IO.Path]::GetTempFileName()
13 |
14 | Write-Verbose "Export current Local Security Policy";
15 | secedit.exe /export /cfg "$($tmp)"
16 |
17 | $c = Get-Content -Path $tmp;
18 |
19 | $SqlServicePriviledges = @();
20 | $ArrySqlPriviledges = @('SeInteractiveLogonRight','SeServiceLogonRight','SeAssignPrimaryTokenPrivilege','SeChangeNotifyPrivilege','SeIncreaseQuotaPrivilege','SeManageVolumePrivilege');
21 |
22 | <#
23 | Log on as a service (SeServiceLogonRight)
24 | Replace a process-level token (SeAssignPrimaryTokenPrivilege)
25 | Bypass traverse checking (SeChangeNotifyPrivilege)
26 | Adjust memory quotas for a process (SeIncreaseQuotaPrivilege)
27 | Perform Volume Maintainence Tasks (SeManageVolumePrivilege)
28 | #>
29 | foreach($s in $c)
30 | {
31 | foreach($p in $ArrySqlPriviledges)
32 | {
33 | $currentSetting = "";
34 | $actionNeeded = $true;
35 | if( $s -like "$p*")
36 | {
37 | $x = $s.split("=",[System.StringSplitOptions]::RemoveEmptyEntries)
38 | $currentSetting = $x[1].Trim();
39 |
40 | if( [string]::IsNullOrEmpty($currentSetting) ) {
41 | $currentSetting = "*$($sidstr)";
42 | } elseif ($currentSetting -notlike "*$($sidstr)*") {
43 | $currentSetting = "*$($sidstr),$($currentSetting)";
44 | } else {
45 | Write-Verbose "No action needed for Log on Locally";
46 | $actionNeeded = $false;
47 | }
48 |
49 | if ($actionNeeded)
50 | {
51 | $priviledge = [Ordered]@{
52 | 'PolicyName' = $x[0];
53 | 'PolicyMembers' = $currentSetting;
54 | }
55 | $priviledgeObj = New-Object -TypeName PSObject -Property $priviledge;
56 | $SqlServicePriviledges += $priviledgeObj;
57 | }
58 | }
59 |
60 | }
61 | }
62 |
63 | if( $SqlServicePriviledges.Count -gt 0)
64 | {
65 | $SqlServicePriviledges;
66 | $outfile = '';
67 | foreach($item in $SqlServicePriviledges)
68 | {
69 | $outfile += @"
70 | [Unicode]
71 | Unicode=yes
72 | [Version]
73 | signature="`$CHICAGO`$"
74 | Revision=1
75 | [Privilege Rights]
76 | $($item.PolicyName) = $($item.PolicyMembers)
77 | "@
78 | }
79 |
80 | $tmp2 = [System.IO.Path]::GetTempFileName()
81 |
82 |
83 | Write-Verbose "Import new settings to Local Security Policy" -ForegroundColor DarkCyan
84 | $outfile | Set-Content -Path $tmp2 -Encoding Unicode -Force
85 |
86 | #notepad.exe $tmp2
87 | Push-Location (Split-Path $tmp2)
88 |
89 | try {
90 | secedit.exe /configure /db "secedit.sdb" /cfg "$($tmp2)" /areas USER_RIGHTS
91 | #write-host "secedit.exe /configure /db ""secedit.sdb"" /cfg ""$($tmp2)"" /areas USER_RIGHTS "
92 | } finally {
93 | Pop-Location
94 | }
95 | }
96 | else {
97 | Write-Verbose "NO ACTIONS REQUIRED regarding SQL Service Account Priviledges!"
98 | }
99 |
100 | Write-Host "SQL Service Account Priviledges! Finished!"
101 |
--------------------------------------------------------------------------------
/Test/Get-OutlookInBox.ps1:
--------------------------------------------------------------------------------
1 | Function Get-OutlookInBox
2 | {
3 | <#
4 | .Synopsis
5 | This function returns InBox items from default Outlook profile
6 | .Description
7 | This function returns InBox items from default Outlook profile. It
8 | uses the Outlook interop assembly to use the olFolderInBox enumeration.
9 | It creates a custom object consisting of Subject, ReceivedTime, Importance,
10 | SenderName for each InBox item.
11 | *** Important *** depending on the size of your InBox items this function
12 | may take several minutes to gather your InBox items. If you anticipate
13 | doing multiple analysis of the data, you should consider storing the
14 | results into a variable, and using that.
15 | .Example
16 | Get-OutlookInbox |
17 | where { $_.ReceivedTime -gt [datetime]"5/5/11" -AND $_.ReceivedTime -lt `
18 | [datetime]"5/10/11" } | sort importance
19 | Displays Subject, ReceivedTime, Importance, SenderName for all InBox items that
20 | are in InBox between 5/5/11 and 5/10/11 and sorts by importance of the email.
21 | .Example
22 | Get-OutlookInbox | Group-Object -Property SenderName | sort-Object Count
23 | Displays Count, SenderName and grouping information for all InBox items. The most
24 | frequently used contacts appear at bottom of list.
25 | .Example
26 | $InBox = Get-OutlookInbox
27 | Stores Outlook InBox items into the $InBox variable for further
28 | "offline" processing.
29 | .Example
30 | ($InBox | Measure-Object).count
31 | Displays the number of messages in InBox Items
32 | .Example
33 | $InBox | where { $_.subject -match '2011 Scripting Games' } |
34 | sort ReceivedTime -Descending | select subject, ReceivedTime -last 5
35 | Uses $InBox variable (previously created) and searches subject field
36 | for the string '2011 Scripting Games' it then sorts by the date InBox.
37 | This sort is descending which puts the oldest messages at bottom of list.
38 | The Select-Object cmdlet is then used to choose only the subject and ReceivedTime
39 | properties and then only the last five messages are displayed. These last
40 | five messages are the five oldest messages that meet the string.
41 | .Notes
42 | NAME: Get-OutlookInbox
43 | AUTHOR: ed wilson, msft
44 | LASTEDIT: 05/13/2011 08:36:42
45 | KEYWORDS: Microsoft Outlook, Office
46 | HSG: HSG-05-26-2011
47 | .Link
48 | Http://www.ScriptingGuys.com/blog
49 | #Requires -Version 2.0
50 | #>
51 | Add-type -assembly "Microsoft.Office.Interop.Outlook" | out-null
52 | $olFolders = "Microsoft.Office.Interop.Outlook.olDefaultFolders" -as [type]
53 | $outlook = new-object -comobject outlook.application
54 | $namespace = $outlook.GetNameSpace("MAPI")
55 | $folder = $namespace.getDefaultFolder($olFolders::olFolderInBox)
56 | $folder.items |
57 | Select-Object -Property Subject, ReceivedTime, Importance, SenderName
58 | } #end function Get-OutlookInbox
59 |
60 |
61 |
62 | Get-OutlookInBox | Export-Csv -Path c:\temp\myOutlook.csv -Encoding ascii -NoTypeInformation
63 |
--------------------------------------------------------------------------------
/Test/Get-OutlookMail.ps1:
--------------------------------------------------------------------------------
1 | # Written by Ben Penney https://sysadminben.wordpress.com
2 |
3 | $mail="ajay.dwivedi@gmail.com"
4 |
5 | $password = Read-Host -assecurestring "Please enter your password"
6 | $password = [System.Runtime.InteropServices.Marshal]::PtrToStringAuto([System.Runtime.InteropServices.Marshal]::SecureStringToBSTR($password))
7 |
8 | # Set the path to your copy of EWS Managed API
9 | $dllpath = "C:\Program Files\Microsoft\Exchange\Web Services\2.2\Microsoft.Exchange.WebServices.dll"
10 | # Load the Assemply
11 | [void][Reflection.Assembly]::LoadFile($dllpath)
12 |
13 | # Create a new Exchange service object
14 | $service = new-object Microsoft.Exchange.WebServices.Data.ExchangeService
15 |
16 | #These are your O365 credentials
17 | $Service.Credentials = New-Object Microsoft.Exchange.WebServices.Data.WebCredentials($mail,$password)
18 |
19 | # this TestUrlCallback is purely a security check
20 | $TestUrlCallback = {
21 | param ([string] $url)
22 | if ($url -eq "https://autodiscover-s.outlook.com/autodiscover/autodiscover.xml") {$true} else {$false}
23 | }
24 | # Autodiscover using the mail address set above
25 | $service.AutodiscoverUrl($mail,$TestUrlCallback)
26 |
27 | # create Property Set to include body and header of email
28 | $PropertySet = New-Object Microsoft.Exchange.WebServices.Data.PropertySet([Microsoft.Exchange.WebServices.Data.BasePropertySet]::FirstClassProperties)
29 |
30 | # set email body to text
31 | $PropertySet.RequestedBodyType = [Microsoft.Exchange.WebServices.Data.BodyType]::Text;
32 |
33 | # Set how many emails we want to read at a time
34 | $numOfEmailsToRead = 100
35 |
36 | # Index to keep track of where we are up to. Set to 0 initially.
37 | $index = 0
38 |
39 | # Do/while loop for paging through the folder
40 | do
41 | {
42 | # Set what we want to retrieve from the folder. This will grab the first $pagesize emails
43 | $view = New-Object Microsoft.Exchange.WebServices.Data.ItemView($numOfEmailsToRead,$index)
44 | # Retrieve the data from the folder
45 | $findResults = $service.FindItems([Microsoft.Exchange.WebServices.Data.WellKnownFolderName]::Inbox,$view)
46 | foreach ($item in $findResults.Items)
47 | {
48 | # load the additional properties for the item
49 | $item.Load($propertySet)
50 |
51 | # Output the results
52 | "From: $($item.From.Name)"
53 | "Subject: $($item.Subject)"
54 | "Body: $($Item.Body.Text)"
55 | "References: $($item.References)"
56 | "InternetMessageID: $($item.InternetMessageID)"
57 | "InternetMessageHeaders:"
58 | # Display the headers - using a little foreach loop
59 | $item.InternetMessageHeaders|foreach{"$($_.Name): $($_.Value)"}
60 | ""
61 | }
62 | # Increment $index to next block of emails
63 | $index += $numOfEmailsToRead
64 | } while ($findResults.MoreAvailable) # Do/While there are more emails to retrieve
65 |
66 |
--------------------------------------------------------------------------------
/Test/Get-SdtLinkedServer _old.ps1:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Test/Get-SdtLinkedServer _old.ps1
--------------------------------------------------------------------------------
/Test/Get-SdtMSSQLLinkPasswords _old.ps1:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/Test/Get-SdtMSSQLLinkPasswords _old.ps1
--------------------------------------------------------------------------------
/Test/Test-Get-VolumeSpaceConsumers.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Remove-Module SQLDBATools -ErrorAction SilentlyContinue;
3 | Import-Module SQLDBATools -DisableNameChecking;
4 | #>
5 |
6 | #Get-VolumeSpaceConsumers -ComputerName $env:computerName -pathOrFolder 'D:\' | Out-GridView;
7 | Get-VolumeSpaceConsumers -ComputerName $env:COMPUTERNAME -pathOrFolder e:\ -Verbose | Out-GridView
--------------------------------------------------------------------------------
/Test/Test-Script-SQLDatabaseRestore.ps1:
--------------------------------------------------------------------------------
1 | Clear-Host;
2 |
3 | Script-SQLDatabaseRestore -RestoreCategory LatestAvailable `
4 | -Source_SQLInstance SqlProd1 `
5 | -SourceDatabase Cosmo `
6 | -Destination_SQLInstance SqlProd1 `
7 | -DestinationPath_Data "F:\mssqldata\Data" `
8 | -DestinationPath_Log "E:\Mssqldata\Log" `
9 | -Verbose;
10 |
11 | <#
12 | Script-SQLDatabaseRestore -BackupPath '\\SqlProd3\g$\Backup' `
13 | -RestoreCategory LatestAvailable `
14 | -Destination_SQLInstance SqlProd1 `
15 | -DestinationPath_Data "F:\mssqldata\Data" `
16 | -DestinationPath_Log "E:\Mssqldata\Log" `
17 | -Verbose
18 | #>
19 |
--------------------------------------------------------------------------------
/WIP/Add-SecurityCheckInfo.ps1:
--------------------------------------------------------------------------------
1 | Function Add-SecurityCheckInfo
2 | {
3 | [CmdletBinding()]
4 | Param (
5 | [Parameter(ValueFromPipeline=$true,
6 | ValueFromPipelineByPropertyName=$true)]
7 | [Alias('ServerName','SQLInstance')]
8 | [String]$ServerInstance
9 | )
10 | $Result = $null;
11 | $Result = Get-SecurityCheckInfo -ServerInstance $ServerInstance;
12 |
13 | Write-Host "Result for [$ServerInstance]:-" -ForegroundColor Green;
14 | $Result | ft -AutoSize;
15 |
16 | if([String]::IsNullOrEmpty($Result))
17 | {
18 | Add-CollectionError -ComputerName $ServerInstance `
19 | -Cmdlet 'Collect-SecurityCheckInfo' `
20 | -CommandText "Get-SecurityCheckInfo -ServerInstance $ServerInstance" `
21 | -ErrorText "Get-SecurityCheckInfo did not return output for server" `
22 | -Remark $null;
23 | if($PSCmdlet.MyInvocation.BoundParameters["Verbose"].IsPresent) {
24 | Write-Host "Error ($ServerInstance) => Error occurred. Kindly check [DBA].[Staging].[CollectionErrors] table " -ForegroundColor Red;
25 | }
26 |
27 | return;
28 | }
29 |
30 | $dtable = $Result | Out-DataTable;
31 |
32 | $cn = new-object System.Data.SqlClient.SqlConnection("Data Source=$sdtInventoryInstance;Integrated Security=SSPI;Initial Catalog=$sdtInventoryDatabase");
33 | $cn.Open();
34 |
35 | $bc = new-object ("System.Data.SqlClient.SqlBulkCopy") $cn;
36 | $bc.DestinationTableName = "Staging.SecurityCheckInfo";
37 | $bc.WriteToServer($dtable);
38 | $cn.Close();
39 | }
--------------------------------------------------------------------------------
/WIP/Copy-SQLObject.ps1:
--------------------------------------------------------------------------------
1 | #Function Copy-SQLObject
2 | #{
3 | [CmdletBinding()]
4 | Param(
5 | [Parameter(ValueFromPipeline=$true,
6 | ValueFromPipelineByPropertyName=$true)]
7 | [Alias('ServerName','MachineName')]
8 | $ComputerName = $env:COMPUTERNAME,
9 |
10 | [String[]]$DatabaseName
11 | )
12 | $InstanceName = 'DEFAULT';
13 |
14 | Import-Module SQLPS -DisableNameChecking;
15 |
16 | $dbs = Get-ChildItem "SQLServer:\SQL\$ComputerName\$InstanceName\Databases";
17 |
18 | foreach($dbObject in $dbs)
19 | {
20 | $tables = $dbObject.Tables
21 | }
22 | $tables;
23 |
24 |
25 | #}
--------------------------------------------------------------------------------
/WIP/Dummy-Code.ps1:
--------------------------------------------------------------------------------
1 | Import-Module SQLPS -DisableNameChecking;
2 |
3 | Set-Location SQLSERVER:\;
4 | Get-ChildItem
5 |
6 | Set-Location SQLSERVER:\SQL;
7 | Get-ChildItem
8 |
9 | # Set variable with Current Machine Name
10 | $ServerName = $env:COMPUTERNAME;
11 | $InstanceName = "SQLSERVER:\SQL\$ServerName\DEFAULT";
12 |
13 | # Get databases for instance
14 | Set-Location $InstanceName\Databases;
15 | Get-ChildItem
16 |
17 | Set-Location $InstanceName\Databases\AdventureWorks2014\Tables;
18 | Get-ChildItem
19 |
20 | <# Get the SQL Server Instance for each machine we pass #>
21 |
22 | # Load an array of instances object
23 | $ServerName = $env:COMPUTERNAME;
24 | $instances = Get-ChildItem "SQLSERVER:\SQL\$ServerName";
25 | Write-Output $instances
26 |
27 | # Load Instances as an Array of Strings
28 | $instances = @();
29 | Get-ChildItem "SQLSERVER:\SQL\$ServerName" |
30 | foreach {$instances += $_.PSChildName};
31 |
32 | Write-Output $instances;
33 |
34 | <# ----------------------------------------------------------------------
35 | Code to Get Backup History
36 | #>
37 | # Pretend like this is an array of Server Names
38 | $machines = $env:COMPUTERNAME;
39 | #$machines = @();
40 | #$machines = Invoke-Sqlcmd -ServerInstance $env:COMPUTERNAME -Database 'DBServers_master' -Query 'select [Server/Instance Name] from [dbo].[Production]' |
41 | #Select-Object -ExpandProperty 'Server/Instance Name';
42 |
43 | Push-Location;
44 | $machineInstances = @();
45 | foreach ($machine in $machines) {
46 | if ($machine -ne "") {
47 | Get-ChildItem "SQLSERVER:\SQL\$ServerName" |
48 | foreach {$machineInstances += "$machine\$($_.PSChildName)"};
49 | }
50 | }
51 |
52 | foreach ($instance in $machineInstances){
53 | Get-ChildItem -Force SQLSERVER:\SQL\$instance\Databases | where-object {$_.Name -ne 'tempdb'; $_.Refresh()} |
54 | Format-Table @{Label="ServerName"; Expression={ $_.Parent -replace '[[\]]',''}},
55 | @{l='DatabaseName';e={$_.Name}},
56 | @{l='DatabaseCreationDate';e={IF ($_.CreateDate -eq "01/01/0001 00:00:00") {$null} else {($_.CreateDate).ToString("yyyy-MM-dd HH:mm:ss")}}},
57 | RecoveryModel,
58 | @{l='LastFullBackupDate';e={IF ($_.LastBackupDate -eq "01/01/0001 00:00:00") {$null} else {($_.LastBackupDate).ToString("yyyy-MM-dd HH:mm:ss")}}},
59 | @{l='LastDifferentialBackupDate';e={IF ($_.LastDifferentialBackupDate -eq "01/01/0001 00:00:00") {$null} else {($_.LastDifferentialBackupDate).ToString("yyyy-MM-dd HH:mm:ss")}}},
60 | @{l='LastLogBackupDate';e={IF ($_.LastLogBackupDate -eq "01/01/0001 00:00:00") {$null} else {($_.LastLogBackupDate).ToString("yyyy-MM-dd HH:mm:ss")}}} `
61 | -AutoSize
62 |
63 | #Select *
64 | }
65 | Pop-Location;
66 |
67 | #Write-Output $machineInstances;
68 | <# ----------------------------------------------------------------------
69 | #>
70 |
71 | <# Create Database #>
72 | $srv = New-Object Microsoft.SqlServer.Management.Smo.Server($machineInstances[0]);
73 | $db = New-Object Microsoft.SqlServer.Management.Smo.Database($srv, "Test_SMO_Database")
74 | $db.Create()
75 | Write-Host $db.CreateDate
76 | $db.Drop()
77 |
78 |
--------------------------------------------------------------------------------
/WIP/Enable-WinRMService.ps1:
--------------------------------------------------------------------------------
1 | Import-Module SqlServer;
2 | Import-Module dbatools;
3 | Import-Module SQLDBATools -DisableNameChecking;
4 |
5 | $tsqlInventoryServers = @"
6 | select ServerName from [SQLDBATools].[Staging].[CollectionErrors] as e with(nolock) where e.Command like '%Invoke-Command%'
7 | "@;
8 |
9 | $Servers = Invoke-DbaQuery -SqlInstance $sdtInventoryInstance -Query $tsqlInventoryServers;
10 |
11 | $CommandText = @();
12 | foreach($Server in $Servers)
13 | {
14 | $cmd = @"
15 |
16 | psexec.exe \\$($Server.ServerName) -s powershell Enable-PSRemoting -Force
17 | "@;
18 | $CommandText += $cmd;
19 | }
20 |
21 | $CommandText | ogv
--------------------------------------------------------------------------------
/WIP/Functions_ADOQuery.ps1:
--------------------------------------------------------------------------------
1 |
2 | Function ExecuteAdoNonQuery {
3 | Param( [Parameter(Mandatory=$true,ValueFromPipeline=$true)]
4 | [String]$connectionString,
5 | [Parameter(Mandatory=$true,ValueFromPipeline=$true)]
6 | [String] $SQLStatement )
7 | $sqlCmd = new-object System.Data.Sqlclient.SqlCommand;
8 | $sqlCmd.CommandTimeout = 0;
9 | $sqlCmd.Connection = $connectionString;
10 | $sqlCmd.CommandText = $SQLStatement;
11 | $sqlCmd.Connection.Open();
12 | $sqlCmd.executeNonQuery();
13 | $sqlCmd.Connection.Close();
14 | }
15 |
16 | Function ExecuteAdoScalar {
17 | Param( [Parameter(Mandatory=$true,ValueFromPipeline=$true)]
18 | [String]$connectionString,
19 | [Parameter(Mandatory=$true,ValueFromPipeline=$true)]
20 | [String]$SQLStatement )
21 | $sqlCmd = new-object System.Data.Sqlclient.SqlCommand;
22 | $sqlCmd.CommandTimeout = 0;
23 | $sqlCmd.Connection = $connectionString;
24 | $sqlCmd.CommandText = $SQLStatement;
25 | $sqlCmd.Connection.Open();
26 | [string]$value = $sqlCmd.ExecuteScalar();
27 | $sqlCmd.Connection.Close();
28 | return, $value
29 | }
30 |
31 | Function ExecuteAdoScalarWithMessage {
32 | Param( [Parameter(Mandatory=$true,ValueFromPipeline=$true)]
33 | [String]$connectionString,
34 | [Parameter(Mandatory=$true,ValueFromPipeline=$true)]
35 | [String]$SQLStatement ,
36 | [String]$logfile,
37 | $timeout = 0)
38 | $conn = New-Object System.Data.SqlClient.SqlConnection "$connectionString";
39 | ## Attach the InfoMessage Event Handler to the connection to write out the messages
40 | $handler = [System.Data.SqlClient.SqlInfoMessageEventHandler] {param($sender, $event) Write-Log $event.Message $logfile -nohost; $global:sqlerror = $event.Message;};
41 | $conn.add_InfoMessage($handler);
42 | $conn.FireInfoMessageEventOnUserErrors = $true;
43 | $cmd = $conn.CreateCommand();
44 | $cmd.CommandTimeout = $timeout;
45 | $cmd.CommandText = $SQLStatement;
46 | $conn.Open();
47 | [string]$returncode = $cmd.ExecuteScalar()
48 | $conn.Close();
49 | return, $returncode
50 | }
--------------------------------------------------------------------------------
/WIP/Get-OlderFilesOnDisk.ps1:
--------------------------------------------------------------------------------
1 | function Get-OlderFilesOnDisk {
2 | <#
3 | .SYNOPSIS
4 | Get files from disk older than threshold hours
5 | .DESCRIPTION
6 | .PARAMETER
7 | .EXAMPLE
8 | .LINK
9 | https://github.com/imajaydwivedi/SQLDBATools
10 | #>
11 | [CmdletBinding()]
12 | Param (
13 | [Parameter(Mandatory=$true)]
14 | [Alias('ServerName')]
15 | [string]$ComputerName,
16 |
17 | [Parameter(Mandatory=$true)]
18 | [Alias('Path')]
19 | [string]$Directory,
20 |
21 | [Parameter(Mandatory=$false)]
22 | [Alias('ThresholdTime_Hours')]
23 | [int]$Hours = 120
24 | )
25 | Write-Verbose "Validating variables..";
26 |
27 | Write-Verbose "Executing remote script to find files older than $Hours hours";
28 | $scriptBlock = {
29 | $files_all = Get-ChildItem -Path $Using:Directory -Recurse | Where-Object {-not $_.PSIsContainer};
30 | [System.Collections.ArrayList]$files_old = @();
31 |
32 | if($files_all.Count -gt 0) {
33 | foreach($file in $files_all) {
34 | $LastUsedTime = $null;
35 | if($file.LastAccessTime -ge $file.LastWriteTime -and $file.LastAccessTime -ge $file.CreationTime) {
36 | $LastUsedTime = $file.LastAccessTime;
37 | }elseif($file.LastWriteTime -ge $file.CreationTime) {
38 | $LastUsedTime = $file.LastWriteTime;
39 | }else {
40 | $LastUsedTime = $file.CreationTime;
41 | }
42 | $age = ((Get-Date) - $LastUsedTime); # LastAccessTime, LastWriteTime, CreationTime
43 | $age_Hours = ($age.Days * 24) + ($age.Hours);
44 |
45 | if($age_Hours -gt $Hours) {
46 | #$file | Add-Member -MemberType NoteProperty -Name LastUsed_Hours -Value $age_Hours;
47 | $files_old.Add($file) | Out-Null;
48 | } # take action on older files
49 | } # process each file
50 | } # process if files are found
51 | Write-Output $files_old;
52 | }
53 | $olderFiles = Invoke-Command -ComputerName $ComputerName -ScriptBlock $scriptBlock | Sort-Object -Property LastAccessTime, LastWriteTime, CreationTime;
54 | Write-Output $olderFiles
55 | }
56 |
57 | Get-OlderFilesOnDisk -ComputerName SqlProd15 -Directory 'F:\' -Hours 168 | ogv
--------------------------------------------------------------------------------
/WIP/Get-SQLServices_HashArray.ps1:
--------------------------------------------------------------------------------
1 | Function Get-SQLServices_HashArray
2 | {
3 | [CmdletBinding()]
4 | [Alias('Computers','Machines')]
5 | Param (
6 | [String[]]$Servers = $env:COMPUTERNAME
7 | )
8 |
9 | $ServiceStatus = @{}; #Initialize our Version Hash table
10 |
11 | foreach($computer in $Servers)
12 | {
13 | Get-Service -Name *SQL* -ComputerName $computer -ErrorAction SilentlyContinue |
14 | Sort-Object -Property DisplayName |
15 | foreach {
16 | $k = $computer + ' - ' + $_.DisplayName # Key
17 | $v = $_.Status # Value
18 | $ServiceStatus[$k] = $v;
19 |
20 | # Get Parent Service without which start is not possible #
21 | Get-Service $_.Name |
22 | Select-Object -ExpandProperty ServicesDependedOn |
23 | foreach {
24 | $kd = $k + " has dependency on " + $_.DisplayName;
25 | $s = $_.Status;
26 | $ServiceStatus[$kd] = $s;
27 | } # Inner Get-Services
28 | } # Outer Get-Service
29 | } # Loop for $Computers
30 |
31 | <# GetEnumerator method sends each entry in the hash table across the pipeline as a separate object #>
32 | $ServiceStatus.GetEnumerator() | Sort-Object Value;
33 | #$ServiceStatus.GetEnumerator() | Sort-Object Value | Format-Table -AutoSize;
34 | #$ServiceStatus.GetEnumerator() | Sort-Object Value | Where-Object {$_.Value -eq 'Stopped'};
35 | #$ServiceStatus.GetEnumerator() | Where-Object {$_.Value -eq 'Stopped' -and $_.Name -notlike "*SQL Server Agent*"} | ft -AutoSize
36 | <#
37 | $body = $ServiceStatus.GetEnumerator() | Where-Object {$_.Value -eq 'Stopped' -and $_.Name -notlike "*SQL Server Agent*"} | ft -AutoSize | Out-String;
38 | Send-SQLMail -Subject "Stopped Services" -Body $body;
39 | #>
40 | }
--------------------------------------------------------------------------------
/WIP/Get-UberBill_USA.ps1:
--------------------------------------------------------------------------------
1 | function Get-UberBill_USA {
2 | [CmdletBinding()]
3 | Param(
4 | [Parameter(Mandatory=$True, ValueFromPipelineByPropertyName=$true)]
5 | [Double]$Total_USD = (Read-Host "Enter Total Amount (Dollars): "),
6 |
7 | [Parameter(Mandatory=$True,ValueFromPipelineByPropertyName=$true)]
8 | [Double]$Extras_USD = (Read-Host "Enter amount for Tolls/Surcharge/Fees (USD): "),
9 |
10 | [Parameter(Mandatory=$True,ValueFromPipelineByPropertyName=$true)]
11 | [Double]$Total_INR = (Read-Host "Enter Total Amount (Rupees): "),
12 |
13 | [Parameter(Mandatory=$False,ValueFromPipelineByPropertyName=$true)]
14 | [Alias("Distance",'DistanceCovered')]
15 | [Double]$Miles, #= (Read-Host "Enter total Miles: "),
16 |
17 | [String]$Time_UberTravel, #Tue, Oct 01, 2019
18 | [String]$Time_GmailReceipt, #Tue, Oct 1, 2019 at 9:34 PM
19 |
20 | [Parameter(HelpMessage="Enter increment value in percentage (for 20%, provide 0.2).")]
21 | [Alias('Increment')]
22 | [Double]$PercentageIncrement = 0.2
23 | )
24 | #https://itknowledgeexchange.techtarget.com/powershell/powershell-f-string/#targetText=A%20PowerShell%20%E2%80%93f%20string%20is,to%20as%20the%20format%20operator.&targetText='A'%20is%20the%20first%20argument,%7B0%7D%20and%20so%20on.&targetText=index%20is%20the%20zero%20based,operator%20as%20you've%20seen.
25 |
26 | $ExchangeRate = $Total_INR / $Total_USD;
27 | Write-Host "$('{0,-35} = {1:F2}' -f 'ExchangeRate', $ExchangeRate)" -ForegroundColor Green;
28 |
29 | $TripFare_USD = $Total_USD - $Extras_USD;
30 | $TripFare_USD_New = [System.Math]::Round((1.0 + $PercentageIncrement) * $TripFare_USD,2);
31 | Write-Host "$('{0,-35} = {1:F2} => {2:F2}' -f 'Trip Fare', $TripFare_USD, $TripFare_USD_New)" -ForegroundColor Yellow;
32 |
33 | #$Extras_USD_New = [System.Math]::Round((1.0 + $PercentageIncrement) * $Extras_USD,2);
34 | #Write-Host "$('{0,-35} = {1:F2} => {2:F2}' -f 'Tolls, Surcharges, and Fees', $Extras_USD, $Extras_USD_New)" -ForegroundColor Cyan;
35 |
36 | $Total_USD_New = [System.Math]::Round($TripFare_USD_New + $Extras_USD,2);
37 | #Write-Host "Total = `$$Total_USD => `$$Total_USD_New" -ForegroundColor Yellow;
38 | Write-Host "$('{0,-35} = {1:F2} => {2:F2}' -f 'Total (USD)', $Total_USD, $Total_USD_New)" -ForegroundColor Yellow;
39 |
40 | $Total_INR_New = [System.Math]::Round($Total_USD_New * $ExchangeRate,2);
41 | #Write-Host "Total = `$$Total_INR => `$$Total_INR_New" -ForegroundColor Cyan;
42 | Write-Host "$('{0,-35} = {1:F2} => {2:F2}' -f 'Total (INR)', $Total_INR, $Total_INR_New)" -ForegroundColor Cyan;
43 |
44 | Write-Host "`n`n";
45 | $str_Total_USD = "document.body.innerHTML = document.body.innerHTML.replace($('/{0:F2}/g,' -f $Total_USD) '$('{0:F2}' -f $Total_USD_New)')";
46 | $str_TripFare_USD = "document.body.innerHTML = document.body.innerHTML.replace($('/{0:F2}/g,' -f $TripFare_USD) '$('{0:F2}' -f $TripFare_USD_New)')";
47 | #$str_Extras_USD = "document.body.innerHTML = document.body.innerHTML.replace($('/{0:F2}/g,' -f $Extras_USD) '$('{0:F2}' -f $Extras_USD_New)')";
48 |
49 | Write-Host "console.log(`"Update Total`");";
50 | Write-Host $str_Total_USD;
51 | Write-Host "console.log(`"Update Trip Fare`");";
52 | Write-Host $str_TripFare_USD;
53 | #Write-Host "console.log(`"Update Tolls, Surcharges, and Fees`");";
54 | #Write-Host $str_Extras_USD;
55 |
56 | <#
57 | if($Miles -eq 0.0) {
58 | $Miles_New = ($Miles * $PercentageIncrement) + $Miles;
59 | Write-Host "console.log(`"Update Miles`");";
60 | $str_Miles = "document.body.innerHTML = document.body.innerHTML.replace($('/{0:F2}/g,' -f $Miles) '$('{0:F2}' -f $Miles_New)')";
61 | Write-Host $str_Miles;
62 | }
63 | #>
64 |
65 | Write-Host "`n";
66 |
67 | if(-not ([string]::IsNullOrEmpty($Time_UberTravel))) {
68 | $str_Time_UberTravel = "document.body.innerHTML = document.body.innerHTML.replace($('/{0:F2}/g,' -f $Time_UberTravel) '$('{0:F2}' -f $Time_UberTravel)')";
69 | Write-Host "console.log(`"Update Day/Date for Uber Travel`");";
70 | Write-Host $str_Time_UberTravel;
71 | }
72 | if(-not ([string]::IsNullOrEmpty($Time_GmailReceipt))) {
73 | $str_Time_UberTravel = "document.body.innerHTML = document.body.innerHTML.replace($('/{0:F2}/g,' -f $Time_GmailReceipt) '$('{0:F2}' -f $Time_GmailReceipt)')";
74 | Write-Host "console.log(`"Update Day/Date/Time for Uber Travel Gmail Receipt`");";
75 | Write-Host $str_Time_UberTravel;
76 | }
77 |
78 | Write-Host "`n";
79 | }
80 |
81 | cls
82 | $Params = @{ Total_USD = 7.25
83 | Extras_USD = 2.65
84 | Total_INR = 537.32
85 | PercentageIncrement = 0.5
86 | }
87 |
88 | Get-UberBill_USA @Params
89 | #-Time_UberTravel 'Tue, Oct 01, 2019' -Time_GmailReceipt 'Tue, Oct 1, 2019 at 9:34 PM'
90 |
--------------------------------------------------------------------------------
/WIP/GetGroupTickets.ps1:
--------------------------------------------------------------------------------
1 | $timestamp = (get-date).ToString('yyMMMddhhmmss')
2 | $outputpath = 'E:\inetpub\wwwroot\InfrastructureInfo\sn\groups'
3 | $inputpath = 'E:\PSSCripts\SNOWScripts\groups.txt'
4 | $pwpath = 'E:\psscripts\snowscripts\cred\snowpw.txt'
5 | $date = (get-date).tostring('g')
6 | [string]$user = 'rharrington_ps'
7 | [string]$password = get-content $pwpath
8 |
9 | [string]$instance = 'YourOrg'
10 |
11 | #// Set Instance
12 | $InstanceName = "https://"+$Instance+".service-now.com/"
13 |
14 | #// Create SN REST API credentials
15 | $SNowUser = $User
16 | $SNowPass = $Password | ConvertTo-SecureString -asPlainText -Force
17 | $SNowCreds = New-Object –TypeName System.Management.Automation.PSCredential –ArgumentList $SNowUser, $SNowPass
18 |
19 | $groups = gc $inputpath
20 | foreach($group in $groups)
21 | {
22 | [string]$AssignGroup = $group
23 | $outputhtml = "$outputpath\$Group.html"
24 | ''|out-file $outputhtml
25 | '' + "$Group Unassigned Tickets" + '
' |out-file $outputhtml -append
26 | 'Last Update: '+ $date +'' |out-file $outputhtml -append
27 |
28 |
29 | #// Get all items Assigned To
30 | $URI = ''
31 | $items = ''
32 | $results = ''
33 | $URI = $InstanceName+"api/now/table/sc_req_item?sysparm_query=assignment_group.name="+$AssignGroup+"^assigned_toISEMPTY"+"^state=2^ORstate=9^ORstate=13"
34 | $URI2 = $InstanceName+"api/now/table/incident?sysparm_query=assignment_group.name="+$AssignGroup+"^assigned_toISEMPTY"+"^incident_state=1^ORincident_state=2^ORincident_state=3"
35 | $items = @()
36 | $items += try{Invoke-RestMethod -Uri $URI -Credential $SNowCreds -Method GET -ContentType "application/json"}catch{
37 | 'Service Now Query failed. Check your queue directly.' |out-file $outputhtml -append
38 | continue}
39 | $items += try{Invoke-RestMethod -Uri $URI2 -Credential $SNowCreds -Method GET -ContentType "application/json"}catch{
40 | 'Service Now Query failed. Check your queue directly.' |out-file $outputhtml -append
41 | continue}
42 | $Resultsunsorted = $items.result # |sort number -Descending
43 |
44 | $results = $Resultsunsorted |sort opened_at -Descending
45 | #// Show each item found
46 | $item = ''
47 | foreach ($item in $Results) {
48 | $openedby = ''
49 | $Openedby = get-aduser -identity $item.sys_created_by |select -ExpandProperty name
50 | $ReqURLbase = ''
51 | if($item.number -like "RIT*")
52 | {$ReqURLbase = "https://YourOrg.service-now.com/nav_to.do?uri=sc_req_item.do?sys_id="}
53 | if($item.number -like "INC*")
54 | {$ReqURLbase = "https://YourOrg.service-now.com/nav_to.do?uri=incident.do?sys_id="}
55 | $ReqURLFull = ''
56 | $ReqURLFull = $ReqURLbase+$item.sys_id
57 | '' + $item.number + '
'|out-file $outputhtml -append
58 | #'Number: ' + + '
'|out-file $outputhtml -append
59 | 'Date Opened: ' + $item.opened_at + '
'|out-file $outputhtml -append
60 | 'Opened by: ' + $openedby +'
'|out-file $outputhtml -append
61 | 'Short Description: ' + $item.short_description.replace("`n","
") + '
'|out-file $outputhtml -append
62 | 'Full Description: ' + '
' |out-file $outputhtml -append
63 | $item.description.Replace("`n","
") |out-file $outputhtml -append
64 | '
'|out-file $outputhtml -append
65 | }#end foreach $item
66 | '' |out-file $outputhtml -append
67 | }#end foreach $group
68 |
--------------------------------------------------------------------------------
/WIP/GetUserTickets.ps1:
--------------------------------------------------------------------------------
1 | $timestamp = (get-date).ToString('yyMMMddhhmmss')
2 | $outputpath = 'E:\inetpub\wwwroot\InfrastructureInfo\sn\users'
3 | $inputpath = 'E:\PSSCripts\SNOWScripts\users.txt'
4 | $pwpath = 'E:\psscripts\snowscripts\cred\snowpw.txt'
5 | $date = (get-date).tostring('g')
6 | [string]$user = 'rharrington_ps'
7 | [string]$password = get-content $pwpath
8 |
9 | [string]$instance = 'YourOrg'
10 |
11 | #// Set Instance
12 | $InstanceName = "https://"+$Instance+".service-now.com/"
13 |
14 | #// Create SN REST API credentials
15 | $SNowUser = $User
16 | $SNowPass = $Password | ConvertTo-SecureString -asPlainText -Force
17 | $SNowCreds = New-Object –TypeName System.Management.Automation.PSCredential –ArgumentList $SNowUser, $SNowPass
18 |
19 | $users = gc $inputpath
20 | foreach($user in $users)
21 | {
22 | [string]$AssignedTo = $user
23 | [string]$displayname = get-aduser -identity $assignedto |select -ExpandProperty name
24 | $newname = $displayname.replace(' ','_')
25 | $outputhtml = "$outputpath\$newname.html"
26 | ''|out-file $outputhtml
27 | '' + "$displayname Open Tickets" + '
' |out-file $outputhtml -append
28 |
29 | 'Last Update: '+ $date +'' |out-file $outputhtml -append
30 |
31 |
32 | #// Get all items Assigned To
33 | $URI = ''
34 | $items = ''
35 | $results = ''
36 | $URI = $InstanceName+"api/now/table/sc_req_item?sysparm_query=assigned_to.user_name=$assignedto"+"^state=2^ORstate=9^ORstate=13"
37 | $URI2 = $InstanceName+"api/now/table/incident?sysparm_query=assigned_to.user_name=$assignedto"+"^state=2^ORstate=9^ORstate=13^ORstate=3^ORstate=1"
38 | $items = @()
39 | $items += try{Invoke-RestMethod -Uri $URI -Credential $SNowCreds -Method GET -ContentType "application/json"}catch{
40 | 'Service Now Query failed. Check your queue directly.' |out-file $outputhtml -append
41 | continue}
42 | $items += try{Invoke-RestMethod -Uri $URI2 -Credential $SNowCreds -Method GET -ContentType "application/json"}catch{
43 | 'Service Now Query failed. Check your queue directly.' |out-file $outputhtml -append
44 | continue}
45 | $Resultsunsorted = $items.result # |sort number -Descending
46 |
47 | $results = $Resultsunsorted |sort opened_at -Descending
48 | #// Show each item found
49 | $item = ''
50 | foreach ($item in $Results) {
51 | $openedby = ''
52 | $Openedby = get-aduser -identity $item.sys_created_by |select -ExpandProperty name
53 | $ReqURLbase = ''
54 | if($item.number -like "RIT*")
55 | {$ReqURLbase = "https://YourOrg.service-now.com/nav_to.do?uri=sc_req_item.do?sys_id="}
56 | if($item.number -like "INC*")
57 | {$ReqURLbase = "https://YourOrg.service-now.com/nav_to.do?uri=incident.do?sys_id="}
58 | $ReqURLFull = ''
59 | $ReqURLFull = $ReqURLbase+$item.sys_id
60 | '' + $item.number + '
'|out-file $outputhtml -append
61 | #'Number: ' + + '
'|out-file $outputhtml -append
62 | 'Date Opened: ' + $item.opened_at + '
'|out-file $outputhtml -append
63 | 'Opened by: ' + $openedby +'
'|out-file $outputhtml -append
64 | 'Short Description: ' + $item.short_description.replace("`n","
") + '
'|out-file $outputhtml -append
65 | 'Full Description: ' + '
' |out-file $outputhtml -append
66 | $item.description.Replace("`n","
") |out-file $outputhtml -append
67 | '
'|out-file $outputhtml -append
68 |
69 | }#end foreach $result
70 | '' |out-file $outputhtml -append
71 | }#end foreach $user
72 |
--------------------------------------------------------------------------------
/WIP/Load-SmoAndSqlProvider.ps1:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/WIP/Load-SmoAndSqlProvider.ps1
--------------------------------------------------------------------------------
/WIP/PingServers.ps1:
--------------------------------------------------------------------------------
1 | $sizeThreshold_In_MB = 5;
2 | $pingResultPath = 'F:\PingMirroringPartners\';
3 | $pingResultFile = 'F:\PingMirroringPartners\pingResult';
4 | $names = @('Server01','Server02');
5 | # Delete files older than 15 days
6 | $limit = (Get-Date).AddDays(-15);
7 | Get-ChildItem -Path $pingResultPath -Recurse -Force | Where-Object {$_.Name -like 'pingResult*' -and !$_.PSIsContainer -and $_.CreationTime -lt $limit } | Remove-Item -Force;
8 |
9 | if (Test-Path $pingResultFile -PathType Leaf)
10 | {
11 | $fileDetails = Get-ItemProperty $pingResultFile;
12 | $sizeInKB = ([Math]::Ceiling(($fileDetails.Length/1mb)));
13 |
14 | if ($sizeInKB -ge $sizeThreshold_In_MB)
15 | {
16 | Write-Host "Renaming file $pingResultFile to $($pingResultFile) $(Get-Date -Format ddMMMyyyyTHHmm) since threshold size of $sizeThreshold_In_MB MB is crossed.";
17 | Rename-Item -Path $pingResultFile -NewName ($pingResultFile+(Get-Date -Format ddMMMyyyyTHHmm));
18 | }
19 | }
20 |
21 | foreach ($name in $names)
22 | {
23 | if (Test-Connection -ComputerName $name -Count 1 -ErrorAction SilentlyContinue)
24 | {
25 | Out-File -FilePath $pingResultFile -Append -InputObject "$((Get-Date).ToString()) - $name is Up and Running";
26 | }
27 | else
28 | {
29 | Out-File -FilePath $pingResultFile -Append -InputObject "$((Get-Date).ToString()) - $name is not connecting";
30 | Out-File -FilePath $pingResultFile -Append -InputObject (Test-Connection $name -Count 1 );
31 | }
32 | }
33 | # Return 0 for Success
34 | return 0;
--------------------------------------------------------------------------------
/WIP/Restore-DatabaseByScriptOut.ps1:
--------------------------------------------------------------------------------
1 | function Restore-DatabaseByScriptOut
2 | {
3 | [CmdletBinding()]
4 | param(
5 | [Parameter(Mandatory=$true)] [string]$SourceSqlInstance,
6 | [Parameter(Mandatory=$true)] [string]$SourceDatabase,
7 | [Parameter(Mandatory=$true)] [string]$DestinationSqlInstance,
8 | [Parameter(Mandatory=$true)] [string]$DestinationDatabase,
9 | [Parameter(Mandatory=$true)] [string]$WorkingDirectory,
10 | [Parameter(Mandatory=$false)][switch]$CreateDatabaseShell
11 | )
12 |
13 | if($CreateDatabaseShell)
14 | {
15 | Write-Verbose "Logic to create Database Shell begins here..";
16 |
17 | $d_srv = new-Object Microsoft.SqlServer.Management.Smo.Server("$DestinationSqlInstance")
18 | $d_db = New-Object Microsoft.SqlServer.Management.Smo.Database($d_srv, "$DestinationDatabase")
19 | $d_db.Create()
20 | if($d_db.CreateDate) {
21 | Write-Verbose "Database [$DestinationSqlInstance].[$DestinationDatabase] shell is created..";
22 | }
23 |
24 | }else {
25 | Write-Verbose "Checking to make sure database [$DestinationSqlInstance].[$DestinationDatabase] shell already exists";
26 | }
27 |
28 | $SourceSqlInstance_p = $SourceSqlInstance;
29 | if($SourceSqlInstance -notcontains '\') {$SourceSqlInstance_p += '\MSSQLSERVER'}
30 |
31 | $DestinationSqlInstance_p = $DestinationSqlInstance;
32 | if($DestinationSqlInstance -notcontains '\') {$DestinationSqlInstance_p += '\MSSQLSERVER'}
33 | }
34 |
35 | Invoke-Sqlcmd -ServerInstance SqlProd1 -Query 'drop database Global';
36 |
37 | Restore-DatabaseByScriptOut -SourceSqlInstance SqlProd1 -SourceDatabase Global `
38 | -DestinationSqlInstance SqlProd1 -DestinationDatabase Global `
39 | -WorkingDirectory c:\temp\migration -CreateDatabaseShell `
40 | -Verbose
--------------------------------------------------------------------------------
/WIP/TreeSizeHtml.ps1:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/imajaydwivedi/SQLDBATools/013c9ea3e230d64bc1287d52023e6a3d5f3b7fa0/WIP/TreeSizeHtml.ps1
--------------------------------------------------------------------------------
/WIP/Update-DBMailProfile.ps1:
--------------------------------------------------------------------------------
1 | Function Update-DBMailProfile {
2 | <#
3 | .SYNOPSIS
4 | Creates command modifies the default Database mail profile for server/instance passed as parameter
5 | .DESCRIPTION
6 | Creates command modifies the default Database mail profile for server/instance passed as parameter. Below are the steps taken in TSQL script:-
7 |
8 | 1) Take out details like Mail profiles, Accounts, and Sequence Number into @ProfilesAccounts variable table.
9 | 2) Check if an entry exists where profileName = @@SERVERNAME and accountName = ‘SQLAlerts’. If yes, then do nothing. Else proceed to Step 3.
10 | 3) Take below actions:-
11 | a. Add profile if not exists
12 | b. Add account if not exists
13 | c. Bind account with profile if not there
14 | d. Move other account sequence number to > 1, and set sequence number for ‘SQLAlerts’ account to 1.
15 |
16 | .PARAMETER SQLInstance
17 | Name of the server where sp_Blitz procedures need to be created.
18 | For Example:
19 | Modify-DBMailProfile -SQLInstance ServerName01
20 | .EXAMPLE
21 | Modify-DBMailProfile -SQLInstance ServerName01
22 | This example will create mail profile with server name (@@servername), set it as default public profile.
23 | #>
24 | Param (
25 | [Alias('ServerName')][String]$SQLInstance,
26 | [String]$scriptPath = $PSScriptRoot+'\DatabaseMailProfile.sql'
27 | )
28 |
29 | Push-Location;
30 | Import-Module SQLPS -DisableNameChecking;
31 | Pop-Location;
32 |
33 | $path = "$PSScriptRoot\Results";
34 | If(!(test-path $path))
35 | {
36 | New-Item -ItemType Directory -Force -Path $path;
37 | }
38 | try
39 | {
40 | Write-Host "Executing script '$scriptPath' on [$SQLInstance] server.";
41 | Invoke-Sqlcmd -ServerInstance $SQLInstance -Database msdb -InputFile $scriptPath -ErrorAction Stop| `
42 | Out-File -FilePath "$path\$($SQLInstance)__OUTPUT.txt"
43 | }
44 |
45 | Catch
46 | {
47 | #Write-Host " Error occurred" -BackgroundColor Yellow -ForegroundColor Red ;
48 | $ErrorMessage = $_.Exception.Message;
49 | "Error occurred:- $ErrorMessage" | `
50 | Out-File -FilePath "$path\$($SQLInstance)__ERROR.txt"
51 | Break
52 | }
53 | }
54 |
55 | $instances = Invoke-Sqlcmd -ServerInstance 'BAN-1ADWIVEDI-L' -Database DBServers_master -Query 'select [Server/Instance Name] as InstanceName from [dbo].[Production] as p
56 | where p.[ID/Count] = 2';
57 |
58 | foreach($inst in $instances) {
59 | Try
60 | {
61 | Modify-DBMailProfile -SQLInstance $inst.InstanceName;
62 | }
63 | Catch
64 | {
65 | #Write-Host " Error occurred" -BackgroundColor Yellow -ForegroundColor Red ;
66 | $ErrorMessage = $_.Exception.Message;
67 | "Error occurred:- $ErrorMessage" | `
68 | Out-File -FilePath "$path\$($inst.InstanceName)__ERROR.txt" -Append;
69 | Break
70 | }
71 | }
72 |
73 |
74 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-AlwaysOnReplicaIssues.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 |
3 | Import-Module SQLDBATools -DisableNameChecking;
4 | #Import-Module dbatools -DisableNameChecking;
5 |
6 | $ExecutionLogsFile = "$$SdtLogsPath\Get-AlwaysOnIssues\___ExecutionLogs.txt";
7 | #New-Item $ExecutionLogsFile -Force
8 |
9 | # Truncate Staging table
10 | #Invoke-Sqlcmd -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase -Query 'truncate table [SQLDBATools].Staging.[AOReplicaInfo];';
11 |
12 | $instancesquery ="SELECT ListenerName FROM Info.AlwaysOnListener";
13 | $instances = Execute-SqlQuery -Query $instancesquery -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase #-ConnectionTimeout 0 -QueryTimeout 0
14 |
15 | $servers = @($instances | select -ExpandProperty ListenerName);
16 |
17 | $replicaHealthQuery = @"
18 | SELECT cl.cluster_name
19 | ,ag.dns_name as ag_Listener
20 | ,ar.replica_server_name
21 | ,ars.role_desc
22 | ,ar.failover_mode_desc
23 | ,ars.synchronization_health_desc
24 | ,ars.operational_state_desc
25 | ,CASE ars.connected_state
26 | WHEN 0
27 | THEN 'Disconnected'
28 | WHEN 1
29 | THEN 'Connected'
30 | ELSE ''
31 | END AS ConnectionState
32 | ,getdate() as CollectionTime
33 | FROM sys.dm_hadr_availability_replica_states ars
34 | INNER JOIN sys.availability_replicas ar ON ars.replica_id = ar.replica_id
35 | AND ars.group_id = ar.group_id
36 | CROSS JOIN
37 | sys.dm_hadr_cluster AS cl
38 | CROSS JOIN
39 | sys.availability_group_listeners AS ag
40 | "@;
41 |
42 | TRY {
43 | if (Test-Path $ExecutionLogsFile) {
44 | Remove-Item $ExecutionLogsFile;
45 | }
46 |
47 |
48 | "
49 | $(Get-Date) => Script running under context of [$($env:USERDOMAIN)\$($env:USERNAME)]
50 | ------------------------------------------------------------------------------------
51 | ------------------------------------------------------------------------------------
52 | " | Out-File -Append $ExecutionLogsFile;
53 |
54 | "Following SQL Instances are processed in order:-
55 | " | Out-File -Append $ExecutionLogsFile;
56 |
57 | #Set-Location 'C:\Users\adwivedi\Documents\WindowsPowerShell\Modules\SQLDBATools';
58 | $Result = @();
59 | foreach($AOServer in $servers)
60 | {
61 | $rs = Invoke-Sqlcmd -Query $replicaHealthQuery -ServerInstance $AOServer -Database master;
62 | $Result += $rs;
63 | }
64 |
65 |
66 | $dtable = $Result #| Out-DataTable;
67 |
68 | $cn = new-object System.Data.SqlClient.SqlConnection("Data Source=$sdtInventoryInstance;Integrated Security=SSPI;Initial Catalog=$sdtInventoryDatabase");
69 | $cn.Open();
70 |
71 | $bc = new-object ("System.Data.SqlClient.SqlBulkCopy") $cn;
72 | $bc.DestinationTableName = "Staging.AOReplicaInfo";
73 | $bc.WriteToServer($dtable);
74 | $cn.Close();
75 |
76 | return 0;
77 |
78 | }
79 | CATCH {
80 | $ErrorMessage = $_.Exception.Message;
81 | $FailedItem = $_.Exception.ItemName;
82 | $errorFile = "$$SdtLogsPath\Get-AlwaysOnIssues\$AOServer.txt";
83 |
84 | # Create if Error Log path does not exist
85 | if (!(Test-Path "$$SdtLogsPath\Get-AlwaysOnIssues")) {
86 | New-Item "$$SdtLogsPath\Get-AlwaysOnIssues" -ItemType directory;
87 | }
88 |
89 | # Drop old error log file
90 | if (Test-Path $errorFile) {
91 | Remove-Item $errorFile;
92 | }
93 |
94 | # Output Error in file
95 | @"
96 | Error occurred AO Listener $AOServer
97 | $ErrorMessage
98 | "@ | Out-File $errorFile;
99 | Write-Verbose "Error occurred in while trying to get Replica Info for AO Listener [$AOServer]. Kindly check logs at $errorFile";
100 |
101 | return 1;
102 | }
103 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-AutoBuild.ps1:
--------------------------------------------------------------------------------
1 | function Install-SqlInstance {
2 | <#
3 | .SYNOPSIS
4 | This function installs and configures SQL Server on computer
5 | .DESCRIPTION
6 | This function take ServerName, SQLServiceAccount, InstanceName etc are parameters, and installl SQL Server on Server.
7 | .PARAMETER ServerName
8 | Name of the Server where SQL Services will be installed
9 | .PARAMETER SQLServiceAccount
10 | SQL Server Service account to choose out of "Corporate\DevSQL", "Corporate\ProdSQL" and "Corporate\QASQL". By default 'Corporate\DevSQL' is passed.
11 | .InstanceName
12 | Name of the Instance. By default assumed to be default installation 'MSSQLSERVER'.
13 | #>
14 | [CmdletBinding()]
15 | Param(
16 | [Parameter(Mandatory=$true)]
17 | [Alias('ComputerName')]
18 | [String]$ServerName,
19 |
20 | [Parameter(Mandatory=$true)]
21 | [ValidateSet(2014, 2016, 2017, 2019)]
22 | [String] $Version = 2014,
23 |
24 | [Parameter(Mandatory=$true)]
25 | [ValidateSet('Developer','Enterprise','Standard','Express')]
26 | [String] $Edition = 'Developer',
27 |
28 | [Parameter(Mandatory=$false)]
29 | [ValidateSet("Corporate\DevSQL", "Corporate\ProdSQL", "Corporate\QASQL")]
30 | [string] $SQLServiceAccount = 'Corporate\DevSQL',
31 |
32 | [Parameter(Mandatory=$false)]
33 | [string] $InstanceName = 'MSSQLSERVER',
34 |
35 | [Parameter(Mandatory=$false)]
36 | [string] $SQLServiceAccountPassword,
37 |
38 | [Parameter(Mandatory=$false)]
39 | [string] $SAPassword,
40 |
41 | [Parameter(Mandatory=$false)]
42 | [string] $Administrators = 'Corporate\SQL Admins'
43 | )
44 |
45 | $SdtSqlServerRepository = "$SdtSqlServerRepository";
46 |
47 | Write-Verbose "Creating credentail for SQLDBATools for PSRemoting";
48 |
49 | # File Path for Credentials & Key
50 | $SQLDBATools = Get-Module -ListAvailable -Name SQLDBATools | Select-Object -ExpandProperty ModuleBase;
51 | $AESKeyFilePath = "$SQLDBATools\SQLDBATools_AESKey.key";
52 | $credentialFilePath = "$SQLDBATools\SQLDBATools_Credentials.xml";
53 | $SdtSqlServerRepository = "$SdtSqlServerRepository";
54 | [string]$userName = 'Corporate\SQLDBATools'
55 |
56 | # Create credential Object
57 | $AESKey = Get-Content $AESKeyFilePath;
58 | $pwdTxt = (Import-Clixml $credentialFilePath | Where-Object {$_.UserName -eq $userName}).Password;
59 | [SecureString]$securePwd = $pwdTxt | ConvertTo-SecureString -Key $AESKey;
60 | [PSCredential]$credentialObject = New-Object System.Management.Automation.PSCredential -ArgumentList $userName, $securePwd;
61 |
62 | Write-Verbose "Registering PSSessionConfiguration for SQLDBATools";
63 | # Create PSSessionConfig
64 | #Invoke-Command -ComputerName $ServerName -ScriptBlock { Register-PSSessionConfiguration -Name SQLDBATools -RunAsCredential $Using:credentialObject -Force -WarningAction Ignore}
65 |
66 | Write-Verbose "Starting PSRemoting Session to perform SQL Installation";
67 | $scriptBlock = {
68 | $SdtSqlServerRepository = $Using:SdtSqlServerRepository;
69 | $Version = $Using:Version;
70 | $Edition = $Using:Edition;
71 | $SetupFolder = "$SdtSqlServerRepository\$Version\$Edition";
72 | $SetupFolder_Local = "C:\";
73 |
74 | # Copy Setup File
75 | Write-Output "Copying SQL Server setup from path '$SetupFolder' to '$SetupFolder_Local' ..";
76 | Copy-Item $SetupFolder -Destination $SetupFolder_Local -Recurse -Force;
77 | }
78 | #$scriptBlock = {$env:COMPUTERNAME}
79 | #Invoke-Command -ComputerName $ServerName -ScriptBlock $scriptBlock -ConfigurationName SQLDBATools -ErrorVariable err;
80 | $VerbosePreference;
81 | Invoke-Command -ComputerName $ServerName -ScriptBlock $scriptBlock -ConfigurationName SQLDBATools -ErrorVariable err;
82 |
83 | Write-Host $err;
84 | #Get-Service *winrm* -ComputerName $ServerName | Start-Service
85 |
86 | Write-Verbose "PSRemoting Session ended.";
87 | }
88 |
89 | $ServerName = 'SqlPoc01'; $Version = 2014; $Edition = 'Developer';
90 | Install-SqlInstance -ServerName $ServerName -Version 2014 -Edition Developer -Verbose;
--------------------------------------------------------------------------------
/Wrapper/Wrapper-DatabaseBackupInfo.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 |
3 | Import-Module SQLDBATools -DisableNameChecking;
4 |
5 | $ExecutionLogsFile = "$$SdtLogsPath\Get-DatabaseBackupInfo\___ExecutionLogs.txt";
6 |
7 |
8 | $instancesquery ="SELECT InstanceName FROM Info.Instance WHERE IsDecommissioned = 0";
9 | #$instances = Invoke-Sqlcmd -Query $instancesquery -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase #-ConnectionTimeout 0 -QueryTimeout 0
10 | $instances = Execute-SqlQuery -Query $instancesquery -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase;
11 | $servers = @($instances | select -ExpandProperty InstanceName);
12 |
13 |
14 | TRY {
15 | if (Test-Path $ExecutionLogsFile) {
16 | Remove-Item $ExecutionLogsFile;
17 | }
18 |
19 | "Script running under context of [$($env:USERDOMAIN)\$($env:USERNAME)]
20 | ------------------------------------------------------------------------------------
21 | ------------------------------------------------------------------------------------
22 | " | Out-File -Append $ExecutionLogsFile;
23 |
24 | $stime = Get-Date;
25 | Set-Location 'C:\Users\adwivedi\Documents\WindowsPowerShell\Modules\SQLDBATools';
26 | Run-CommandMultiThreaded `
27 | -MaxThreads 26 `
28 | -MaxResultTime 240 `
29 | -Command Collect-DatabaseBackupInfo `
30 | -ObjectList ($servers) `
31 | -InputParam SQLInstance;
32 |
33 | $etime = Get-Date
34 |
35 | $timeDiff = New-TimeSpan -Start $stime -End $etime ;
36 |
37 | return 0;
38 | }
39 | CATCH {
40 | throw "Something went wrong";
41 | return 1;
42 | }
--------------------------------------------------------------------------------
/Wrapper/Wrapper-DatabaseBackupInfo_FAILED.ps1:
--------------------------------------------------------------------------------
1 | Import-Module SQLDBATools -DisableNameChecking;
2 |
3 | $ExecutionLogsFile = "$$SdtLogsPath\Get-DatabaseBackupInfo\___ExecutionLogs.txt";
4 |
5 | $instancesquery = @"
6 | SELECT Name as InstanceName FROM [dbo].[Instance]
7 | WHERE IsDecommissioned = 0 AND [IsPowerShellLinked] = 0 AND Domain = 'Corporate.local'
8 | "@;
9 | $instances = Execute-SqlQuery -Query $instancesquery -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase;
10 | $servers = @($instances | select -ExpandProperty InstanceName);
11 |
12 | if (Test-Path $ExecutionLogsFile) {
13 | Remove-Item $ExecutionLogsFile;
14 | }
15 |
16 | "Following SQL Instances are processed in order:-
17 | " | Out-File -Append $ExecutionLogsFile;
18 |
19 | $stime = Get-Date;
20 | Set-Location 'C:\Users\adwivedi\Documents\WindowsPowerShell\Modules\SQLDBATools';
21 |
22 | Run-CommandMultiThreaded `
23 | -MaxThreads 26 `
24 | -MaxResultTime 240 `
25 | -Command Collect-DatabaseBackupInfo `
26 | -ObjectList ($servers) `
27 | -InputParam SQLInstance;
28 |
29 |
30 | <#
31 | $i = 0;
32 | foreach($SQLInstance in $servers)
33 | {
34 | $i = $i + 1;
35 | # Making entry into General Logs File
36 | "$i) $SQLInstance " | Out-File -Append $ExecutionLogsFile;
37 |
38 | Collect-DatabaseBackupInfo -SQLInstance $SQLInstance -Verbose;
39 |
40 | }
41 | #>
42 |
43 | "Processed $i sql instances" | Out-File -Append $ExecutionLogsFile;
44 |
45 | $etime = Get-Date
46 |
47 | $timeDiff = New-TimeSpan -Start $stime -End $etime ;
48 |
49 |
50 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-DbaLogWalk.ps1:
--------------------------------------------------------------------------------
1 | <#
2 | Remove-Module SQLDBATools -ErrorAction SilentlyContinue;
3 | Import-Module SQLDBATools -DisableNameChecking;
4 | #>
5 | cls
6 | $SourceDatabases_DS12 = @('AMG_AVG','AMG_Extra','AMG_Music','AMG_MusicMore','Babel','DSG_EU','Facebook','Mosaic','MuzeUK','MuzeUS','MuzeVideo','Prism','RGS','RCM_morecore_20130710_NoMusic1a_en-US','Sky','Staging','Staging2','Twitter','TVGolConfigs','UKVideo');
7 | foreach($SourceDb in $SourceDatabases_DS12)
8 | {
9 | Setup-DbaLogWalk -SourceServer SqlProd01 -SourceDbName $SourceDb -DestinationServer SqlProd12 -GenerateRESTOREScriptOnly;
10 | }
11 |
12 | $SourceDatabases_DS13 = @('AMG_AVG','AMG_Extra','AMG_Music','AMG_MusicMore','Babel','DSG_EU','Facebook','IDS_Turner','Mosaic','MuzeUK','MuzeVideo','Prism','Staging','Staging2','Twitter','TVGolConfigs');
13 | foreach($SourceDb in $SourceDatabases_DS13)
14 | {
15 | Setup-DbaLogWalk -SourceServer SqlProd01 -SourceDbName $SourceDb -DestinationServer SqlProd13 -GenerateRESTOREScriptOnly;
16 | }
17 |
18 | <#
19 | $babelHistory = Get-DbaBackupHistory -SqlInstance SqlProd1 -Database Babel -Last
20 | $babelHistory | Select-Object * | ogv
21 | $ProcessAllLogBackups = $true;
22 | $logBackupFiles_Count = 0;
23 | if($ProcessAllLogBackups)
24 | {
25 | @($babelHistory | Where-Object {$_.Type -eq 'LOG'}).Count
26 | }
27 | #>
28 | <#
29 | foreach($bkp in $babelHistory)
30 | {
31 | $bkpFileSize_GB = $bkp.CompressedBackupSize.Gigabyte;
32 | #if([string]::IsNullOrEmpty($bkpFileSize)) {$bkpFileSize = $bkp.TotalSize}
33 |
34 | #$bkpFileSizeUnit = $bkpFileSize.SubString($bkpFileSize.LastIndexOf(' ')+1);
35 | #$bkpFileSizeValue = [float]($bkpFileSize.Substring(0,$bkpFileSize.LastIndexOf(' ')));
36 | #$bkpFileSize_GB = if($bkpFileSizeUnit -eq 'KB'){0} elseif($bkpFileSizeUnit -eq 'MB'){1} elseif ($bkpFileSizeUnit -eq 'GB'){$bkpFileSizeValue} elseif($bkpFileSizeUnit -eq 'TB'){$bkpFileSizeValue*1024};
37 |
38 | if($bkpFileSize_GB -le 30 -and $bkp.Path -match ":") {
39 | $backupPath = "\\$SourceServer\" + ($($bkp.Path) -replace ':\\','$\');
40 | }else {
41 | $backupPath = $bkp.Path;
42 | }
43 | $backupPath
44 | }
45 | #>
46 |
47 |
48 | #Invoke-Command -ComputerName DestinationServer -ScriptBlock { robocopy '\\SqlProd01\J$\MSSQLData\Backups' 'Local\Path\On\Destination' Babel_FULL_20190613.bak }
--------------------------------------------------------------------------------
/Wrapper/Wrapper-EventLogs.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 |
3 | Import-Module dbatools #-Scope Local -ErrorAction SilentlyContinue;
4 | #Import-Module SQLDBATools -DisableNameChecking;
5 | Invoke-Expression -Command "C:\Set-EnvironmentVariables.ps1";
6 |
7 | $ExecutionLogsFile = "$$SdtLogsPath\Wrapper-EventLogs\___ExecutionLogs.txt";
8 |
9 | $Servers = @('SqlNode01','SqlNode02','SqlNode03');
10 | $EventIDs = @(7034,1069,2004)
11 | #$After = (Get-Date).AddDays(-10);
12 |
13 | TRY
14 | {
15 | if (Test-Path $ExecutionLogsFile) {
16 | Remove-Item $ExecutionLogsFile;
17 | } else {
18 | $f = New-Item -Path $ExecutionLogsFile -ItemType "file" -Force;
19 | }
20 |
21 |
22 | "Script running under context of [$($env:USERDOMAIN)\$($env:USERNAME)]
23 | ------------------------------------------------------------------------------------
24 | ------------------------------------------------------------------------------------
25 | " | Out-File -Append $ExecutionLogsFile;
26 |
27 | $Error.Clear();
28 | $Command = {
29 | $After = (Get-Date).AddHours(-2);
30 | Get-EventLog -EntryType Error -LogName System -After $After | Where-Object {$_.EventID -in $EventIDs} | Select-Object TimeGenerated, MachineName, Source, EventID, EntryType, Message;
31 | }
32 | $ErrorLogs = Invoke-Command -ComputerName $Servers -ScriptBlock $Command -ErrorAction SilentlyContinue;
33 | $ErrorLogs | Select-Object TimeGenerated, MachineName, Source, EventID, @{l='EntryType';e={$_.EntryType.Value}}, Message `
34 | | Write-DbaDataTable -SqlInstance $sdtInventoryInstance -Database $sdtAutomationDatabase -Schema 'dbo' -Table 'EventLogs' -AutoCreateTable -Truncate;
35 |
36 | return '0';
37 | }
38 | CATCH {
39 | $formatstring = "{0} : {1}`n{2}`n" +
40 | " + CategoryInfo : {3}`n" +
41 | " + FullyQualifiedErrorId : {4}`n"
42 | $fields = $_.InvocationInfo.MyCommand.Name,
43 | $_.ErrorDetails.Message,
44 | $_.InvocationInfo.PositionMessage,
45 | $_.CategoryInfo.ToString(),
46 | $_.FullyQualifiedErrorId
47 |
48 | $returnMessage = $formatstring -f $fields;
49 |
50 | if ($Error -eq 'Unable to Find CurJob')
51 | {
52 | return "No job in queue right now.";
53 | }
54 | else {
55 | "Error:-
56 | $returnMessage
57 | " | Out-File -Append $ExecutionLogsFile;
58 | #throw "$Error";
59 | return $returnMessage;
60 | }
61 | }
62 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-ExecuteTsqlScriptOnAllServers.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 | Import-Module SQLDBATools -DisableNameChecking;
3 |
4 | $tQuery = @"
5 | select InstanceName from Info.Instance
6 | "@;
7 |
8 | $Servers = Invoke-Sqlcmd -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase -Query $tQuery | Select-Object -ExpandProperty InstanceName;
9 |
10 | $Services = $Servers | Run-CommandMultiThreaded -Command "Get-Service" `
11 | -InputParam 'ComputerName'
12 |
13 | $Services | Where-Object {$_.Name -like '*sql*' } | Select-Object MachineName, Name, DisplayName, Status, StartType | ft -AutoSize
--------------------------------------------------------------------------------
/Wrapper/Wrapper-JAMSEntry.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 |
3 | Import-Module dbatools #-Scope Local -ErrorAction SilentlyContinue;
4 | #Import-Module SQLDBATools -DisableNameChecking;
5 | Import-Module JAMS;
6 | Invoke-Expression -Command "C:\Set-EnvironmentVariables.ps1";
7 |
8 | $ExecutionLogsFile = "$$SdtLogsPath\Wrapper-JAMSEntry\___ExecutionLogs.txt";
9 |
10 | # Set Jams Server
11 | $JAMS_Server = 'SqlProd3';
12 |
13 | TRY
14 | {
15 | if (Test-Path $ExecutionLogsFile) {
16 | Remove-Item $ExecutionLogsFile;
17 | }
18 |
19 | "Script running under context of [$($env:USERDOMAIN)\$($env:USERNAME)]
20 | ------------------------------------------------------------------------------------
21 | ------------------------------------------------------------------------------------
22 | " | Out-File -Append $ExecutionLogsFile;
23 |
24 | $Error.Clear();
25 | # Push JAMSEntry queue to SQL Table
26 | $JAMS_CurrentSetups = Get-JAMSEntry -Server $JAMS_Server | Where-Object {$_.Setup -like 'Setup: Sync*'};
27 |
28 |
29 | $JAMS_CurrentSetups | Select-Object @{l='ServerName';e={ if($_.Setup -match "\s(?'ServerName'BLR\w+)") { $Matches['ServerName'] } else {$null} }}, SetupID, Setup, JAMSEntry, JobName, Description, CurrentState, TodaysDate, HoldTime, OriginalHoldTime, `
30 | ElapsedTime, CompletionTime, FinalStatus, Held, Stalled, WaitFor, StepWait, Halted, InitiatorType, SubmittedBy, @{l='CollectionTime';e={Get-Date}} | #ogv
31 | Write-DbaDataTable -SqlInstance $sdtInventoryInstance -Database $sdtInventoryDatabase -Schema 'Staging' -Table JAMSEntry #-AutoCreateTable
32 |
33 | #return "Script Wrapper-JAMSEntry executed successfully";
34 | return '0';
35 | }
36 | CATCH {
37 | $formatstring = "{0} : {1}`n{2}`n" +
38 | " + CategoryInfo : {3}`n" +
39 | " + FullyQualifiedErrorId : {4}`n"
40 | $fields = $_.InvocationInfo.MyCommand.Name,
41 | $_.ErrorDetails.Message,
42 | $_.InvocationInfo.PositionMessage,
43 | $_.CategoryInfo.ToString(),
44 | $_.FullyQualifiedErrorId
45 |
46 | $returnMessage = $formatstring -f $fields;
47 |
48 | if ($Error -eq 'Unable to Find CurJob')
49 | {
50 | return "No job in queue right now.";
51 | }
52 | else {
53 | "Error:-
54 | $returnMessage
55 | " | Out-File -Append $ExecutionLogsFile;
56 | #throw "$Error";
57 | return $returnMessage;
58 | }
59 | }
60 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-PowerShellDataCollection.ps1:
--------------------------------------------------------------------------------
1 | Import-Module SQLDBATools -DisableNameChecking;
2 |
3 | #Set-Variable -Name sdtInventoryInstance -Value 'BAN-1ADWIVEDI-L' -Scope Global;
4 | #Set-Variable -Name sdtInventoryDatabase -Value 'DBServers_master' -Scope Global;
5 |
6 | #$sdtInventoryInstance = 'BAN-1ADWIVEDI-L';
7 | #$sdtInventoryDatabase = 'DBServers_master';
8 |
9 | $instancesquery ="select [Server/Instance Name] as InstanceName from [dbo].[Production]";
10 | $instances = Invoke-Sqlcmd -Query $instancesquery -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase #-ConnectionTimeout 0 -QueryTimeout 0
11 | $servers = @($instances | select -ExpandProperty InstanceName);
12 |
13 | #$servers = @($env:COMPUTERNAME);
14 |
15 | #$servers
16 | #cd C:\temp\Collect-DatabaseBackupInfo;
17 | #Remove-Item "c:\temp\PowerShellDataCollection\Collect-DatabaseBackupInfo.txt" -ErrorAction Ignore;
18 |
19 | Push-Location;
20 |
21 | $stime = Get-Date;
22 | Set-Location 'C:\Users\adwivedi\Documents\WindowsPowerShell\Modules\SQLDBATools';
23 | Run-CommandMultiThreaded `
24 | -MaxThreads 3 `
25 | -Command Collect-DatabaseBackupInfo `
26 | -ObjectList ($servers) `
27 | -InputParam SQLInstance -Verbose
28 |
29 | $etime = Get-Date
30 |
31 | $timeDiff = New-TimeSpan -Start $stime -End $etime ;
32 | write-host $timeDiff;
33 |
34 | Pop-Location;
--------------------------------------------------------------------------------
/Wrapper/Wrapper-SQLInstanceInfo.ps1:
--------------------------------------------------------------------------------
1 | Import-Module SqlServer;
2 | Import-Module dbatools;
3 | Remove-Module SQLDBATools -ErrorAction SilentlyContinue;
4 | Import-Module SQLDBATools -DisableNameChecking;
5 |
6 | $global:SdtLogErrorToInventory = $true;
7 |
8 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
9 | $ExecutionLogsFile = "$$SdtLogsPath\Wrapper-ServerInfo\___ExecutionLogs.txt";
10 |
11 | $tsqlInventoryServers = @"
12 | select * from dbo.Server s where s.IsStandaloneServer = 1 or s.IsSqlCluster = 1 or s.IsAG = 1 or s.IsAgNode = 1
13 | "@;
14 |
15 | $Servers = Invoke-DbaQuery -SqlInstance $sdtInventoryInstance -Database $sdtInventoryDatabase -Query $tsqlInventoryServers;
16 | foreach($Server in $Servers)
17 | {
18 | Write-Host "Processing server [$($Server.FQDN)]";
19 | $Error.Clear();
20 | $ErrorText = $null;
21 | $CommandText = $null;
22 |
23 | try
24 | {
25 | <#
26 | # Add-ServerInfo
27 | if(![string]::IsNullOrEmpty($($Server.ServerType).Trim())) {
28 | Add-ServerInfo -ComputerName $Server.Server -EnvironmentType $Server.ServerType -GeneralDescription $Server.ShortDescription -CallTSQLProcedure No #-Verbose
29 | }
30 | else {
31 | Add-ServerInfo -ComputerName $Server.Server -GeneralDescription $Server.ShortDescription -CallTSQLProcedure No #-Verbose
32 | }
33 | #>
34 |
35 | Get-SQLInstanceInfo -ServerName $Server.FQDN;
36 |
37 | #$SuccessServers += $Server.Server;
38 | }
39 | catch {
40 | $returnMessage = $null;
41 | $formatstring = "{0} : {1}`n{2}`n" +
42 | " + CategoryInfo : {3}`n" +
43 | " + FullyQualifiedErrorId : {4}`n"
44 | $fields = $_.InvocationInfo.MyCommand.Name,
45 | $_.ErrorDetails.Message,
46 | $_.InvocationInfo.PositionMessage,
47 | $_.CategoryInfo.ToString(),
48 | $_.FullyQualifiedErrorId
49 |
50 | $returnMessage = $formatstring -f $fields;
51 |
52 | @"
53 |
54 |
55 | Error:-
56 |
57 | $returnMessage
58 | "@ | Out-File -Append $ExecutionLogsFile;
59 |
60 |
61 | Write-Host $returnMessage -ForegroundColor Red;
62 | }
63 | }
64 |
65 | $global:SdtLogErrorToInventory = $false;
66 |
67 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-SdtTestCommand.ps1:
--------------------------------------------------------------------------------
1 | [CmdletBinding()]
2 | Param (
3 | [Parameter(Mandatory=$false)]
4 | [string[]]$ComputerName = $env:COMPUTERNAME
5 | )
6 | $isModuleFileLoaded = $false
7 | if(Get-Module SQLDBATools) {
8 | Write-Verbose "Module SQLDBATools already imported in session."
9 | $isModuleFileLoaded = $true
10 | }
11 | else {
12 | $commandPath = Split-Path $MyInvocation.MyCommand.Path -Parent;
13 | $modulePathBasedOnWrapperLocation = Split-Path $PSScriptRoot -Parent;
14 | $moduleFileBasedOnWrapperLocation = Join-Path $modulePathBasedOnWrapperLocation 'SQLDBATools.psm1';
15 |
16 | if( Test-Path $moduleFileBasedOnWrapperLocation ) {
17 | Write-Verbose "Module file found based on wrapper file location"
18 | Import-Module $moduleFileBasedOnWrapperLocation -DisableNameChecking
19 | $isModuleFileLoaded = $true
20 | }
21 |
22 | if(-not $isModuleFileFound) {
23 | Write-Verbose "Loading module from `$env:PSModulePath"
24 | Import-Module SQLDBATools -DisableNameChecking
25 | $isModuleFileLoaded = $true
26 | }
27 | }
28 | @"
29 | `nWrapper-SdtTestCommand => You called me.
30 | `$ComputerName = '$ComputerName'
31 | `n
32 | "@ | Write-Output;
33 |
34 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-SecurityCheckInfo.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 | Import-Module SQLDBATools -DisableNameChecking -Force;
3 |
4 | # Fetch ServerInstances from Inventory
5 | $tsqlInventory = @"
6 | select InstanceName from Info.Instance
7 | "@;
8 |
9 | $ServerInstances = @(Invoke-Sqlcmd -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase -Query $tsqlInventory |
10 | Select-Object -ExpandProperty InstanceName);
11 |
12 | #Run-CommandMultiThreaded -ObjectList $ServerInstances -Command "Collect-SecurityCheckInfo" -InputParam ServerInstance -MaxThreads 26;
13 | $Result = Get-SecurityCheckInfo -ServerInstance $ServerInstances;
14 | #$Result | ft -AutoSize
15 |
16 | $dtable = $Result | Out-DataTable;
17 |
18 | $cn = new-object System.Data.SqlClient.SqlConnection("Data Source=$sdtInventoryInstance;Integrated Security=SSPI;Initial Catalog=$sdtInventoryDatabase");
19 | $cn.Open();
20 |
21 | $bc = new-object ("System.Data.SqlClient.SqlBulkCopy") $cn;
22 | $bc.DestinationTableName = "Staging.SecurityCheckInfo";
23 | $bc.WriteToServer($dtable);
24 | $cn.Close();
--------------------------------------------------------------------------------
/Wrapper/Wrapper-ServerInfo.ps1:
--------------------------------------------------------------------------------
1 | Import-Module SqlServer;
2 | Import-Module dbatools;
3 | Import-Module SQLDBATools -DisableNameChecking;
4 |
5 | $global:SdtLogErrorToInventory = $true;
6 |
7 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
8 | $ExecutionLogsFile = "$$SdtLogsPath\Wrapper-ServerInfo\___ExecutionLogs.txt";
9 |
10 | $tsqlInventoryServers = @"
11 | select case when s.Domain = 'Corporate' then server+'.corporate.local'
12 | when s.Domain = 'Armus' then server+'.tvguide.com'
13 | when s.Domain = 'Angoss' then server+'.angoss.local'
14 | else Server
15 | end as Server,
16 | case when s.ServerType = 'Development' then 'Dev'
17 | when s.ServerType = 'Production ' then 'Prod'
18 | when s.ServerType = 'Cluster Instance ' then 'Prod'
19 | else null
20 | end as ServerType,
21 | s.ShortDescription
22 | from [YourOrgSQLInventory].dbo.Server s
23 | where Domain not in ('Armus','Angoss')
24 | "@;
25 |
26 | $Servers = Invoke-DbaQuery -SqlInstance $sdtInventoryInstance -Query $tsqlInventoryServers;
27 | $SuccessServers = @();
28 | $FailedServers = @();
29 | foreach($Server in $Servers)
30 | {
31 | Write-Host "Processing server [$($Server.Server)]";
32 | $Error.Clear();
33 | $ErrorText = $null;
34 | $CommandText = $null;
35 |
36 | try
37 | {
38 | # Validation 01:- Ping Validation
39 | $ErrorText = "Server not reachable using Ping";
40 | $CommandText = "Test-Connection -ComputerName $($Server.Server) -Count 1 -Quiet";
41 | if ((Test-Connection -ComputerName $Server.Server -Count 1 -Quiet) -eq $false) {
42 | throw $Message;
43 | }
44 |
45 | # Validation 02:- WinRM Service
46 | $ErrorText = "WinRM service not running";
47 | $CommandText = "Invoke-Command -ComputerName $($Server.Server) -ScriptBlock {`$PSVersionTable}";
48 | $o = Invoke-Command -ComputerName $Server.Server -ScriptBlock {$PSVersionTable} -ErrorAction Stop | Out-Null;
49 |
50 | # Validation 03:- Sql Connection
51 | $ErrorText = "SQL Connection Failed";
52 | $CommandText = "Invoke-DbaQuery -SqlInstance $($Server.Server) -Query 'select @@servername'";
53 | $r = Invoke-DbaQuery -SqlInstance $Server.Server -Query 'select @@servername' -ErrorAction Stop -WarningAction Stop;
54 |
55 | # Add-ServerInfo
56 | if(![string]::IsNullOrEmpty($($Server.ServerType).Trim())) {
57 | Add-ServerInfo -ComputerName $Server.Server -EnvironmentType $Server.ServerType -GeneralDescription $Server.ShortDescription -CallTSQLProcedure No #-Verbose
58 | }
59 | else {
60 | Add-ServerInfo -ComputerName $Server.Server -GeneralDescription $Server.ShortDescription -CallTSQLProcedure No #-Verbose
61 | }
62 |
63 | $SuccessServers += $Server.Server;
64 | }
65 | catch {
66 | $returnMessage = $null;
67 | $formatstring = "{0} : {1}`n{2}`n" +
68 | " + CategoryInfo : {3}`n" +
69 | " + FullyQualifiedErrorId : {4}`n"
70 | $fields = $_.InvocationInfo.MyCommand.Name,
71 | $_.ErrorDetails.Message,
72 | $_.InvocationInfo.PositionMessage,
73 | $_.CategoryInfo.ToString(),
74 | $_.FullyQualifiedErrorId
75 |
76 | $returnMessage = $formatstring -f $fields;
77 |
78 | @"
79 |
80 |
81 | Error:-
82 |
83 | $returnMessage
84 | "@ | Out-File -Append $ExecutionLogsFile;
85 |
86 |
87 | # If Invoke-DbaQuery error
88 | if($ErrorText -eq "SQL Connection Failed") {
89 | $returnMessage = @"
90 |
91 | $ErrorText
92 | $($_.Exception.Message)
93 |
94 |
95 | "@ + $returnMessage;
96 | } else {
97 | $returnMessage = @"
98 |
99 | $ErrorText
100 |
101 | "@ + $returnMessage;
102 | }
103 |
104 | if($SdtLogErrorToInventory) {
105 | Add-CollectionError -ComputerName $Server.Server `
106 | -Cmdlet 'Wrapper-ServerInfo' `
107 | -CommandText $CommandText `
108 | -ErrorText $returnMessage `
109 | -Remark "$ErrorText";
110 | } else {
111 | Write-Verbose $returnMessage;
112 | }
113 |
114 | $FailedServers += $Server.Server;
115 | }
116 | }
117 |
118 | $global:SdtLogErrorToInventory = $false;
119 |
120 | $SuccessServers | ogv -Title "Successfully connected Servers"
121 | $FailedServers | ogv -Title "Servers with failed connection"
122 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-ServiceNow.ps1:
--------------------------------------------------------------------------------
1 | <# Using ServiceNow REST APIs and PowerShell To Automatically Create Incidents
2 | https://virtuallysober.com/2018/07/24/using-servicenow-rest-apis-and-powershell-to-automatically-create-incidents/
3 | https://github.com/Sam-Martin/servicenow-powershell#example---creating-a-incident-with-custom-table-entries
4 | https://www.powershellgallery.com/packages/ServiceNow/1.7.0
5 | #>
6 |
7 | ###############################################
8 | # Configure variable below, you will be prompted for your SNOW login
9 | ###############################################
10 | $SNOWURL = "https://YourOrg.service-now.com/"
11 | ################################################################################
12 | # Nothing to configure below this line - Starting the main function
13 | ################################################################################
14 | ###############################################
15 | # Prompting & saving SNOW credentials, delete the XML file created to reset
16 | ###############################################
17 | # Setting credential file
18 | $SNOWCredentialsFile = ".\SNOWCredentials.xml"
19 | # Testing if file exists
20 | $SNOWCredentialsFileTest = Test-Path $SNOWCredentialsFile
21 | # IF doesn't exist, prompting and saving credentials
22 | IF ($SNOWCredentialsFileTest -eq $False)
23 | {
24 | $SNOWCredentials = Get-Credential -Message "Enter SNOW login credentials"
25 | $SNOWCredentials | EXPORT-CLIXML $SNOWCredentialsFile -Force
26 | }
27 | # Importing credentials
28 | $SNOWCredentials = IMPORT-CLIXML $SNOWCredentialsFile
29 | # Setting the username and password from the credential file (run at the start of each script)
30 | $SNOWUsername = $SNOWCredentials.UserName
31 | $SNOWPassword = $SNOWCredentials.GetNetworkCredential().Password
32 | ##################################
33 | # Building Authentication Header & setting content type
34 | ##################################
35 | $HeaderAuth = [Convert]::ToBase64String([Text.Encoding]::ASCII.GetBytes(("{0}:{1}" -f $SNOWUsername, $SNOWPassword)))
36 | $SNOWSessionHeader = New-Object "System.Collections.Generic.Dictionary[[String],[String]]"
37 | $SNOWSessionHeader.Add('Authorization',('Basic {0}' -f $HeaderAuth))
38 | $SNOWSessionHeader.Add('Accept','application/json')
39 | $Type = "application/json"
40 | ###############################################
41 | # Getting list of Incidents
42 | ###############################################
43 | $IncidentListURL = $SNOWURL+"api/now/table/incident"
44 | Try
45 | {
46 | $IncidentListJSON = Invoke-RestMethod -Method GET -Uri $IncidentListURL -TimeoutSec 100 -Headers $SNOWSessionHeader -ContentType $Type
47 | $IncidentList = $IncidentListJSON.result
48 | }
49 | Catch
50 | {
51 | Write-Host $_.Exception.ToString()
52 | $error[0] | Format-List -Force
53 | }
54 | ###############################################
55 | # Host output of the data
56 | ###############################################
57 | $IncidentCount = $IncidentList.count
58 | $ActiveIncidentCount = $IncidentList | Where-Object {$_.active -eq "true"} | Measure | Select -ExpandProperty Count
59 | "Open Incidents:"
60 | $IncidentList | Where-Object {$_.active -eq "true"} | Select number,short_description,opened_at,impact,priority | Sort-Object opened_at -Descending | Format-Table
61 | "ActiveIncidents:$ActiveIncidentCount"
62 | "TotalIncidents:$IncidentCount"
63 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-TestScript.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 |
3 | Import-Module dbatools;
4 | Import-Module SQLDBATools -DisableNameChecking;
5 | Import-Module JAMS;
6 |
7 | $ExecutionLogsFile = "$$SdtLogsPath\Wrapper-TestScript\___ExecutionLogs.txt";
8 |
9 |
10 | TRY
11 | {
12 | if (Test-Path $ExecutionLogsFile) {
13 | Remove-Item $ExecutionLogsFile;
14 | }
15 |
16 | "
17 | $(Get-Date) => Script running under context of [$($env:USERDOMAIN)\$($env:USERNAME)]
18 | ------------------------------------------------------------------------------------
19 | ------------------------------------------------------------------------------------
20 | " | Out-File -Append $ExecutionLogsFile;
21 |
22 | $Error.Clear();
23 | # Generate Dummy Error
24 | #$x = 12/0;
25 | return "Wrapper-TestScript executed successfully";
26 | }
27 | CATCH {
28 | "Error:-
29 | $Error
30 | " | Out-File -Append $ExecutionLogsFile;
31 | throw $Error;
32 | #return 1;
33 | }
34 |
--------------------------------------------------------------------------------
/Wrapper/Wrapper-VolumeInfo.ps1:
--------------------------------------------------------------------------------
1 | $env:PSModulePath = $env:PSModulePath + ";" + "C:\Program Files\WindowsPowerShell\Modules;C:\Windows\system32\WindowsPowerShell\v1.0\Modules\;C:\Program Files\MVPSI\Modules\";
2 |
3 | Import-Module SQLDBATools -DisableNameChecking;
4 |
5 | $ExecutionLogsFile = "$$SdtLogsPath\Get-VolumeInfo\___ExecutionLogs.txt";
6 | if (!(Test-Path "$$SdtLogsPath\Get-VolumeInfo")) {
7 | Write-Verbose "Path "+"$$SdtLogsPath\Get-VolumeInfo does not exist. Creating it.";
8 | New-Item -ItemType "directory" -Path "$$SdtLogsPath\Get-VolumeInfo";
9 | }
10 |
11 |
12 | $instancesquery = @"
13 | select ServerName from [info].[Server];
14 | --SELECT Name as InstanceName FROM [Info].[Instance] WHERE IsDecommissioned = 0
15 | "@;
16 |
17 | $machines = Execute-SqlQuery -Query $instancesquery -ServerInstance $sdtInventoryInstance -Database $sdtInventoryDatabase;
18 | $servers = @($machines | select -ExpandProperty ServerName);
19 |
20 |
21 | TRY {
22 | if (Test-Path $ExecutionLogsFile) {
23 | Remove-Item $ExecutionLogsFile;
24 | # Clear last Log generated
25 | Get-ChildItem "$$SdtLogsPath\Get-VolumeInfo" | Remove-Item;
26 | }
27 |
28 | "Script running under context of [$($env:USERDOMAIN)\$($env:USERNAME)]
29 | ------------------------------------------------------------------------------------
30 | ------------------------------------------------------------------------------------
31 | " | Out-File -Append $ExecutionLogsFile;
32 |
33 | $Error.Clear();
34 |
35 | $stime = Get-Date;
36 | Set-Location 'C:\Users\adwivedi\Documents\WindowsPowerShell\Modules\SQLDBATools';
37 | Run-CommandMultiThreaded `
38 | -MaxThreads 26 `
39 | -MaxResultTime 240 `
40 | -Command Collect-VolumeInfo `
41 | -ObjectList ($servers) `
42 | -InputParam ComputerName;
43 |
44 | $etime = Get-Date
45 |
46 | $timeDiff = New-TimeSpan -Start $stime -End $etime ;
47 |
48 | return "Script Wrapper-VolumeInfo executed successfully.";
49 | }
50 | CATCH {
51 | @"
52 | Error occurred while running 'Wrapper-VolumeInfo'
53 | $Error
54 | "@ | Out-File -Append $ExecutionLogsFile;
55 |
56 | throw "$Error";
57 | }
--------------------------------------------------------------------------------
/docs/_config.yml:
--------------------------------------------------------------------------------
1 | theme: jekyll-theme-architect
--------------------------------------------------------------------------------
/docs/index.md:
--------------------------------------------------------------------------------
1 | # SQLDBATools
2 | Powershell Module containing cmdlets for carrying out SQL DBA activities.
3 |
4 | **Functionality** covered includes finding our server properties, disk utilization, discover sql instance in network, find license keys, setup mail profile, setup dba operator, get backup history, audit user/database permissions, maintain inventory, cleanup orphan database files from disk, find resouce consuming queries on server, space consumers, estimate space to add into disk/database files, setup maintenance jobs, perform basic basic server optimization settings etc.
5 |
6 | This module also has built-in capability to setup **Monitoring & Alerting** system using PowerShell & SqlServer. The alerting system is designed to *automatically clear alerts* when no longer active, *send email notifications*, *suppress* alert is required, display *alert history* on Grafana. This available alerts include Disk Space, Blocking, Job Failure, High CPU, Memory Issue, and many more.
7 |
8 | ## How to Install
9 | One way to work with this module is to simply download this github repository at zip file, extract downloaded zip file, and extract it to folder named 'SQLDBATools'. Finally copy/paste it on one of the module folders returned by variable $PSGetPath.
10 |
11 | It can also be installed easily from PSGallery using below command -
12 |
13 | ```
14 | Install-Module -Name SQLDBATools
15 | # Update-Module -Name SQLDBATools
16 | ```
17 |
18 | ## Donation
19 | If this project help you reduce time to develop, you can give me a cup of coffee :)
20 |
21 | PayPal | | UPI
22 | ------ | - | -----------
23 | [](https://paypal.me/imajaydwivedi?country.x=IN&locale.x=en_GB) | | [](https://github.com/imajaydwivedi/Images/raw/master/Miscellaneous/UPI-PhonePe-Main.jpeg)
24 |
25 | -------------------------------------------------------------------------------------
26 | Some of the common functionalities of this module are as follows -
27 |
28 | ## Get-SdtLinkedServer
29 | This function scripts out SQL Server Linked Servers with actual passwords into a script file.
30 |
31 | 
32 |
33 | ## Get-SdtServerInfo
34 | This function returns basic information about machine(s) passed in pipeline or as value. This includes Operating System, Service Pack, LastBoot Time, Model, RAM & CPU for computer(s).
35 |
36 | 
37 |
38 | ## Get-SdtVolumeInfo
39 | This function returns utilization of Disk Volumes on machine including mounted volumes.
40 |
41 | [](https://youtu.be/n160GyC0g-8)
42 |
43 | ## Script-SdtSQLDatabaseRestore
44 | This function accepts backup path, data and log directory for restore operation on destination sql instance, and create RESTORE script for database restore/migration activity.
45 | It can be used for performing database restore operation with latest available backups on BackupPath.
46 | Can be used to restore database for Point In Time.
47 | Can be used for restoring database with new name on Destination SQL Instance.
48 |
49 | 
50 |
51 | For more information on how to use this, kindly [watch below YouTube video](https://youtu.be/v4r2lhIFii4):-
52 |
53 | [](https://youtu.be/v4r2lhIFii4)
54 |
55 | ## Get-SdtProcessForDBA
56 | This function displays ComputerName, ProcessId, ProcessName, Description, StartTime, Threads, Memory(MB), Path, Company, Product for all processes of Server name(s) passed as parameter.
57 |
58 | 
59 |
60 | For more information on how to use this, kindly [watch below YouTube video](https://youtu.be/bhzc2LO2Pb4):-
61 |
62 | [](https://youtu.be/bhzc2LO2Pb4)
63 |
64 | ## Get-SdtVolumeSpaceConsumers
65 | This function displays all files and folders including hidden items with details like Owner, Size, Created Date, Updated By etc path passed in parameter.
66 |
67 | 
68 |
--------------------------------------------------------------------------------