Fire Trigger when stored procedure is created or modified.

  • Hi,

    Can anyone please let me know how to fire trigger when stored procedure is created or modified ?

    I want such a trigger that checks whether a stored procedure follows defined rule or not.

    Where ddl triggers are stored in database ?

    Thanks in Advance.

  • You can do it with DDL trigger. DDL trigger can be created on server level and on database level, but each level has different events that fire the trigger. For example server level ddl trigger can be fired on new database creation, login modification, granting server level permissions etc'. Database level DDL trigger can be fired for table creation, user modification, when procedure that is altered etc'. In your case you can create a database level trigger for procedure creation and procedure modification:

    Create trigger CheckTrigger

    On database

    For create_procedure, alter_procedure

    .

    .

    .

    Adi

    --------------------------------------------------------------
    To know how to ask questions and increase the chances of getting asnwers:
    http://www.sqlservercentral.com/articles/Best+Practices/61537/

    For better answers on performance questions, click on the following...
    http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

  • Here you go mate here is one i created to do exactly what you ask, dont forget to create the log table its in the comments, this SP will log when and a stored proc, tirgger, Index is created, altered or deleted and when a table is altered only. It logs Date, who, etc in the comments there is also a section to deny updates or deletes to the log table :w00t:

    Create trigger SCHEMA_AUDIT on database

    for CREATE_PROCEDURE, ALTER_PROCEDURE, DROP_PROCEDURE,

    CREATE_INDEX , ALTER_INDEX ,DROP_INDEX,

    CREATE_TRIGGER, ALTER_TRIGGER, DROP_TRIGGER,

    ALTER_TABLE

    as

    begin

    set nocount on

    /*

    Ref:

    Name: DDL_TRIGGERS.sql

    Version: 1.0

    Author: Glen Wass

    Date Created:22/05/2012

    Description: create audit table and audit trigger to track stored procedure trigger index creation and changes

    Impact:

    Warnings:

    Version History: DateVersionAuthorComments

    ---------------------------------------------------------------------------

    22/05/2012|1.0| GW | Initial release

    06/08/2012|1.1| GW| addded alter table

    create table VEH_SCHEMA_LOG (id int identity,

    USER_NAME nvarchar(255),

    EVT_TYPE nvarchar (255),

    OBJ_NAME nvarchar(255),

    OBJ_TYPE nvarchar(255),

    CREATE_DTTM datetime)

    --- to stop users from altering the log table

    DENY DELETE, UPDATE, ALTER on VEH_SCHEMA_LOG to [domain\DeptSqlUsers],

    */

    Declare @data xml

    set @data=Eventdata()

    Insert into VEH_SCHEMA_LOG values

    (

    @data.value('(/EVENT_INSTANCE/LoginName)[1]','nvarchar(255)'),

    @data.value('(/EVENT_INSTANCE/EventType)[1]','nvarchar(255)'),

    @data.value('(/EVENT_INSTANCE/ObjectName)[1]','nvarchar(255)'),

    @data.value('(/EVENT_INSTANCE/ObjectType)[1]','nvarchar(255)'),

    getdate()

    )

    set nocount off

    end

    ***The first step is always the hardest *******

  • Thanks a lot.

  • I Modified the trigger to send a mail once it is done. Sadly, it only runs on one database, I wish I could have this in a cursor, So i can apply it to all DB's on my server(s)

    alter trigger SCHEMA_AUDIT on database

    for CREATE_PROCEDURE, ALTER_PROCEDURE, DROP_PROCEDURE,

    CREATE_INDEX , ALTER_INDEX ,DROP_INDEX,

    CREATE_TRIGGER, ALTER_TRIGGER, DROP_TRIGGER,

    CREATE_FUNCTION, ALTER_FUNCTION, DROP_FUNCTION,

    ALTER_TABLE

    as

    begin

    set nocount on

    /*

    Ref:

    Name: DDL_TRIGGERS.sql

    Version: 1.0

    Author: Glen Wass

    Date Created:22/05/2012

    Description: create audit table and audit trigger to track stored procedure trigger index creation and changes

    Impact:

    Warnings:

    Version History: DateVersionAuthorComments

    ---------------------------------------------------------------------------

    22/05/2012|1.0| GW | Initial release

    06/08/2012|1.1| GW| addded alter table

    create table VEH_SCHEMA_LOG (id int identity,

    USER_NAME nvarchar(255),

    EVT_TYPE nvarchar (255),

    OBJ_NAME nvarchar(255),

    OBJ_TYPE nvarchar(255),

    CREATE_DTTM datetime)

    --- to stop users from altering the log table

    DENY DELETE, UPDATE, ALTER on VEH_SCHEMA_LOG to [domain\DeptSqlUsers],

    select * from veh_schema_log

    */

    create table VEH_SCHEMA_LOG (id int identity,

    USER_NAME nvarchar(255),

    EVT_TYPE nvarchar (255),

    OBJ_NAME nvarchar(255),

    OBJ_TYPE nvarchar(255),

    CREATE_DTTM datetime)

    Declare @data xml

    set @data=Eventdata()

    Insert into VEH_SCHEMA_LOG values

    (

    @data.value('(/EVENT_INSTANCE/LoginName)[1]','nvarchar(255)'),

    @data.value('(/EVENT_INSTANCE/EventType)[1]','nvarchar(255)'),

    @data.value('(/EVENT_INSTANCE/ObjectName)[1]','nvarchar(255)'),

    @data.value('(/EVENT_INSTANCE/ObjectType)[1]','nvarchar(255)'),

    getdate()

    )

    set nocount off

    end

    declare @results varchar(max)

    declare @UserName VARCHAR(150)

    declare @HostName VARCHAR(50)

    declare @subjectText varchar(max)

    declare @objectName VARCHAR(255)

    declare @objectType VARCHAR(255)

    declare @eventType VARCHAR(255)

    declare @body VARCHAR(max)

    declare @bodytext VARCHAR(255)

    declare @subject VARCHAR(255)

    SELECT @UserName = SYSTEM_USER, @HostName = HOST_NAME()

    SET @subjectText = 'DDL Modification on ' + @@SERVERNAME + ' by ' + @UserName

    SET @results =

    (SELECT @data.value('(/EVENT_INSTANCE/TSQLCommand/CommandText)[1]','nvarchar(max)'))

    SET @objectName = (SELECT @data.value('(/EVENT_INSTANCE/ObjectName)[1]', 'VARCHAR(255)'))

    SET @objectType = (SELECT @data.value('(/EVENT_INSTANCE/ObjectType)[1]', 'VARCHAR(255)'))

    SET @eventType = (SELECT @data.value('(/EVENT_INSTANCE/EventType)[1]','nvarchar(255)'))

    SET @body = 'User: '+@username+' from '+@hostname+' performed action of type ['+@eventType+'] on ['+@ObjectType+']:['+@objectName+'] at '+CONVERT(VARCHAR(20),GETDATE(),100)

    --Send Mail when the trigger is called

    EXEC msdb.dbo.sp_send_dbmail

    @profile_name = 'SQLMail Profile',

    @recipients = 'me@email.com',

    @body = @body,

    @subject = @subjectText,

    @exclude_query_output = 1 --Suppress 'Mail Queued' message

    GO

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply