Today, I will be looking at how INSTEAD OF TRIGGERS can be used to make our VIEW correctly work with a UPDATE statement.
I will be using the [AUTOS] sample database for this demonstration. The [VW_JOIN_MAKES_2_MODELS] view will be enhanced with a instead of trigger so that update action can be perform on two tables at the same time.
The enclosed script has code to perform the following actions in the AUTOS database.
- 5A – Remove aggregate view
- 5B – Reload tables with good data
- 5C – Create a instead of trigger (insert)
- 5D – Test insert actions of instead of trigger
- 5E – Create a instead of trigger (delete)
- 5F – Test delete actions of instead of trigger
- 5G – Create a instead of trigger (update)
- 5H – Test update actions of instead of trigger
Our focus today will be on 5G – defining the instead of update trigger and 5H – performing unit testing on said trigger.
Like most Data Definition Language (DDL) constructs, a user defined trigger has three operations associated with it: CREATE TRIGGER, ALTER TRIGGER and DROP TRIGGER.
Since our view joins data between two tables, we need to know if data is going to be updated from the 1 = MODELS, 2 = MAKES or 3 = BOTH tables.
With the instead of update trigger, we could compare the new data in the inserted table to the old data in the deleted table to determine what action to perform. This would require a lot of code for a view with a bunch of fields.
How do we determine what table to update using a limited amount of code?
We are in luck since the DBCC INPUTBUFFER command can help us. Calling this function with the current session id returns a table containing information about the event. I used a table variable below to hold the information. We can find the exact TSQL statement that was used when the trigger fired.
By parsing this string, we can find the WHERE clause of the update statement. Thus, finding what table to update from.
Here are some ground rules for our view users. One requirement of the user is to use the primary key (make id or model id) or natural key (make name or model name) in the WHERE clause. Only fields other than the primary key will be updated. Any broken requirements will end up in a error.
The code below defines the INSTEAD OF UPDATE trigger.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 |
-- -- Create a instead of trigger (update) -- -- Remove existing trigger IF OBJECT_ID('DBO.TRG_CORRECT_UPD_ACTION_4_MAKES_2_MODELS') IS NOT NULL DROP TRIGGER [DBO].[TRG_CORRECT_UPD_ACTION_4_MAKES_2_MODELS]; GO -- Create instead of trigger CREATE TRIGGER [DBO].[TRG_CORRECT_UPD_ACTION_4_MAKES_2_MODELS] ON [DBO].[VW_JOIN_MAKES_2_MODELS] INSTEAD OF UPDATE AS -- Author: John Miner -- Date: Jan 2013 -- Purpose: Perform the correct update action for a view. BEGIN -- Declare local variables DECLARE @VAR_WHICH_TABLE INT; DECLARE @VAR_TSQL NVARCHAR(4000); DECLARE @VAR_VAL1 INT; DECLARE @VAR_VAL2 INT; -- Declare input buffer variable DECLARE @VAR_BUFFER TABLE ( [EventType] NVARCHAR(30), [Parameters] INT, [EventInfo] NVARCHAR(4000) ); -- Find the tsql that fired the trigger INSERT INTO @VAR_BUFFER EXEC sp_executesql N'DBCC INPUTBUFFER(@@spid) WITH NO_INFOMSGS'; -- Parse TSQL to get WHERE clause SELECT @VAR_TSQL = UPPER(ISNULL(B.EventInfo, '')) FROM @VAR_BUFFER B; SELECT @VAR_VAL1 = CHARINDEX('WHERE', @VAR_TSQL, 1); IF (@VAR_VAL1 > 0) SELECT @VAR_TSQL = SUBSTRING(@VAR_TSQL, @VAR_VAL1, LEN(@VAR_TSQL) - @VAR_VAL1); ELSE SELECT @VAR_TSQL = ' '; -- Action being performed PRINT 'INSTEAD OF UPDATE ACTION - '; -- Find out what is being modified SELECT @VAR_WHICH_TABLE = 0; IF ( (CHARINDEX('MODEL_ID', @VAR_TSQL, 1) > 0) OR (CHARINDEX('MODEL_NM', @VAR_TSQL, 1) > 0) ) SELECT @VAR_WHICH_TABLE = @VAR_WHICH_TABLE + 1; IF ( (CHARINDEX('MAKER_ID', @VAR_TSQL, 1) > 0) OR (CHARINDEX('MAKER_NM', @VAR_TSQL, 1) > 0) ) SELECT @VAR_WHICH_TABLE = @VAR_WHICH_TABLE + 2; -- Key fields are null IF (@VAR_WHICH_TABLE = 0) BEGIN -- Action being performed PRINT ' NO VALID KEYS SUPPLIED. '; -- Raise an error on this action RAISERROR('Either makers or models id or name must not be null when updating data. Please try again.', 16, 1) END; -- Update data in models table IF (@VAR_WHICH_TABLE = 1) OR (@VAR_WHICH_TABLE = 3) BEGIN -- Action being performed PRINT ' UPDATE MODELS DATA. '; -- Perform the update UPDATE [DBO].[MODELS] SET MODEL_NM = I.MODEL_NM, MODEL_YR = I.MODEL_YR, MSRP = I.MSRP FROM [DBO].[MODELS] M INNER JOIN inserted I ON M.MODEL_ID = I.MODEL_ID; END; -- Update data in makes table IF (@VAR_WHICH_TABLE = 2) OR (@VAR_WHICH_TABLE = 3) BEGIN -- Action being performed PRINT ' UPDATE MAKES DATA. '; -- Perform the update UPDATE [DBO].[MAKES] SET MAKER_NM = I.MAKER_NM, START_YR = I.START_YR, END_YR = I.END_YR FROM [DBO].[MAKES] M INNER JOIN inserted I ON M.MAKER_ID = I.MAKER_ID; END; END; |
Lets get the negative testing out of the way by trying to update data from the view without a primary key.
1 2 3 |
-- Update should fail UPDATE DBO.VW_JOIN_MAKES_2_MODELS SET MAKER_NM = 'Dodge Ram' |
The first positive test is to update data in the MAKES table using a primary key.
1 2 3 4 |
-- Update single field UPDATE DBO.VW_JOIN_MAKES_2_MODELS SET MAKER_NM = 'Dodge Ram' WHERE MAKER_ID = 2; |
The second positive test is to update data in the MODELS table using the primary key.
1 2 3 4 |
-- Update single field UPDATE DBO.VW_JOIN_MAKES_2_MODELS SET MODEL_NM = '1500' WHERE MODEL_ID = 2; |
The third positive test is to update data from both the MAKES and MODELS tables at the same time works. This is a new functionality that is not available in a normal view.
1 2 3 4 5 6 |
-- Update two fields, restore original setting UPDATE DBO.VW_JOIN_MAKES_2_MODELS SET MAKER_NM = 'Dodge' , MODEL_NM = 'Ram 1500' WHERE MAKER_ID = 2 AND MODEL_ID = 2; |
In summary, we were able to add a INSTEAD OF UPDATE trigger to our user defined view to make it function correctly with a UPDATE statement. While I have been focusing on enabling a VIEW to be updatable, triggers can be used to implement many different business rules.
Just remember, a trigger gets fired like a Tommy Gun every time the associated DML statement (INSERT, UPDATE, DELETE) is executed. Therefore, limiting the amount of code in a trigger will make sure your SQL statements execute as quick as possible.
Next time, I will be creating a test data warehouse from scratch with 20 million rows. This in preparation for partitioned and materialized views.