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 ]  
}  

Note

To view Transact-SQL syntax for SQL Server 2014 (12.x) and earlier versions, see Previous versions documentation.

Arguments

audit_specification_name
Is the name of the audit specification.

audit_name
Is the name of the audit to which this specification is applied.

audit_action_specification
Is the specification of actions on securables by principals that should be recorded in the audit.

action
Is 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
Is 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
Is the class name (if applicable) on the securable.

securable
Is 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
Is the name of database principal on which to apply the audit action or audit action group. To audit all database principals use the database principal public. 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 is 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, it can be viewed by users with the CONTROL SERVER permission, or the sysadmin account.

Examples

A. Audit SELECT and INSERT on a table for any database principal

The following example creates a server audit called Payrole_Security_Audit and then a database audit specification called Payrole_Security_Audit that audits SELECT and INSERT statements by any member of the public database role, for the HumanResources.EmployeePayHistory table in the AdventureWorks2022 database. This has the effect that every user is audited as every user is always member of the public role.

USE master ;  
GO  
-- Create the server audit.  
CREATE SERVER AUDIT Payrole_Security_Audit  
    TO FILE ( FILEPATH =   
'D:\SQLAudit\' ) ;  -- make sure this path exists
GO  
-- Enable the server audit.  
ALTER SERVER AUDIT Payrole_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 Payrole_Security_Audit  
ADD (SELECT , INSERT  
     ON HumanResources.EmployeePayHistory BY public )  
WITH (STATE = ON) ;  
GO  

B. Audit any DML (INSERT, UPDATE or DELETE) on all objects in the sales 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 in the AdventureWorks2022 database.

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  

See Also

CREATE SERVER AUDIT (Transact-SQL)
ALTER SERVER AUDIT (Transact-SQL)
DROP SERVER AUDIT (Transact-SQL)
CREATE SERVER AUDIT SPECIFICATION (Transact-SQL)
ALTER SERVER AUDIT SPECIFICATION (Transact-SQL)
DROP SERVER AUDIT SPECIFICATION (Transact-SQL)
CREATE DATABASE AUDIT SPECIFICATION (Transact-SQL)
ALTER DATABASE AUDIT SPECIFICATION (Transact-SQL)
DROP DATABASE AUDIT SPECIFICATION (Transact-SQL)
ALTER AUTHORIZATION (Transact-SQL)
sys.fn_get_audit_file (Transact-SQL)
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)
sys.dm_server_audit_status (Transact-SQL)
sys.dm_audit_actions (Transact-SQL)
Create a Server Audit and Server Audit Specification