Database Creation and Trigger Scripts for Event Log on All databases

USE [master]
GO
/****** Object:  Database [TrackingDB]    Script Date: 1/5/2017 9:24:50 AM ******/
CREATE DATABASE [TrackingDB]
 CONTAINMENT = NONE
 ON  PRIMARY
( NAME = N'TrackingDB', FILENAME = N'D:\TrackingDB_DO NOT DELETE\TrackingDB.mdf' , SIZE = 380928KB , MAXSIZE = UNLIMITED, FILEGROWTH = 1024KB )
 LOG ON
( NAME = N'TrackingDB_log', FILENAME = N'D:\TrackingDB_DO NOT DELETE\TrackingDB_log.ldf' , SIZE = 517184KB , MAXSIZE = UNLIMITED, FILEGROWTH = 10%)
GO
ALTER DATABASE [TrackingDB] SET COMPATIBILITY_LEVEL = 110
GO
IF (1 = FULLTEXTSERVICEPROPERTY('IsFullTextInstalled'))
begin
EXEC [TrackingDB].[dbo].[sp_fulltext_database] @action = 'enable'
end
GO
ALTER DATABASE [TrackingDB] SET ANSI_NULL_DEFAULT OFF
GO
ALTER DATABASE [TrackingDB] SET ANSI_NULLS OFF
GO
ALTER DATABASE [TrackingDB] SET ANSI_PADDING OFF
GO
ALTER DATABASE [TrackingDB] SET ANSI_WARNINGS OFF
GO
ALTER DATABASE [TrackingDB] SET ARITHABORT OFF
GO
ALTER DATABASE [TrackingDB] SET AUTO_CLOSE OFF
GO
ALTER DATABASE [TrackingDB] SET AUTO_CREATE_STATISTICS ON
GO
ALTER DATABASE [TrackingDB] SET AUTO_SHRINK OFF
GO
ALTER DATABASE [TrackingDB] SET AUTO_UPDATE_STATISTICS ON
GO
ALTER DATABASE [TrackingDB] SET CURSOR_CLOSE_ON_COMMIT OFF
GO
ALTER DATABASE [TrackingDB] SET CURSOR_DEFAULT  GLOBAL
GO
ALTER DATABASE [TrackingDB] SET CONCAT_NULL_YIELDS_NULL OFF
GO
ALTER DATABASE [TrackingDB] SET NUMERIC_ROUNDABORT OFF
GO
ALTER DATABASE [TrackingDB] SET QUOTED_IDENTIFIER OFF
GO
ALTER DATABASE [TrackingDB] SET RECURSIVE_TRIGGERS OFF
GO
ALTER DATABASE [TrackingDB] SET  DISABLE_BROKER
GO
ALTER DATABASE [TrackingDB] SET AUTO_UPDATE_STATISTICS_ASYNC OFF
GO
ALTER DATABASE [TrackingDB] SET DATE_CORRELATION_OPTIMIZATION OFF
GO
ALTER DATABASE [TrackingDB] SET TRUSTWORTHY OFF
GO
ALTER DATABASE [TrackingDB] SET ALLOW_SNAPSHOT_ISOLATION OFF
GO
ALTER DATABASE [TrackingDB] SET PARAMETERIZATION SIMPLE
GO
ALTER DATABASE [TrackingDB] SET READ_COMMITTED_SNAPSHOT OFF
GO
ALTER DATABASE [TrackingDB] SET HONOR_BROKER_PRIORITY OFF
GO
ALTER DATABASE [TrackingDB] SET RECOVERY FULL
GO
ALTER DATABASE [TrackingDB] SET  MULTI_USER
GO
ALTER DATABASE [TrackingDB] SET PAGE_VERIFY CHECKSUM
GO
ALTER DATABASE [TrackingDB] SET DB_CHAINING OFF
GO
ALTER DATABASE [TrackingDB] SET FILESTREAM( NON_TRANSACTED_ACCESS = OFF )
GO
ALTER DATABASE [TrackingDB] SET TARGET_RECOVERY_TIME = 0 SECONDS
GO
EXEC sys.sp_db_vardecimal_storage_format N'TrackingDB', N'ON'
GO
/****** Object:  Table [dbo].[DDL_Events_Log]    Script Date: 1/5/2017 9:24:50 AM ******/
USE [TrackingDB]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DDL_Events_Log](
[ID] [bigint] IDENTITY(1,1) NOT NULL,
[EventTime] [datetime] NULL,
[LoginNameIP] [varchar](max) NULL,
[SPID] [int] NULL,
[ServerName] [varchar](max) NULL,
[DatabaseName] [varchar](max) NULL,
[ObjectName] [varchar](max) NULL,
[ObjectType] [varchar](max) NULL,
[Event] [varchar](max) NULL,
[TSQL] [varchar](max) NULL,
 CONSTRAINT [PK_DDL_Events_Log] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
USE [master]
GO
ALTER DATABASE [TrackingDB] SET  READ_WRITE
GO


----******************** Cursor Script For loging events on all Databases

USE [master]
GO

/****** Object:  DdlTrigger [DDL_Event_Log]    Script Date: 1/5/2017 9:22:06 AM ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO







CREATE TRIGGER [DDL_Event_Log]
ON ALL SERVER
WITH EXECUTE AS 'sa'
FOR DDL_DATABASE_LEVEL_EVENTS
AS
DECLARE @data XML
SET @data = EVENTDATA()
SET ANSI_NULLS ON
SET ANSI_PADDING ON
SET ANSI_WARNINGS ON
SET ARITHABORT ON
SET CONCAT_NULL_YIELDS_NULL ON
SET NUMERIC_ROUNDABORT OFF
SET QUOTED_IDENTIFIER ON
INSERT INTO TrackingDB..DDL_Events_Log
   (EventTime, LoginNameIP, SPID, ServerName,DatabaseName, ObjectName,ObjectType,Event, TSQL)
   VALUES
   (GETDATE(),
   (SELECT client_net_address FROM sys.dm_exec_connections WHERE session_id = @@SPID)+'\'+@data.value('(/EVENT_INSTANCE/LoginName)[1]', 'varchar(max)'),
   (@@SPID),
   (@@SERVERNAME),
   @data.value('(/EVENT_INSTANCE/DatabaseName)[1]', 'varchar(max)'),
   @data.value('(/EVENT_INSTANCE/ObjectName)[1]', 'varchar(max)'),
   @data.value('(/EVENT_INSTANCE/ObjectType)[1]', 'varchar(max)'),
   @data.value('(/EVENT_INSTANCE/EventType)[1]', 'varchar(max)'),
   @data.value('(/EVENT_INSTANCE/TSQLCommand)[1]', 'varchar(max)') ) ;







GO

SET ANSI_NULLS OFF
GO

SET QUOTED_IDENTIFIER OFF
GO

ENABLE TRIGGER [DDL_Event_Log] ON ALL SERVER
GO


Comments

Popular posts from this blog

TSQL To Get All the Names of tables and Databases whose data have changed in last 24 Hours

To Get All the Names of tables and Databases their data have changed in last 24 Hours And Backup those databases

Apply paging in procedure