1
+ /* +---------------------------------------------------------------------------
2
+ | Purpose: To check for non-service accounts
3
+ | Note: SQLCmdMode Script --> on the SSMS menu bar "Query" | "SQLCMD Mode"
4
+ +-----------------------------------------------------------------------------
5
+ */
6
+
7
+ :setvar _server " YourServerName" -- change the server here
8
+ :setvar _database " master"
9
+ :connect $(_server)
10
+
11
+ USE [$(_database)];
12
+ GO
13
+
14
+ :setvar login_name " " -- to search for an individual account enter it here e.g. "Domain\UserName"
15
+
16
+
17
+ SET XACT_ABORT ON
18
+ BEGIN TRANSACTION ;
19
+
20
+ PRINT ' =====================================================================' ;
21
+ PRINT ' define all services accounts ... ' ;
22
+
23
+ SELECT tbl.* INTO #service_accounts FROM (VALUES
24
+ (' ##MS_PolicyEventProcessingLogin##' )
25
+ , (' ##MS_PolicyTsqlExecutionLogin##' )
26
+ , (' NT AUTHORITY\SYSTEM' )
27
+ , (' NT Service\MSSQLSERVER' )
28
+ , (' NT SERVICE\SQLSERVERAGENT' )
29
+ , (' NT SERVICE\SQLTELEMETRY' )
30
+ , (' NT SERVICE\SQLWriter' )
31
+ , (' NT SERVICE\Winmgmt' )
32
+ , (' public' )
33
+ , (' sa' )
34
+ ) tbl ([Login_Name])
35
+
36
+ PRINT ' =====================================================================' ;
37
+ PRINT ' check databases owners ... ' ;
38
+
39
+ SELECT
40
+ [Server_Name] = @@SERVERNAME
41
+ , [Database_Name] = db.[name]
42
+ , [Login_Name] = sl.[Name]
43
+ , [CommandToRun] = (CASE WHEN db.[is_read_only] = 1 THEN ' -- Remove ReadOnly State' WHEN db.[state_desc] = ' ONLINE' THEN ' ALTER AUTHORIZATION on DATABASE::[' + db.[name] + ' ] to [sa];' ELSE ' -- Turn On ' END )
44
+ -- , [Database_ID] = db.[database_id]
45
+ -- , [Current_State] = db.[state_desc]
46
+ -- , [Read_Only] = db.[is_read_only]
47
+ FROM
48
+ [master].[sys].[databases] AS db
49
+ INNER JOIN [master].[sys].[syslogins] AS sl ON db.[owner_sid] = sl.[sid]
50
+ WHERE
51
+ 1 = 1
52
+ AND sl.[Name] NOT IN (SELECT [Login_Name] FROM #service_accounts)
53
+ AND (sl.[Name] = N ' $(login_name)' OR N ' $(login_name)' = N ' ' )
54
+ ORDER BY
55
+ db.[Name]
56
+
57
+ PRINT ' =====================================================================' ;
58
+ PRINT ' check databases users ... ' ;
59
+
60
+ DECLARE @dbs_users TABLE
61
+ (
62
+ [Database_Name] SYSNAME
63
+ , [User_Name] SYSNAME
64
+ , [Login_Type] SYSNAME
65
+ , [Associated_Role] VARCHAR (MAX )
66
+ , [Create_Date] DATETIME
67
+ , [Modify_Date] DATETIME
68
+ )
69
+
70
+ INSERT @dbs_users
71
+ EXEC sp_MSforeachdb '
72
+ USE [?]
73
+ SELECT
74
+ [Database_Name] = '' ?''
75
+ , [User_Name] = CASE dp.[name] WHEN '' dbo'' THEN (SELECT SUSER_SNAME([owner_sid]) FROM [master].[sys].[databases] WHERE [name] ='' ?'' ) ELSE dp.[name] END
76
+ , [Login_Type] = dp.[type_desc]
77
+ , [Associated_Role] = isnull(USER_NAME(dm.role_principal_id),'' '' )
78
+ , dp.[create_date]
79
+ , dp.[modify_date]
80
+ FROM
81
+ [sys].[database_principals] AS dp
82
+ LEFT JOIN [sys].[database_role_members] AS dm ON dp.[principal_id] = dm.[member_principal_id]
83
+ WHERE
84
+ 1=1
85
+ AND dp.[sid] IS NOT NULL
86
+ AND dp.[sid] NOT IN (0x00)
87
+ AND dp.[is_fixed_role] != 1
88
+ AND dp.[name] NOT LIKE '' ##%'' '
89
+
90
+ SELECT
91
+ [Server_Name] = @@SERVERNAME
92
+ , [Database_Name]
93
+ , [User_Name]
94
+ , [Create_Date]
95
+ , [Modify_Date]
96
+ , [Permissions_User] = STUFF ((
97
+ SELECT ' ,' + CONVERT (VARCHAR (500 ), [Associated_Role])
98
+ FROM @dbs_users AS dbu2
99
+ WHERE dbu1.[Database_Name] = dbu2.[Database_Name]
100
+ AND dbu1.[User_Name] = dbu2.[User_Name]
101
+ FOR XML PATH (' ' )
102
+ ), 1 , 1 , ' ' )
103
+ -- , [Login_Type]
104
+ FROM
105
+ @dbs_users AS dbu1
106
+ WHERE
107
+ 1 = 1
108
+ AND [User_Name] NOT IN (SELECT [Login_Name] FROM #service_accounts)
109
+ AND [Login_Type] = ' WINDOWS_USER'
110
+ AND ([User_Name] = N ' $(login_name)' OR N ' $(login_name)' = N ' ' )
111
+ GROUP BY
112
+ [Database_Name]
113
+ , [User_Name]
114
+ , [Create_Date]
115
+ , [Modify_Date]
116
+ -- , [Login_Type]
117
+ ORDER BY
118
+ [Database_Name]
119
+ , [User_Name]
120
+
121
+ PRINT ' =====================================================================' ;
122
+ PRINT ' check agent jobs ... ' ;
123
+
124
+ SELECT
125
+ [Server_Name] = @@SERVERNAME
126
+ , [SQL_Agent_Job_Name] = sj.[name]
127
+ , [Job_Owner] = sl.[name]
128
+ , [CommandToRun] = ' EXEC [msdb].[dbo].[sp_update_job] @job_id=N'' ' + CAST (sj.[job_id] AS VARCHAR (150 )) + ' '' , @owner_login_name=N'' sa'' '
129
+ -- , sj.[description]
130
+ -- , sc.[name]
131
+ FROM
132
+ [msdb].[dbo].[sysjobs] AS sj
133
+ INNER JOIN [master].[sys].[syslogins] AS sl ON sj.[owner_sid] = sl.[sid]
134
+ INNER JOIN [msdb].[dbo].[syscategories] AS sc ON sc.[category_id] = sj.[category_id]
135
+ WHERE
136
+ 1 = 1
137
+ AND sl.[Name] NOT IN (SELECT [Login_Name] FROM #service_accounts)
138
+ AND (sl.[name] = N ' $(login_name)' OR N ' $(login_name)' = N ' ' )
139
+ ORDER BY
140
+ sj.[name]
141
+
142
+ PRINT ' =====================================================================' ;
143
+ PRINT ' check report subscriptions ... ' ;
144
+
145
+ IF DB_ID (' ReportServer' ) IS NOT NULL
146
+ SELECT DISTINCT
147
+ [Server_Name] = @@SERVERNAME
148
+ , [Report_Name] = rp.[Name]
149
+ , [Subscription_Owner] = ou.[UserName]
150
+ , [Subscription_Owner_ID] = ou.[UserID]
151
+ -- , sb.[Report_OID]
152
+ FROM
153
+ [ReportServer].[dbo].[Subscriptions] AS sb
154
+ INNER JOIN [ReportServer].[dbo].[Catalog] AS rp ON rp.[ItemID] = sb.[Report_OID]
155
+ INNER JOIN [ReportServer].[dbo].[Users] AS ou ON ou.[UserID] = sb.[OwnerID]
156
+ WHERE
157
+ 1 = 1
158
+ AND ou.[UserName] NOT IN (SELECT [Login_Name] COLLATE Latin1_General_CI_AS FROM #service_accounts)
159
+ AND (ou.[UserName] = N ' $(login_name)' OR N ' $(login_name)' = N ' ' )
160
+
161
+ PRINT ' ******* ROLLBACK TRANSACTION ******* ' ;
162
+ ROLLBACK TRANSACTION ;
163
+
164
+ -- PRINT '******* COMMIT TRANSACTION ******* ';
165
+ -- COMMIT TRANSACTION;
0 commit comments