Skip to content

Commit 0bc2c8a

Browse files
authored
Add files via upload
1 parent a645737 commit 0bc2c8a

File tree

2 files changed

+282
-0
lines changed

2 files changed

+282
-0
lines changed

SSDB.Row_Level_Auditing_Add.sql

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

SSDB.Row_Level_Auditing_Remove.sql

+62
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,62 @@
1+
CREATE PROCEDURE [admin].[RowLevelAuditingRemove]
2+
@SchemaName NVARCHAR(50) = NULL
3+
, @TableName NVARCHAR(50) = NULL
4+
AS
5+
BEGIN
6+
/*
7+
'--------------------------------------------------------------------------------------------------------------------
8+
' Purpose: Removes row level auditing columns to a table
9+
' Example: EXEC admin.RowLevelAuditingRemove 'dbo', 'Users';
10+
'--------------------------------------------------------------------------------------------------------------------
11+
12+
13+
-----------------------------------------------------
14+
-->>>>>>>>>>>>>>>>> FOR DEBUGGING <<<<<<<<<<<<<<<<<<<
15+
-----------------------------------------------------
16+
BEGIN
17+
DECLARE @SchemaName NVARCHAR(50)
18+
DECLARE @TableName NVARCHAR(50)
19+
SET @SchemaName = 'dbo'
20+
SET @TableName = 'Users'
21+
-----------------------------------------------------
22+
-----------------------------------------------------
23+
24+
*/
25+
26+
SET XACT_ABORT ON
27+
BEGIN TRANSACTION;
28+
SET NOCOUNT ON
29+
30+
DECLARE @SqlCommand NVARCHAR(1000)
31+
DECLARE @CreatedId NVARCHAR(50)
32+
DECLARE @CreatedDate NVARCHAR(50)
33+
DECLARE @ModifiedId NVARCHAR(50)
34+
DECLARE @ModifiedDate NVARCHAR(50)
35+
36+
SET @CreatedId = 'CreatedId'
37+
SET @CreatedDate = 'CreatedDate'
38+
SET @ModifiedId = 'ModifiedId'
39+
SET @ModifiedDate = 'ModifiedDate'
40+
41+
SET @SqlCommand = 'DROP TRIGGER [' + @SchemaName + '].[TR_' + @TableName + '_LAST_UPDATED];' + CHAR(13);
42+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP CONSTRAINT [DF_' + @TableName + '_' + @CreatedId + '];' + CHAR(13);
43+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP CONSTRAINT [DF_' + @TableName + '_' + @CreatedDate + '];' + CHAR(13);
44+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP CONSTRAINT [DF_' + @TableName + '_' + @ModifiedId + '];' + CHAR(13);
45+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP CONSTRAINT [DF_' + @TableName + '_' + @ModifiedDate + '];' + CHAR(13);
46+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP COLUMN ' + @CreatedId + ';' + CHAR(13);
47+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP COLUMN ' + @CreatedDate + ';' + CHAR(13);
48+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP COLUMN ' + @ModifiedId + ';' + CHAR(13);
49+
SET @SqlCommand += 'ALTER TABLE ' + @SchemaName + '.' + @TableName + ' DROP COLUMN ' + @ModifiedDate + ';' + CHAR(13);
50+
PRINT @SqlCommand
51+
EXEC (@SqlCommand)
52+
53+
54+
--PRINT 'ROLLBACK TRANSACTION... ';
55+
--ROLLBACK TRANSACTION;
56+
57+
PRINT 'COMMIT TRANSACTION... '
58+
COMMIT TRANSACTION;
59+
60+
END
61+
62+
GO

0 commit comments

Comments
 (0)