CREATE DATABASE AUDIT SPECIFICATION (Transact-SQL)
Applies to: SQL Server Azure SQL Managed Instance
Creates a database audit specification object using the SQL Server audit feature. For more information, see SQL Server Audit (Database Engine).
Transact-SQL syntax conventions
Syntax
CREATE DATABASE AUDIT SPECIFICATION audit_specification_name
{
FOR SERVER AUDIT audit_name
[ ADD (
{ <audit_action_specification> | audit_action_group_name }
[ , ...n ] )
]
[ WITH ( STATE = { ON | OFF } ) ]
}
[ ; ]
<audit_action_specification>::=
{
action [ , ...n ] ON [class::]securable BY principal [ , ...n ]
}
Arguments
audit_specification_name
The name of the audit specification.
audit_name
The name of the audit to which this specification is applied.
audit_action_specification
The specification of actions on securables by principals that should be recorded in the audit.
action
The name of one or more database-level auditable actions. For a list of audit actions, see SQL Server Audit Action Groups and Actions.
audit_action_group_name
The name of one or more groups of database-level auditable actions. For a list of audit action groups, see SQL Server Audit Action Groups and Actions.
class
The class name (if applicable) on the securable.
securable
The table, view, or other securable object in the database on which to apply the audit action or audit action group. For more information, see Securables.
principal
The name of database principal on which to apply the audit action or audit action group. To audit all database principals, use the public database principal. For more information, see Principals (Database Engine).
WITH ( STATE = { ON | OFF } )
Enables or disables the audit from collecting records for this audit specification.
Remarks
Database audit specifications are non-securable objects that reside in a given database. When a database audit specification is created, it's in a disabled state.
Permissions
Users with the ALTER ANY DATABASE AUDIT
permission can create database audit specifications and bind them to any audit.
After a database audit specification is created, users with the CONTROL SERVER
permission, or the sysadmin
account, can view it.
Examples
The Transact-SQL code samples in this article use the AdventureWorks2022
or AdventureWorksDW2022
sample database, which you can download from the Microsoft SQL Server Samples and Community Projects home page.
A. Audit SELECT and INSERT on a table for any database principal
The following example creates a server audit called Payroll_Security_Audit
and then a database audit specification called Payroll_Security_Audit
that audits SELECT
and INSERT
statements by any member of the public database role, for the HumanResources.EmployeePayHistory
table. Every user is audited, because every user is always member of the public role.
USE master;
GO
-- Create the server audit.
CREATE SERVER AUDIT Payroll_Security_Audit
TO FILE (FILEPATH = 'D:\SQLAudit\'); -- make sure this path exists
GO
-- Enable the server audit.
ALTER SERVER AUDIT Payroll_Security_Audit
WITH (STATE = ON);
GO
-- Move to the target database.
USE AdventureWorks2022;
GO
-- Create the database audit specification.
CREATE DATABASE AUDIT SPECIFICATION Audit_Pay_Tables
FOR SERVER AUDIT Payroll_Security_Audit ADD (
SELECT, INSERT ON HumanResources.EmployeePayHistory BY PUBLIC
)
WITH (STATE = ON);
GO
B. Audit any data modification on all objects in a schema for a specific database role
The following example creates a server audit called DataModification_Security_Audit
and then a database audit specification called Audit_Data_Modification_On_All_Sales_Tables
that audits INSERT
, UPDATE
, and DELETE
statements by users in a new database role SalesUK
, for all objects in the Sales
schema.
USE master;
GO
-- Create the server audit.
-- Change the path to a path that the SQLServer Service has access to.
CREATE SERVER AUDIT DataModification_Security_Audit
TO FILE (FILEPATH = 'D:\SQLAudit\'); -- make sure this path exists
GO
-- Enable the server audit.
ALTER SERVER AUDIT DataModification_Security_Audit
WITH (STATE = ON);
GO
-- Move to the target database.
USE AdventureWorks2022;
GO
CREATE ROLE SalesUK
GO
-- Create the database audit specification.
CREATE DATABASE AUDIT SPECIFICATION Audit_Data_Modification_On_All_Sales_Tables
FOR SERVER AUDIT DataModification_Security_Audit ADD (
INSERT, UPDATE, DELETE ON SCHEMA::Sales BY SalesUK
)
WITH (STATE = ON);
GO
Related tasks
Server audit specifications:
- CREATE SERVER AUDIT SPECIFICATION (Transact-SQL)
- ALTER SERVER AUDIT SPECIFICATION (Transact-SQL)
- DROP SERVER AUDIT SPECIFICATION (Transact-SQL)
Database audit specifications:
- CREATE DATABASE AUDIT SPECIFICATION (Transact-SQL)
- ALTER DATABASE AUDIT SPECIFICATION (Transact-SQL)
- DROP DATABASE AUDIT SPECIFICATION (Transact-SQL)
Catalog views and DMVs:
- sys.server_audits (Transact-SQL)
- sys.server_file_audits (Transact-SQL)
- sys.server_audit_specifications (Transact-SQL)
- sys.server_audit_specification_details (Transact-SQL)
- sys.database_audit_specifications (Transact-SQL)
- sys.database_audit_specification_details (Transact-SQL)
Related content
- Create a Server Audit and Server Audit Specification
- CREATE SERVER AUDIT (Transact-SQL)
- ALTER SERVER AUDIT (Transact-SQL)
- DROP SERVER AUDIT (Transact-SQL)
- ALTER AUTHORIZATION (Transact-SQL)
- sys.fn_get_audit_file (Transact-SQL)
- sys.dm_server_audit_status (Transact-SQL)
- sys.dm_audit_actions (Transact-SQL)