Skip to content

Commit 9b74f85

Browse files
committed
updated for better naming conventions
1 parent 4f0971b commit 9b74f85

File tree

1 file changed

+73
-31
lines changed

1 file changed

+73
-31
lines changed

audit setup.sql

Lines changed: 73 additions & 31 deletions
Original file line numberDiff line numberDiff line change
@@ -8,75 +8,117 @@
88
--in SSMS, use Tools -> Options -> Query Results -> SQL Server -> Results to Grid -> Retain CR/LF on copy or save
99
--then open/close SSMS
1010

11+
--You may also have to change the "Maximum Number of Characters displayed in each column from the default.
12+
--in SSMS, use Tools -> Options -> Query Results -> SQL Server -> Results to Text window
13+
--then open/close SSMS window
1114

1215
use master
1316
GO
14-
select
15-
'USE [master]
17+
SET NOCOUNT ON
18+
GO
19+
SELECT
20+
'USE [master];
1621
GO
1722
CREATE SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+'-Audit]
1823
TO APPLICATION_LOG --write to the Application Event Log
1924
WITH
2025
( QUEUE_DELAY = 5000
2126
,ON_FAILURE = CONTINUE
22-
)
27+
);
2328
go
24-
CREATE SERVER AUDIT SPECIFICATION [ServerAudit]
29+
CREATE SERVER AUDIT SPECIFICATION ['+replace(@@SERVERNAME,'\','')+'-Audit-Spec]
2530
FOR SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+'-Audit]
2631
ADD (DATABASE_OBJECT_CHANGE_GROUP),
2732
ADD (DATABASE_ROLE_MEMBER_CHANGE_GROUP),
2833
ADD (AUDIT_CHANGE_GROUP),
2934
ADD (DATABASE_PERMISSION_CHANGE_GROUP),
3035
ADD (SCHEMA_OBJECT_PERMISSION_CHANGE_GROUP),
31-
ADD (SCHEMA_OBJECT_CHANGE_GROUP), --Important: This event is raised whenever any schema of any database changes.
36+
ADD (SCHEMA_OBJECT_CHANGE_GROUP), --Important: This event is raised for any DDL in any database.
3237
ADD (SERVER_ROLE_MEMBER_CHANGE_GROUP),
3338
ADD (LOGIN_CHANGE_PASSWORD_GROUP),
3439
ADD (SERVER_PRINCIPAL_CHANGE_GROUP)
35-
WITH (STATE = OFF)
40+
WITH (STATE = OFF);
3641
GO'
3742

38-
select
43+
SELECT
3944
--TODO 1. specify events and logins/groups to be captured for Database Audit
4045
--As configured only captures writes. Add a similar pattern for ADD(SELECT ... to capture all reads.
4146

42-
'USE ['+d.name+']
43-
GO
44-
CREATE DATABASE AUDIT SPECIFICATION [Database-'+replace(d.name,' ','')+'-Audit]
45-
FOR SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+'-Audit]
4647
--catch all known admin users, regardless of whether or not they have dbo right now
4748
--Examples:
48-
ADD (UPDATE ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
49-
ADD (DELETE ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
50-
ADD (INSERT ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
51-
ADD (EXECUTE ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
52-
ADD (UPDATE ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
53-
ADD (DELETE ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
54-
ADD (INSERT ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
55-
ADD (EXECUTE ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
49+
--ADD (UPDATE ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
50+
--ADD (DELETE ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
51+
--ADD (INSERT ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
52+
--ADD (EXECUTE ON DATABASE::['+d.name+'] BY [Sparkhound\william.assaf]),
53+
--ADD (UPDATE ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
54+
--ADD (DELETE ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
55+
--ADD (INSERT ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
56+
--ADD (EXECUTE ON DATABASE::['+d.name+'] BY [Sparkhound\Developers]),
5657

5758
--catch all database admins, period.
58-
ADD (UPDATE ON DATABASE::['+d.name+'] BY [dbo]),
59-
ADD (INSERT ON DATABASE::['+d.name+'] BY [dbo]),
60-
ADD (DELETE ON DATABASE::['+d.name+'] BY [dbo]),
61-
ADD (EXECUTE ON DATABASE::['+d.name+'] BY [dbo])
59+
--ADD (UPDATE ON DATABASE::['+d.name+'] BY [dbo]),
60+
--ADD (INSERT ON DATABASE::['+d.name+'] BY [dbo]),
61+
--ADD (DELETE ON DATABASE::['+d.name+'] BY [dbo]),
62+
--ADD (EXECUTE ON DATABASE::['+d.name+'] BY [dbo]),
63+
--ADD (SELECT ON DATABASE::['+d.name+'] BY [dbo])
64+
--WITH (STATE = OFF);
65+
66+
N'USE ['+d.name+'];
67+
GO
68+
CREATE DATABASE AUDIT SPECIFICATION [Database-'+replace(d.name,N' ',N'')+N'-Audit-Spec]
69+
FOR SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+N'-Audit]
70+
--catch all activity, period.
71+
ADD (UPDATE ON DATABASE::['+d.name+N'] BY [public]),
72+
ADD (INSERT ON DATABASE::['+d.name+N'] BY [public]),
73+
ADD (DELETE ON DATABASE::['+d.name+N'] BY [public]),
74+
ADD (EXECUTE ON DATABASE::['+d.name+N'] BY [public]),
75+
ADD (SELECT ON DATABASE::['+d.name+N'] BY [public])
6276
WITH (STATE = OFF);
6377
GO
64-
ALTER DATABASE AUDIT SPECIFICATION [Database-'+replace(d.name,' ','')+'-Audit]
65-
FOR SERVER AUDIT ['+@@SERVERNAME+'-Audit]
78+
ALTER DATABASE AUDIT SPECIFICATION [Database-'+replace(d.name,N' ',N'')+N'-Audit-Spec]
79+
FOR SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+N'-Audit]
6680
WITH (STATE = ON);
6781
GO
6882
'
69-
from sys.databases d
83+
FROM (SELECT name = convert(nvarchar(4000), d.name) from sys.databases d
84+
WHERE d.name not in ('tempdb','msdb','distribution')
85+
--and d.name in (N'a2012db') --this filter for testing only
86+
) d;
7087
--TODO 2. Add any database names here you want to ignore
71-
where d.name not in ('tempdb','msdb','distribution')
88+
7289
GO
7390
SELECT '
74-
USE master
91+
use master
92+
go
93+
ALTER SERVER AUDIT SPECIFICATION ['+replace(@@SERVERNAME,'\','')+'-Audit-Spec]
94+
WITH (STATE = ON);
7595
GO
76-
--ALTER SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+'-Audit]
77-
--WITH (STATE = OFF);
78-
--GO
7996
ALTER SERVER AUDIT ['+replace(@@SERVERNAME,'\','')+'-Audit]
8097
WITH (STATE = ON);
8198
GO
8299
';
100+
101+
/*
102+
103+
--Cleanup
104+
105+
USE [master]
106+
GO
107+
ALTER SERVER AUDIT [BTR-69NRN32SQL2K16-Audit] WITH (STATE = OFF);
108+
GO
109+
ALTER SERVER AUDIT SPECIFICATION [BTR-69NRN32SQL2K16-Audit-Spec] WITH (STATE = OFF);
110+
GO
111+
USE [a2012db]
112+
GO
113+
ALTER DATABASE AUDIT SPECIFICATION [Database-a2012db-Audit-Spec] WITH (STATE = OFF);
114+
GO
115+
DROP DATABASE AUDIT SPECIFICATION [Database-a2012db-Audit-Spec]
116+
GO
117+
USE [master]
118+
GO
119+
DROP SERVER AUDIT SPECIFICATION [BTR-69NRN32SQL2K16-Audit-Spec]
120+
GO
121+
DROP SERVER AUDIT [BTR-69NRN32SQL2K16-Audit]
122+
GO
123+
124+
*/

0 commit comments

Comments
 (0)