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


Monitoring and Recording DDL changes on SQL 2005 (NARC)


Monitoring and Recording DDL changes on SQL 2005 (NARC)

Author
Message
James Greaves
James Greaves
Old Hand
Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)

Group: General Forum Members
Points: 326 Visits: 460
"The attached SQL to this article contains the extended meta data for the views and is not shown in the code below."

When I scripted out the views for this article from SQL 2005 there was extended meta data with the actual view T-SQL code that I did not include with the original article. This meta data is not required for the views for the code to work.



James Greaves
James Greaves
Old Hand
Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)

Group: General Forum Members
Points: 326 Visits: 460
pkenny (2/29/2008)
What is unique about server 2005? Can't this be done with previous versions of SQL. Nice solution BTW! Presumably the new database is secured in some way eg. you are the DBO?
Peter.


DDL triggers is a 2005 option only. The new database is secured in a way so that only administrators (sa) would have access. Since that is usually not enough, one could put a trigger on tables that hold the information that would have a contraint that would only allow you to delete if you were logged in with your domain name.

e.g.

IF suser_sname() = 'yourdomain\username'
BEGIN

End
ELSE

ROLLBACK TRAN
END

Something like that would be fun to catch those trying to hide the audit trail.



James Greaves
James Greaves
Old Hand
Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)

Group: General Forum Members
Points: 326 Visits: 460
The attached code is not required and was only meta data from the scripted 2005 SQL view.



pkenny
pkenny
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 22
Thanks very much for your reply!
Peter.
geno wald
geno wald
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 94
This appears to be pretty much what I would want, except that I would like to be able to capture the machine name associated with the user who is making the connection. When I view the Activity Monitor in SSMS under the Management node, I can see the client computer name identified as "Host", but it is not clear how I can access that value from the trigger.

The reason this would be helpful is that there might be several people who share access to an account. Using the client computer name to distinguish where the login came from would help identify the person making those ddl changes.
James Greaves
James Greaves
Old Hand
Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)

Group: General Forum Members
Points: 326 Visits: 460
geno wald (4/3/2008)
This appears to be pretty much what I would want, except that I would like to be able to capture the machine name associated with the user who is making the connection. When I view the Activity Monitor in SSMS under the Management node, I can see the client computer name identified as "Host", but it is not clear how I can access that value from the trigger.

The reason this would be helpful is that there might be several people who share access to an account. Using the client computer name to distinguish where the login came from would help identify the person making those ddl changes.


Within the database and/or server trigger you may create another variable to capture the hostname and any other information you would like from the sys.sysprocesses table.

e.g.

DELCARE @hostnm VARCHAR(50)

SELECT @hostnm = hostname
FROM sys.sysprocesses
WHERE loginame = suser_sname()
and cmd <> 'awaiting command'

You would then alter the tables hosting the information to add a column for host name. Finally, you may also want to capture the "net_address" column within the sys.sysprocesses table to get the MAC address of the network card as well as the hostname.



mstjean
mstjean
Mr or Mrs. 500
Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)Mr or Mrs. 500 (561 reputation)

Group: General Forum Members
Points: 561 Visits: 2546
I have a user (developer) that tried to alter a view in a db. He does not have rights to the db ("Admin") I write the 2 tables to. He DOES have rights to do what he was doing.

Granting him even write rights to the 2 audit tables seems counter intuitive; I thought the db and server triggers should execute in another security context... maybe this is my incorrect assumption. I don't want to turn on cross db ownership chaining-- that would expose me to a different set of risks when I am trying to ratchet those down.

His Error:
Msg 916, Level 14, State 1, Procedure trgMonitorChange, Line 33
The server principal "the users domain name" is not able to access the database "Admin" under the current security context

Any thoughts/recommendations?


Cursors are useful if you don't know SQL
@fracionero
@fracionero
SSC Veteran
SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)SSC Veteran (275 reputation)

Group: General Forum Members
Points: 275 Visits: 361
Hi all,

Nice article.

I'm working in a similar trigger but I'm recording information in a table in a Linked server for consolidation issues, because I have several instances and several server and I need to collect all information in only a database, but when I try to the insert command, I only get a set of errors. I've checked previously the trigger in the local server and runs ok, but the fails appear when I try to execute from a remote server.

My insert command:

INSERT INTO [SRSQL1001\MANAGEMENT].[DBA_AUDIT].[dbo].[ENV_SRV_INS_DB_CHG]
([ENV_SRV_INS_DB_CHG_Server]
,[ENV_SRV_INS_DB_CHG_Name]
,[ENV_SRV_INS_DB_CHG_EventType]
,[ENV_SRV_INS_DB_CHG_PostTime]
,[ENV_SRV_INS_DB_CHG_Login]
,[ENV_SRV_INS_DB_CHG_TSQLCommand]
,[ENV_SRV_INS_DB_CHG_Completed])
values(@ServerName,@DBName,@EventType,@PostTime,@login,@TSQLCommand,@comp)

errors set

Msg 3984, Level 16, State 1, Line 1
Cannot acquire a database lock during a transaction change.
Msg 3985, Level 16, State 2, Line 1
An error occurred during the changing of transaction context. This is usually caused by low memory in the system. Try to free up more memory.
Msg 3984, Level 16, State 1, Line 1
Cannot acquire a database lock during a transaction change.
Msg 3985, Level 16, State 1, Line 1
An error occurred during the changing of transaction context. This is usually caused by low memory in the system. Try to free up more memory.


I have checked if I delete insert command database is created without errors.

Thanks in advance for your help

F.Racionero

Francisco Racionero
twitter: @fracionero
James Greaves
James Greaves
Old Hand
Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)Old Hand (326 reputation)

Group: General Forum Members
Points: 326 Visits: 460
mstjean (5/5/2008)
I have a user (developer) that tried to alter a view in a db. He does not have rights to the db ("Admin") I write the 2 tables to. He DOES have rights to do what he was doing.

Granting him even write rights to the 2 audit tables seems counter intuitive; I thought the db and server triggers should execute in another security context... maybe this is my incorrect assumption. I don't want to turn on cross db ownership chaining-- that would expose me to a different set of risks when I am trying to ratchet those down.

His Error:
Msg 916, Level 14, State 1, Procedure trgMonitorChange, Line 33
The server principal "the users domain name" is not able to access the database "Admin" under the current security context

Any thoughts/recommendations?


Perhaps I should have put something in my article regarding my intention for these triggers as I originally put them on production servers that had limited access. The database and server triggers will run in the security context of the individual account that is triggered by the DDL change. Therefore when the trigger goes off and wants to write the data to a separate database, that user requires write permission to the destination table.

In your case you have the following options:

1. Change the database trigger to point to an auditing table within the local database instead of a separate database and give that local auditing table write permissions to the developer.
2. Give the developer write permissions on the table that is in the auditing database. This may not be effective if you have more than one account making changes to your database.



Kenneth Younger
Kenneth Younger
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 29
Remember, though, that these database triggers will not catch changes from using sp_rename.
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