Aklımda Kalası Kelimeler

* давайте работать вместе
* Zarf ve Mazruf, Zerafet(xHoyratlık) ile aynı kökten(za-ra-fe) gelir
* Bedesten
* Suç subuta ermiştir - Suç sabit olmuştur

20 Kasım 2012 Salı

Database içindeki tüm tablolar için LOG tablosuna değişimleri kaydetmek için Veritabanı seviyesinde(TRIGGER temelli) LOGLAMA

Log Tablosu
USE [ZapaZupaVeritabani]
GO

/****** Object:  Table [dbo].[Loglar]    Script Date: 11/20/2012 21:22:07 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

SET ANSI_PADDING ON
GO

CREATE TABLE [dbo].[Loglar](
 [log_id] [int] IDENTITY(1,1) NOT NULL,
 [logTarih] [datetime] NULL,
 [logIslem] [tinyint] NULL,
 [trgKullanici_id] [varchar](50) NULL,
 [tabloAdi] [varchar](250) NULL,
 [logXml] [xml] NULL,
 CONSTRAINT [PK_Logla] PRIMARY KEY CLUSTERED 
(
 [log_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]

GO

SET ANSI_PADDING OFF
GO

EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'1: INSERT, 2: UPDATE, 3: DELETE' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Loglar', @level2type=N'COLUMN',@level2name=N'logIslem'
GO

ALTER TABLE [dbo].[Loglar] ADD  CONSTRAINT [DF_Logla_tarih]  DEFAULT (getdate()) FOR [logTarih]
GO

ALTER TABLE [dbo].[Loglar] ADD  CONSTRAINT [DF_Loglar_logIslem]  DEFAULT ((1)) FOR [logIslem]
GO

Her tablo için INSERT, UPDATE, DELETE tetikleyicisini otomatik oluşturma
USE medula_V3
DECLARE @sInsert AS NVARCHAR(MAX)
DECLARE @sUpdate AS NVARCHAR(MAX)
DECLARE @sDelete AS NVARCHAR(MAX)
DECLARE @trigName AS NVARCHAR(200)
DECLARE @tableName AS NVARCHAR(200)

DECLARE crTabloAdlari CURSOR FOR
SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES 
OPEN crTabloAdlari
FETCH NEXT FROM crTabloAdlari INTO @tableName
 
WHILE @@Fetch_Status = 0
BEGIN
print @tableName + ' -  '+CAST(CHARINDEX('Log',@tableName) AS VARCHAR(20))

 IF CHARINDEX('Log',@tableName)= 0 AND CHARINDEX('sys',@tableName)= 0 
 BEGIN

  SET @sInsert = 'CREATE TRIGGER [dbo].[Insert'+@tableName+']   ON  dbo.'+@tableName+'   AFTER INSERT AS BEGIN DECLARE @logIslem TINYINT SET @logIslem = 1 SET NOCOUNT ON DECLARE @tableName VARCHAR(200) SELECT @tableName = OBJECT_SCHEMA_NAME( parent_id ) + ''.'' + OBJECT_NAME( parent_id ) FROM sys.triggers WHERE object_id = @@PROCID DECLARE @after AS XML  SET @after = ''<''+@tableName+''>''+ (select * from inserted for xml AUTO,ELEMENTS XSINIL)+''''   INSERT INTO [dbo].[Loglar]           ([logIslem]  ,[trgKullanici_id]  ,[tabloAdi]  ,[logXml])     VALUES           (@logIslem  ,SUSER_NAME()  ,@tableName  ,@after) END'
  SET @sUpdate = 'CREATE TRIGGER [dbo].[Update'+@tableName+']   ON  dbo.'+@tableName+'   AFTER UPDATE AS BEGIN DECLARE @logIslem TINYINT SET @logIslem = 2 SET NOCOUNT ON DECLARE @tableName VARCHAR(200) SELECT @tableName = OBJECT_SCHEMA_NAME( parent_id ) + ''.'' + OBJECT_NAME( parent_id ) FROM sys.triggers WHERE object_id = @@PROCID  DECLARE @allXml AS XML SET @allXml = ''<''+@tableName+''>''+ (select * from deleted for xml AUTO, ELEMENTS XSINIL)  + (select * from inserted for xml AUTO,ELEMENTS XSINIL) +''''  INSERT INTO [dbo].[Loglar]           ([logIslem]  ,[trgKullanici_id]  ,[tabloAdi]  ,[logXml]) VALUES (@logIslem  ,SUSER_NAME()  ,@tableName  ,@allXml) END'
  SET @sDelete = 'CREATE TRIGGER [dbo].[Deleted'+@tableName+']   ON  dbo.'+@tableName+'   AFTER DELETE AS BEGIN DECLARE @logIslem TINYINT SET @logIslem = 3 SET NOCOUNT ON DECLARE @tableName VARCHAR(200) SELECT @tableName = OBJECT_SCHEMA_NAME( parent_id ) + ''.'' + OBJECT_NAME( parent_id ) FROM sys.triggers WHERE object_id = @@PROCID  DECLARE @allXml AS XML SET @allXml = ''<''+@tableName+''>''+ (select * from deleted for xml AUTO, ELEMENTS XSINIL)  +''''  INSERT INTO [dbo].[Loglar]           ([logIslem]  ,[trgKullanici_id]  ,[tabloAdi]  ,[logXml])     VALUES           (@logIslem  ,SUSER_NAME()  ,@tableName  ,@allXml)END'

  print @sInsert
  exec  sp_executesql @sInsert
  print @sUpdate
  exec  sp_executesql @sUpdate
  print @sDelete
  exec  sp_executesql @sDelete
 END
FETCH NEXT FROM crTabloAdlari INTO @tableName
END
 
CLOSE crTabloAdlari
DEALLOCATE crTabloAdlari
GO