SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


DDL Trigger to Track All Database Changes? Permissions


DDL Trigger to Track All Database Changes? Permissions

Author
Message
azenon
azenon
SSC Eights!
SSC Eights! (956 reputation)SSC Eights! (956 reputation)SSC Eights! (956 reputation)SSC Eights! (956 reputation)SSC Eights! (956 reputation)SSC Eights! (956 reputation)SSC Eights! (956 reputation)SSC Eights! (956 reputation)

Group: General Forum Members
Points: 956 Visits: 301
Looking to implement the server level trigger below to track all DDL changes in the instance. How do I get the trigger to insert in the DBAudit db table for any user without giving each user access to the DBAudit database?


ALTER TRIGGER [SchemaChange_LogInTable_DDL]

ON ALL SERVER

FOR CREATE_PROCEDURE, ALTER_PROCEDURE, DROP_PROCEDURE, CREATE_FUNCTION, ALTER_FUNCTION, DROP_FUNCTION, CREATE_TRIGGER, ALTER_TRIGGER, DROP_TRIGGER

--Fires only for CREATE / ALTER / DROP on Store Procedures Functions Triggers

AS
DECLARE @eventInfo XML

SET @eventInfo = EVENTDATA()


INSERT INTO DBAudit.dbo.DBSchema_Change_Log VALUES

(


REPLACE(CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/PostTime)')),'T', ' '),

CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/LoginName)')),

CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/UserName)')),

CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/DatabaseName)')),

CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/SchemaName)')),

CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/ObjectName)')),
CONVERT(VARCHAR(50),@eventInfo.query('data(/EVENT_INSTANCE/ObjectType)')),

CONVERT(VARCHAR(MAX),@eventInfo.query('data(/EVENT_INSTANCE/TSQLCommand/CommandText)'))

)


GO
Database admin(DBA)
Database admin(DBA)
SSCarpal Tunnel
SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)

Group: General Forum Members
Points: 4716 Visits: 2092
Hi,

Is it implemented? If yes please let me know even i'm looking for same kind of request..

Thanks in advance!!

Best Regards,

SQL server DBA
Steve Jones
Steve Jones
SSC Guru
SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)

Group: Administrators
Points: 609517 Visits: 21159
 GRANT INSERT ON dbo.DBSchema_Change_Log  TO PUBLIC
GRANT CONNECT TO guest


This is the easiest way. I am , in general, not a fan of granting rights to public, but in this case, this is probably OK. I enable guest, and then anyone maps over to guest and data is inserted.


Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
Phil Parkin
Phil Parkin
SSC Guru
SSC Guru (217K reputation)SSC Guru (217K reputation)SSC Guru (217K reputation)SSC Guru (217K reputation)SSC Guru (217K reputation)SSC Guru (217K reputation)SSC Guru (217K reputation)SSC Guru (217K reputation)

Group: General Forum Members
Points: 217052 Visits: 24909
Steve Jones - SSC Editor - Monday, January 22, 2018 9:38 AM
 GRANT INSERT ON dbo.DBSchema_Change_Log  TO PUBLIC
GRANT CONNECT TO guest


This is the easiest way. I am , in general, not a fan of granting rights to public, but in this case, this is probably OK. I enable guest, and then anyone maps over to guest and data is inserted.

Hi Steve. This article suggests that SELECT is required, in additional to INSERT, on the log table. Can't see why, though.



Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
Steve Jones
Steve Jones
SSC Guru
SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)

Group: Administrators
Points: 609517 Visits: 21159
Didn't need it in my testing. Just INSERT and I could have a normal user insert via DDL trigger.

Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
Steve Jones
Steve Jones
SSC Guru
SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)SSC Guru (609K reputation)

Group: Administrators
Points: 609517 Visits: 21159
I suspect Aaron used that in testing. For audits, I typically wouldn't have normal users able to read the audit records. INSERT only, with SELECT given to admins/security staff.

Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85508 Visits: 9624
My (strong) preference is instead to use EXECUTE AS on the CREATE TRIGGER:

ALTER TRIGGER [SchemaChange_LogInTable_DDL]
ON ALL SERVER
WITH EXECUTE AS 'big_cheese_login'
FOR ...
...

SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search