|
| 1 | +CREATE PROCEDURE [dbo].[RowLevelAuditAdd] |
| 2 | + @DatabaseName NVARCHAR(50) = NULL |
| 3 | + , @SchemaName NVARCHAR(50) = NULL |
| 4 | + , @TableName NVARCHAR(50) = NULL |
| 5 | +AS |
| 6 | +BEGIN |
| 7 | + |
| 8 | +/* |
| 9 | +'-------------------------------------------------------------------------------------------------------------------- |
| 10 | +' Purpose: Adds row level auditing columns to a table |
| 11 | +' Example: EXEC dbo.RowLevelAuditAdd 'YourDatabase', 'dbo', 'ORGN'; |
| 12 | +' Note: The table must have a primary key to create the update trigger |
| 13 | +'-------------------------------------------------------------------------------------------------------------------- |
| 14 | +
|
| 15 | + ----------------------------------------------------- |
| 16 | + -->>>>>>>>>>>>>>>>> FOR DEBUGGING <<<<<<<<<<<<<<<<<<< |
| 17 | + ----------------------------------------------------- |
| 18 | + BEGIN |
| 19 | + DECLARE @DatabaseName NVARCHAR(50) |
| 20 | + DECLARE @SchemaName NVARCHAR(50) |
| 21 | + DECLARE @TableName NVARCHAR(50) |
| 22 | + SET @DatabaseName = 'YourDatabase' |
| 23 | + SET @SchemaName = 'dbo' |
| 24 | + SET @TableName = 'ORGN' |
| 25 | + ----------------------------------------------------- |
| 26 | + ----------------------------------------------------- |
| 27 | +
|
| 28 | +*/ |
| 29 | + |
| 30 | + SET XACT_ABORT ON |
| 31 | + BEGIN TRANSACTION; |
| 32 | + SET NOCOUNT ON |
| 33 | + |
| 34 | + DECLARE @SqlCommand NVARCHAR(1000) |
| 35 | + DECLARE @TableKey NVARCHAR(1000) |
| 36 | + DECLARE @UserName NVARCHAR(50) |
| 37 | + DECLARE @CreatedId NVARCHAR(50) |
| 38 | + DECLARE @CreatedDate NVARCHAR(50) |
| 39 | + DECLARE @ModifiedId NVARCHAR(50) |
| 40 | + DECLARE @ModifiedDate NVARCHAR(50) |
| 41 | + DECLARE @TodayDate NVARCHAR(50) |
| 42 | + |
| 43 | + SET @CreatedId = 'CreatedId' |
| 44 | + SET @CreatedDate = 'CreatedDate' |
| 45 | + SET @ModifiedId = 'ModifiedId' |
| 46 | + SET @ModifiedDate = 'ModifiedDate' |
| 47 | + SET @UserName = LOWER(LEFT(RIGHT(SYSTEM_USER,(LEN(SYSTEM_USER)-CHARINDEX('\',SYSTEM_USER))), 50)) |
| 48 | + SET @TodayDate = FORMAT(GETDATE(), 'dd-MMM-yyyy HH:mm:ss', 'en-US' ) |
| 49 | + |
| 50 | + PRINT '====================================================================='; |
| 51 | + PRINT 'START - ALTER [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + ']... '; |
| 52 | + |
| 53 | + IF COL_LENGTH(@DatabaseName + '.' + @SchemaName + '.' + @TableName, @CreatedId) IS NULL |
| 54 | + BEGIN |
| 55 | + |
| 56 | + PRINT '====================================================================='; |
| 57 | + PRINT 'START - ADD COLUMN [' + @CreatedId + ']... '; |
| 58 | + |
| 59 | + PRINT '1. alter table add ' + @CreatedId + ' column... '; |
| 60 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD [' + @CreatedId + '] [NVARCHAR](50) NULL' |
| 61 | + EXEC (@SqlCommand) |
| 62 | + |
| 63 | + PRINT '2. update new column to a value... ' + @UserName; |
| 64 | + SET @SqlCommand = 'UPDATE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] SET [' + @CreatedId + '] =''' + @UserName + ''' WHERE [' + @CreatedId + '] IS NULL' |
| 65 | + EXEC (@SqlCommand) |
| 66 | + |
| 67 | + PRINT '3. alter table alter new column add constraints... '; |
| 68 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ALTER COLUMN [' + @CreatedId + '] [NVARCHAR](50) NOT NULL' |
| 69 | + EXEC (@SqlCommand) |
| 70 | + |
| 71 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD CONSTRAINT [DF_' + @TableName + '_' + @CreatedId + '] DEFAULT (LOWER(LEFT(RIGHT(SYSTEM_USER,(LEN(SYSTEM_USER)-CHARINDEX(''\'',SYSTEM_USER))), 50))) FOR [' + @CreatedId + ']' |
| 72 | + EXEC (@SqlCommand) |
| 73 | + |
| 74 | + PRINT '4. add column description... '; |
| 75 | + EXEC [sys].sp_addextendedproperty @name=N'MS_Description', @value=N'Who created the record' , @level0type=N'SCHEMA',@level0name=@SchemaName, @level1type=N'TABLE',@level1name=@TableName, @level2type=N'COLUMN',@level2name=@CreatedId; |
| 76 | + |
| 77 | + PRINT 'END - ADD COLUMN [' + @CreatedId + ']... '; |
| 78 | + PRINT '====================================================================='; |
| 79 | + END |
| 80 | + |
| 81 | + IF COL_LENGTH(@DatabaseName + '.' + @SchemaName + '.' + @TableName, @CreatedDate) IS NULL |
| 82 | + BEGIN |
| 83 | + |
| 84 | + PRINT '====================================================================='; |
| 85 | + PRINT 'START - ADD COLUMN [' + @CreatedDate + ']... '; |
| 86 | + |
| 87 | + PRINT '1. alter table add ' + @CreatedDate + ' column... '; |
| 88 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD [' + @CreatedDate + '] [DATETIME] NULL' |
| 89 | + EXEC (@SqlCommand) |
| 90 | + |
| 91 | + PRINT '2. update new column to a value... ' + @TodayDate; |
| 92 | + SET @SqlCommand = 'UPDATE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] SET [' + @CreatedDate + '] = ''' + @TodayDate+ ''' WHERE [' + @CreatedDate + '] IS NULL' |
| 93 | + EXEC (@SqlCommand) |
| 94 | + |
| 95 | + PRINT '3. alter table alter new column add constraints... '; |
| 96 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ALTER COLUMN [' + @CreatedDate + '] [DATETIME] NOT NULL' |
| 97 | + EXEC (@SqlCommand) |
| 98 | + |
| 99 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD CONSTRAINT [DF_' + @TableName + '_' + @CreatedDate + '] DEFAULT (GETDATE()) FOR [' + @CreatedDate + ']' |
| 100 | + EXEC (@SqlCommand) |
| 101 | + |
| 102 | + PRINT '4. add column description... '; |
| 103 | + EXEC [sys].sp_addextendedproperty @name=N'MS_Description', @value=N'The date and time the record was created' , @level0type=N'SCHEMA',@level0name=@SchemaName, @level1type=N'TABLE',@level1name=@TableName, @level2type=N'COLUMN',@level2name=@CreatedDate; |
| 104 | + |
| 105 | + PRINT 'END - ADD COLUMN [' + @CreatedDate + ']... '; |
| 106 | + PRINT '====================================================================='; |
| 107 | + END |
| 108 | + |
| 109 | + IF COL_LENGTH(@DatabaseName + '.' + @SchemaName + '.' + @TableName, @ModifiedId) IS NULL |
| 110 | + BEGIN |
| 111 | + |
| 112 | + PRINT '====================================================================='; |
| 113 | + PRINT 'START - ADD COLUMN [' + @ModifiedId + ']... '; |
| 114 | + |
| 115 | + PRINT '1. alter table add ' + @ModifiedId + ' column... '; |
| 116 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD [' + @ModifiedId + '] [NVARCHAR](50) NULL' |
| 117 | + EXEC (@SqlCommand) |
| 118 | + |
| 119 | + PRINT '2. update new column to a value... ' + @UserName; |
| 120 | + SET @SqlCommand = 'UPDATE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] SET [' + @ModifiedId + '] =''' + @UserName + ''' WHERE [' + @ModifiedId + '] IS NULL' |
| 121 | + EXEC (@SqlCommand) |
| 122 | + |
| 123 | + PRINT '3. alter table alter new column add constraints... '; |
| 124 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ALTER COLUMN [' + @ModifiedId + '] [NVARCHAR](50) NOT NULL' |
| 125 | + EXEC (@SqlCommand) |
| 126 | + |
| 127 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD CONSTRAINT [DF_' + @TableName + '_' + @ModifiedId + '] DEFAULT (LOWER(LEFT(RIGHT(SYSTEM_USER,(LEN(SYSTEM_USER)-CHARINDEX(''\'',SYSTEM_USER))), 50))) FOR [' + @ModifiedId + ']' |
| 128 | + EXEC (@SqlCommand) |
| 129 | + |
| 130 | + PRINT '4. add column description... '; |
| 131 | + EXEC [sys].sp_addextendedproperty @name=N'MS_Description', @value=N'Who modified the record' , @level0type=N'SCHEMA',@level0name=@SchemaName, @level1type=N'TABLE',@level1name=@TableName, @level2type=N'COLUMN',@level2name=@ModifiedId; |
| 132 | + |
| 133 | + PRINT 'END - ADD COLUMN [' + @ModifiedId + ']... '; |
| 134 | + PRINT '====================================================================='; |
| 135 | + END |
| 136 | + |
| 137 | + IF COL_LENGTH(@DatabaseName + '.' + @SchemaName + '.' + @TableName, @ModifiedDate) IS NULL |
| 138 | + BEGIN |
| 139 | + |
| 140 | + PRINT '====================================================================='; |
| 141 | + PRINT 'START - ADD COLUMN [' + @ModifiedDate + ']... '; |
| 142 | + |
| 143 | + PRINT '1. alter table add ' + @ModifiedDate + ' column... '; |
| 144 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD [' + @ModifiedDate + '] [DATETIME] NULL' |
| 145 | + EXEC (@SqlCommand) |
| 146 | + |
| 147 | + PRINT '2. update new column to a value... ' + @TodayDate; |
| 148 | + SET @SqlCommand = 'UPDATE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] SET [' + @ModifiedDate + '] = ''' + @TodayDate+ ''' WHERE [' + @ModifiedDate + '] IS NULL' |
| 149 | + EXEC (@SqlCommand) |
| 150 | + |
| 151 | + PRINT '3. alter table alter new column add constraints... '; |
| 152 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ALTER COLUMN [' + @ModifiedDate + '] [DATETIME] NOT NULL' |
| 153 | + EXEC (@SqlCommand) |
| 154 | + |
| 155 | + SET @SqlCommand = 'ALTER TABLE [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + '] ADD CONSTRAINT [DF_' + @TableName + '_' + @ModifiedDate + '] DEFAULT (GETDATE()) FOR [' + @ModifiedDate + ']' |
| 156 | + EXEC (@SqlCommand) |
| 157 | + |
| 158 | + PRINT '4. add column description... '; |
| 159 | + EXEC [sys].sp_addextendedproperty @name=N'MS_Description', @value=N'The date and time the record was modified' , @level0type=N'SCHEMA',@level0name=@SchemaName, @level1type=N'TABLE',@level1name=@TableName, @level2type=N'COLUMN',@level2name=@ModifiedDate; |
| 160 | + |
| 161 | + PRINT 'END - ADD COLUMN [' + @ModifiedDate + ']... '; |
| 162 | + PRINT '====================================================================='; |
| 163 | + END |
| 164 | + |
| 165 | + IF NOT EXISTS (SELECT * FROM [sys].[triggers] WHERE [object_id] = OBJECT_ID(N'[' + @SchemaName + '].[TR_' + @TableName + '_LAST_UPDATED]')) |
| 166 | + BEGIN |
| 167 | + |
| 168 | + PRINT '====================================================================='; |
| 169 | + PRINT 'START - ADD TRIGGER [TR_' + @TableName + '_LAST_UPDATED]... '; |
| 170 | + |
| 171 | + PRINT '1. get primary key from information schema'; |
| 172 | + SET @SqlCommand = 'USE ' + @DatabaseName + '; ' |
| 173 | + SET @SqlCommand += ' SELECT ' |
| 174 | + SET @SqlCommand += ' @TableKey = COALESCE(@TableKey, '''') + CASE WHEN [ORDINAL_POSITION] = 1 THEN ''ON'' ELSE ''AND'' END + '' t.'' + [COLUMN_NAME] + '' = i.'' + [COLUMN_NAME] + '' ''' |
| 175 | + SET @SqlCommand += ' FROM' |
| 176 | + SET @SqlCommand += ' [INFORMATION_SCHEMA].[KEY_COLUMN_USAGE]' |
| 177 | + SET @SqlCommand += ' WHERE' |
| 178 | + SET @SqlCommand += ' OBJECTPROPERTY(OBJECT_ID([CONSTRAINT_SCHEMA] + ''.'' + QUOTENAME([CONSTRAINT_NAME])), ''IsPrimaryKey'') = 1 ' |
| 179 | + SET @SqlCommand += ' AND [TABLE_NAME] = ''' + @TableName + '''' |
| 180 | + SET @SqlCommand += ' AND [TABLE_SCHEMA] = ''' + @SchemaName + '''' |
| 181 | + SET @SqlCommand += ' ORDER BY [ORDINAL_POSITION]' |
| 182 | + EXEC sp_executeSQl @SqlCommand, N'@TableKey NVARCHAR(1000) OUTPUT', @TableKey OUTPUT |
| 183 | + |
| 184 | + PRINT '2. build trigger dynamically'; |
| 185 | + SET @SqlCommand = 'USE ' + @DatabaseName + '; ' |
| 186 | + SET @SqlCommand += ' CREATE TRIGGER [' + @SchemaName + '].[TR_' + @TableName + '_LAST_UPDATED]' + CHAR(13); |
| 187 | + SET @SqlCommand += ' ON [' + @SchemaName + '].[' + @TableName + ']' + CHAR(13); |
| 188 | + SET @SqlCommand += ' AFTER UPDATE' + CHAR(13); |
| 189 | + SET @SqlCommand += ' AS' + CHAR(13); |
| 190 | + SET @SqlCommand += ' BEGIN' + CHAR(13); |
| 191 | + SET @SqlCommand += CHAR(9) + ' IF NOT UPDATE(' + @ModifiedDate + ')' + CHAR(13); |
| 192 | + SET @SqlCommand += CHAR(9) + ' BEGIN' + CHAR(13); |
| 193 | + SET @SqlCommand += CHAR(9) + CHAR(9) + ' UPDATE t' + CHAR(13); |
| 194 | + SET @SqlCommand += CHAR(9) + CHAR(9) + ' SET' + CHAR(13); |
| 195 | + SET @SqlCommand += CHAR(9) + CHAR(9) + ' t.' + @ModifiedDate + ' = CURRENT_TIMESTAMP' + CHAR(13); |
| 196 | + SET @SqlCommand += CHAR(9) + CHAR(9) + ' , t.' + @ModifiedId + ' = LOWER(LEFT(RIGHT(SYSTEM_USER,(LEN(SYSTEM_USER)-CHARINDEX(''\'',SYSTEM_USER))), 50))' + CHAR(13); |
| 197 | + SET @SqlCommand += CHAR(9) + CHAR(9) + ' FROM [' + @SchemaName + '].[' + @TableName + '] AS t' + CHAR(13); |
| 198 | + SET @SqlCommand += CHAR(9) + CHAR(9) + ' INNER JOIN inserted AS i' + CHAR(13); |
| 199 | + SET @SqlCommand += CHAR(9) + CHAR(9) + @TableKey + ';' + CHAR(13); |
| 200 | + SET @SqlCommand += CHAR(9) + ' END' + CHAR(13); |
| 201 | + SET @SqlCommand += ' END;' + CHAR(13); |
| 202 | + EXEC (@SqlCommand) |
| 203 | + |
| 204 | + PRINT '3. enable trigger'; |
| 205 | + SET @SqlCommand = 'USE ' + @DatabaseName + '; ' |
| 206 | + SET @SqlCommand += ' ALTER TABLE [' + @SchemaName + '].[' + @TableName + '] ENABLE TRIGGER [TR_' + @TableName + '_LAST_UPDATED]'; |
| 207 | + EXEC (@SqlCommand) |
| 208 | + |
| 209 | + PRINT 'END - ADD TRIGGER [' + @ModifiedDate + ']... '; |
| 210 | + PRINT '====================================================================='; |
| 211 | + END |
| 212 | + |
| 213 | + |
| 214 | + PRINT 'END - ALTER [' + @DatabaseName + '].[' + @SchemaName + '].[' + @TableName + ']... '; |
| 215 | + PRINT '====================================================================='; |
| 216 | + |
| 217 | + --PRINT '******* ROLLBACK TRANSACTION ******* '; |
| 218 | + --ROLLBACK TRANSACTION; |
| 219 | + |
| 220 | + PRINT '******* COMMIT TRANSACTION ******* '; |
| 221 | + COMMIT TRANSACTION; |
| 222 | + |
| 223 | +END |
| 224 | + |
| 225 | +GO |
0 commit comments