Posts tagged: trigger

Enabling and Disabling Triggers

By , August 18, 2010 20:47

Yesterday, a colleague of mine proudly told me about a workaround that he had put together in the form of a trigger. “The work around”, he said “can simply be switched on and off by creating or dropping the trigger.” He had a glint in his eye until I asked him if he was aware that triggers can be disabled while still leaving the code in place. His solution would have meant keeping the T-SQL for the trigger on the server’s file system in case it had been “switched off” and needed to be “switched on” again, which is not really conform with best practices.

So I provided him with the code below, which I wrote for a project I dealt with a little while ago. I am also, for the sake of testing, including a little bit of DDL in the post. Also note that the test-trigger, that I include, deals with all rows affected by the triggering statement and not just one. This is a common mistake that is made (I have made it myself) when triggers are written.

use ThinkTank
go

if OBJECT_ID('dbo.TriggerTest') is not null
	drop table dbo.TriggerTest

create table dbo.TriggerTest (
	id int identity(1,1) primary key,
	guid_field uniqueidentifier ,
	calculated_field bigint
	)
go

Now the code for the trigger. Note the inner join between the logical table “inserted” and the table dbo.TriggerTest. This ensures that the trigger fires for all rows affected by the triggering statement.

create trigger dbo.tr_GenerateCalculatedFieldValue on dbo.TriggerTest
after insert
as

update tt
set calculated_field = i.id + 111 --an arbitrary data manipulation for testing
	from dbo.TriggerTest tt
	inner join inserted i
	on i.id = tt.id
go

Ok, so that is the DDL required to test what this post is actually about. Now for the code snippet which I have packed into a user stored procedure:

use ThinkTank
go

create procedure dbo.up_ReverseTriggerStatus
	@TriggerName sysname,
	@TableName sysname,
	@SchemaName sysname = 'dbo'
as

declare @IsDisabled bit
declare @ChangeStatusCommand nvarchar(500)
declare @QualifiedTable nvarchar(260)
declare @QualifiedTrigger nvarchar(260)
declare @UserMessageVar varchar(8)

--validate values passed in to the procedure and prevent sql injection
--First check to see that we are dealing with a valid schema
if schema_id(@SchemaName) != 1 or schema_id(@SchemaName) is null
begin
	raiserror ('"%s" is not a valid schema!', 16, 1, @SchemaName)
	return
end

--build the qualified names
set @QualifiedTable = quotename(@SchemaName) + '.' + quotename(@TableName)
set @QualifiedTrigger = quotename(@SchemaName) + '.' + quotename(@TriggerName)

-- Now check to see that we have a trigger with this schema and name
if objectpropertyex(object_id(@QualifiedTrigger), 'IsTrigger') != 1
or objectpropertyex(object_id(@QualifiedTrigger), 'IsTrigger') is null
begin
	raiserror ('%s is not a known trigger!', 16, 1, @QualifiedTrigger)
	return
end

--Then check to see that the table exists in the database
if objectpropertyex(object_id(@QualifiedTable), 'IsTable') != 1
or objectpropertyex(object_id(@QualifiedTable), 'IsTable')  is null
begin
	raiserror('%s is not a valid table object!', 16, 1, @QualifiedTable)
	return
end
else if objectpropertyex(object_id(@QualifiedTable), 'IsTable') = 1
begin
--OK, we've gotten this far, so the parameters aren't injected.
--It is also necessary to check that the trigger is actually installed on the table
	select @IsDisabled = is_disabled
		from sys.triggers
			where name = @TriggerName --unqualified
			and parent_id = object_id(@QualifiedTable)
end

if @IsDisabled is null
begin
	raiserror('The trigger %s is not installed on %s', 16, 1, @QualifiedTrigger, @QualifiedTable)
	return
end

--now we can get started with the actual work
--this would normally be done in one step, but for the sake of keeping in on the monitor...
set @ChangeStatusCommand = N'&command trigger &trigger on &table'
set @ChangeStatusCommand = replace(@ChangeStatusCommand,  '&table', @QualifiedTable)
set @ChangeStatusCommand = replace(@ChangeStatusCommand, '&trigger', @QualifiedTrigger)

if @IsDisabled = 1
begin
--here we want to re-enable the trigger
	set @ChangeStatusCommand = replace(@ChangeStatusCommand, '&command', 'enable')
	set @UserMessageVar = 'enabled'
end
else if @IsDisabled = 0
begin
--here we want to disable the trigger
	set @ChangeStatusCommand = replace(@ChangeStatusCommand, '&command', 'disable')
	set @UserMessageVar = 'disabled'
end

execute sp_executesql @ChangeStatusCommand
raiserror('The trigger %s was %s on %s.', 10, 1, @QualifiedTrigger, @UserMessageVar, @QualifiedTable)

Testing

Of course we need to test this solution. The standard status for a trigger is enabled, so the following code fires the trigger and we get the expected results.

use ThinkTank
go

insert into dbo.TriggerTest (guid_field)
select top 10 NEWID() from sys.columns a cross join sys.columns b

If we disable the trigger using the procedure “up_ReverseTriggerStatus”, the field “calculated_field” is not filled when the above statement is next run. Try it out and see for yourself.

In Conclusion

I haven’t included any error handling or the like, as I would really like to leave that up to each user to do for his- or herself and I didn’t want to bloat this post too much. It already has more code than I intended when I originally started writing the post (I really just wanted to blog about the fact that enable/disable trigger actually exists). It is, however, interesting to note that the bulk of the code is dedicated to parameter validation and that the core functionality comprises less than half of the code. It might actually be worthwhile looking into reducing the code for the validation. Perhaps I’ll do that at a later date.

Insert, Update or Delete Trigger

By , May 17, 2010 18:44

This one is a bit of a no-brainer and is really just for me, but if it does help anyone out there then I suppose it was worth posting.

I had to write a trigger today to monitor changes to data in a table. The client application does DML for the login language of the current user and the trigger has to do the same for the other languages for which the system was configured, so that clients logging on using another language also see the current data. For example: if a user in England inserts a new part number (along with description etc…), the same information has to be available for users in Romania and Germany. The same applied to updated and deleted data.

I generally don’t write many triggers, as I have had bad (really bad) experiences in the past, with undocumented triggers. But, the requirement was that a trigger be implemented.

Because the code that has to be run varies depending on which DML event was executing the trigger, I had to establish which event was occurring. I could have written three triggers, once each for insert, update and delete but I didn’t want to have three db-objects essentially linked by functionality and purpose, but acting as separate entities. This can get rather confusing when someone else has to maintain and or support the database and application using the database. (I have yet to meet the support-technician that reads system documentation at 3am). So I figured: Just give them one trigger to deal with.

This is how I went about finding out which DML event was firing the trigger:

create trigger TR_TriggerName
on Table
after insert, update, delete
as

declare @Update bit = 0
declare @Insert bit = 0
declare @Delete bit = 0

if exists (select * from inserted) --could be update or insert, but not delete
begin
	if exists (select * from deleted) --this is an update statement
	begin
		select	@Update = 1,
				@Insert = 0,
				@Delete = 0;
	end
	else --this is an insert statement
	begin
		select	@Insert = 1,
				@Update = 0,
				@Delete = 0;
	end
end
else --can only be a delete because nothing was in inserted
begin
	select	@Delete = 1,
			@Insert = 0,
			@Update = 0;
end

if (@Insert = 1)
begin
--insert code for insert procedure
end
else if (@Update = 1)
begin
--insert code for update procedure
end
else if (@Delete= 1)
begin
--insert code for delete procedure
end
go

Panorama Theme by Themocracy