Archive for September, 2009

Auditing DDL Statements for user databases


By creating the below trigger we can keep a track of changes made to any of the tables and its objects by users who is having dbo_access role on databases.

Requirements

·         SQL Server 2005 sqlserver with SP2.

·         Need to create DBA_Admin database on all the production sqlserver to create the EvtLog table which can be used to store the data of all the changes made to any of the sql user databases.

·         Need to create a trigger on all the production database.

 

 

Create the event log table

USE [DBA_Audit]

GO

/****** Object:  Table [dbo].[tblEventLog]    Script Date: 09/17/2009 14:41:52 ******/

SET ANSI_NULLS ON

GO

SET QUOTED_IDENTIFIER ON

GO

SET ANSI_PADDING ON

GO

CREATE TABLE [dbo].[tblEventLog](

      [ID] [int] IDENTITY(1,1) NOT NULL,

      [EventTime] [datetime] NULL,

      [EventType] [varchar](15) NULL,

      [ServerName] [varchar](25) NULL,

      [DatabaseName] [varchar](25) NULL,

      [ObjectType] [varchar](25) NULL,

      [ObjectName] [varchar](25) NULL,

      [UserName] [varchar](15) NULL,

      [CommandText] [varchar](max) NULL

) ON [PRIMARY]

 

GO

SET ANSI_PADDING OFF

 

 

 

 

 

Create the DDL trigger

CREATE TRIGGER [trg_DDLChange_LOG] ON DATABASE — Create Database DDL Trigger

 

FOR DDL_DATABASE_LEVEL_EVENTS–CREATE_TABLE — Trigger will raise when creating a Table

 

AS

 

SET NOCOUNT ON

 

DECLARE @xmlEventData XML

 

 

— Capture the event data that is created

 

SET @xmlEventData = eventdata()

 

 

— Insert information to a EventLog table

 

INSERT INTO INLTE6531.DBA_Audit.dbo.tblEventLog

(

EventTime,

EventType,

ServerName,

DatabaseName,

ObjectType,

ObjectName,

UserName,

CommandText

)

 

SELECT REPLACE(CONVERT(VARCHAR(50), @xmlEventData.query('data(/EVENT_INSTANCE/PostTime)')),

 

'T', ' '),

 

CONVERT(VARCHAR(15), @xmlEventData.query('data(/EVENT_INSTANCE/EventType)')),

 

CONVERT(VARCHAR(25), @xmlEventData.query('data(/EVENT_INSTANCE/ServerName)')),

 

CONVERT(VARCHAR(25), @xmlEventData.query('data(/EVENT_INSTANCE/DatabaseName)')),

 

CONVERT(VARCHAR(25), @xmlEventData.query('data(/EVENT_INSTANCE/ObjectType)')),

 

CONVERT(VARCHAR(25), @xmlEventData.query('data(/EVENT_INSTANCE/ObjectName)')),

 

CONVERT(VARCHAR(15), @xmlEventData.query('data(/EVENT_INSTANCE/UserName)')),

 

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

 

GO

 

 


Moving the master and Resource Databases

The Resource database depends on the location of the master database. The Resource data and log files must reside together and must be in the same location as the master data file (master.mdf). Therefore, if you move the master database, you must also move the Resource database to the same location as the master data file. Do not put the Resource database in either compressed or encrypted NTFS file system folders. Doing so will hinder performance and prevent upgrades.

To move the master and Resource databases, follow these steps.

1.       Open Sqlserver Management Studio, Click on New Query and notedown the properties of master database. Please do not close this window until you finish the activity.

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID('master')

2.       From the Start menu, point to All Programs, point to Microsoft SQL Server 2005, point to Configuration Tools, and then click SQL Server Configuration Manager.

3.       In the SQL Server 2005 Services node, right-click the instance of SQL Server (for example, SQL Server (MSSQLSERVER)) and choose Properties.

4.       In the SQL Server (instance_name) Properties dialog box, click the Advanced tab.

5.       Edit the Startup Parameters values to point to the planned location for the master database data and log files, and click OK. Moving the error log file is optional.
The parameter value for the data file must follow the 
-d parameter and the value for the log file must follow the -l parameter. The following example shows the parameter values for the default location of the master data and log files.

-dC:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\DATA\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\LOG\ERRORLOG;-lC:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\DATA\mastlog.ldf

If the planned relocation for the master data and log files is E:\SQLData, the parameter values would be changed as follows:

 -dE:\SQLData\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\LOG\ERRORLOG;-lE:\SQLData\mastlog.ldf

6.       Stop the instance of SQL Server by right-clicking the instance name and choosing Stop.

7.       Move the master.mdf and mastlog.ldf files to the new location.

8.       Start the instance of SQL Server in master-only recovery mode(Single user mode) by entering one of the following commands at the command prompt. The parameters specified in these commands are case sensitive. The commands fail when the parameters are not specified as shown.

 

9.      

Open command prompt and type the below commands.
 

 

 

 

 

 

 

 

 

1.       For the default (MSSQLSERVER) instance, run the following command.

 NET START MSSQLSERVER /f /T3608

2.       For a named instance, run the following command.

 NET START MSSQL$instancename /f /T3608

10.   Using sqlcmd commands or SQL Server Management Studio, run the following statements. Change the FILENAME path to match the new location of the master data file. Do not change the name of the database or the file names.

 ALTER DATABASE mssqlsystemresource 
    MODIFY FILE (NAME=data, FILENAME= 'D:\SqlData\mssqlsystemresource.mdf');
GO
 ALTER DATABASE mssqlsystemresource 
    MODIFY FILE (NAME=log, FILENAME= ' D:\SqlData\mssqlsystemresource.ldf');

11.   Open command prompt and type the below command to stop sqlserver

 NET STOP MSSQLSERVER

12.   Move the mssqlsystemresource.mdf and mssqlsystemresource.ldf files to the new location.

13.   Start the sqlserver again in single user mode once you finished moving the files.

14.   Open command prompt and type the below command to start sqlserver in single user mode

 NET START MSSQLSERVER /f /T3608

15.   Set the Resource database to read-only by running the following statement in SSMS.

 ALTER DATABASE mssqlsystemresource SET READ_ONLY;

16.   Exit the sqlcmd utility or SQL Server Management Studio.

17.   Stop the instance of SQL Server.

18.   Restart the instance of SQL Server.

19.   Verify the file change for the master database by running the following query. The Resource database metadata cannot be viewed by using the system catalog views or system tables.

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID('master')
  

 

 

 

 

 

 

 

Procedure to Move TEMPDB database

 

The following example moves the tempdb data and log files to a new location as part of a planned relocation.

 

1.       Determine the logical file names of the tempdb 

database and their current location on the disk.

 

 

 

 

 

 

 

 

 

 

 SELECT name, physical_name AS CurrentLocation
FROM sys.master_files
WHERE database_id = DB_ID(N'tempdb');
 GO

Change the location of each file by using ALTER DATABASE

.
 

 

 

 

 

 

 

 

 

 USE master;
GO
ALTER DATABASE tempdb 
 MODIFY FILE (NAME = tempdev, FILENAME = 'E:\SQLData\tempdb.mdf');
 GO
ALTER DATABASE tempdb 
MODIFY FILE (NAME = templog, FILENAME = 'F:\SQLLog\templog.ldf');
GO

2.       Stop and restart the instance of SQL Server. 

3.      

Verify the file change.
 

 

 

 

 

 

 

 

 

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'tempdb');

4.       Delete the tempdb.mdf and templog.ldf files from the original location.

 

 

 

 

 

 

 

Procedure to Move  MSDB database

 

The following example moves the msdb data and log files to a new location as part of a planned relocation.

 

5.       Determine the logical file names of the msdb 

database and their current location on the disk.

 

 

 

 

 

 

 

 

 

 

 SELECT name, physical_name AS CurrentLocation
FROM sys.master_files
WHERE database_id = DB_ID(N'MSDB');
 GO

Change the location of each file by using ALTER DATABASE

.
 

 

 

 

 

 

 

 

 

 USE master;
GO
ALTER DATABASE msdb 
 MODIFY FILE (NAME = MSDBData, FILENAME = 'D:\SQLData\MSDBData.mdf');
 GO
ALTER DATABASE MSDB
MODIFY FILE (NAME = MSDBLog, FILENAME = 'D:\SQLLog\MSDBLog.ldf');
GO

6.       Stop and restart the instance of SQL Server. 

7.       Open command prompt and type the below command to stop sqlserver

 NET STOP MSSQLSERVER

8.       Move the MSDBData.mdf and MSDBlog.ldf files to the new location.

9.       Open command prompt and type the below command to start sqlserver in single user mode

 NET START MSSQLSERVER /f /T3608

10.   Verify the file change.

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'msdb');
  1. Restart the sqlserver in normal mode.

OR

  1. GoTo  STEP- 9
  2. Detach the msdb database after executing the STEP- 9
SP_DETACH_DB 'MSDB'
  1.  Follow Step-8
  2. Attach the msdb database once you move the files (.mdf and .ldf) to new location.
SP_ATTACH_DB 'MSDB''D:\DATA\MSDBDATA.MDF','D:\DATA\MSDBLOG.LDF'

16.   Open command prompt and type the below command to start sqlserver in single user mode

 NET START MSSQLSERVER /f /T3608

17.   Verify the file change.

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'msdb');
  1. Restart the sqlserver in normal mode.

 

 

 

 

 

 

 

 

 

 

 

 

 

 

Procedure to Move  Model database

 

The following example moves the model data and log files to a new location as part of a planned relocation.

 

1. Determine the logical file names of the model 

database and their current location on the disk.

 

 

 

 

 

 

 

 

 

 

 SELECT name, physical_name AS CurrentLocation
FROM sys.master_files
WHERE database_id = DB_ID(N'Model');
 GO

Change the location of each file by using ALTER DATABASE

.
 

 

 

 

 

 

 

 

 

 USE master;
GO
ALTER DATABASE Model 
 MODIFY FILE (NAME = ModelDev, FILENAME = 'D:\SQLData\Model.mdf');
 GO
ALTER DATABASE Model
MODIFY FILE (NAME = ModelLog, FILENAME = 'D:\SQLLog\ModelLog.ldf');
GO

2.       Stop and restart the instance of SQL Server. 

3.       Open command prompt and type the below command to stop sqlserver

 NET STOP MSSQLSERVER

4.       Move the Model.mdf and Modellog.ldf files to the new location.

5.       Open command prompt and type the below command to start sqlserver in single user mode

 NET START MSSQLSERVER /f /T3608

6.       Verify the file change.

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'model');
  1. Restart the sqlserver in normal mode.

OR

  1. GoTo  STEP- 9
  2. Detach the msdb database after executing the STEP- 9
SP_DETACH_DB 'Model'
  1.  Follow Step-8
  2. Attach the msdb database once you move the files (.mdf and .ldf) to new location.
SP_ATTACH_DB 'MODEL','C:\SQLData\MODEL.MDF','C:\SQLData\MODELLOG.LDF'

12.   Open command prompt and type the below command to start sqlserver in single user mode

 NET START MSSQLSERVER /f /T3608

13.   Verify the file change.

 SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'Model');

Restart the sqlserver in normal mode.