Tuesday, October 11, 2011

List all triggers in a database with its source code

Yesterday I saw a question in a forum asking for help in writing a script to list out all Triggers within a database. They also wanted to see the source code of each trigger.

Method 1: Which works in SQL Server 2000, SQL Server 2005 and SQL Server 2008.

But the problem with SYSCOMMENTS is it would truncate any text beyond 4000 characters. As the "Text" column which preserves the source code is declared as NVARCHAR(8000).

/*
Written By: Vadivel Mohanakrishnan
Date: Oct 10, 2011
URL: http://vadivel.blogspot.com
Purpose:  To list all triggers in the current database along with the actual text/source code. It also lists what of type of trigger it is. 


But for all future development we should avoid using SYSOBJECTS, SYSCOMMENTS as it might be removed in the future versions.
*/
SELECT
  SO2.Name AS [Table Name],
    SO1.name AS [Trigger Name],
  OBJECTPROPERTY( [so1].[id], 'ExecIsUpdateTrigger') AS [isUpdate],
    OBJECTPROPERTY( [so1].[id], 'ExecIsDeleteTrigger') AS [isDelete],
    OBJECTPROPERTY( [so1].[id], 'ExecIsInsertTrigger') AS [isInsert],
    OBJECTPROPERTY( [so1].[id], 'ExecIsAfterTrigger') AS [isAfter],
    OBJECTPROPERTY( [so1].[id], 'ExecIsInsteadOfTrigger') AS [isInsteadOf],
    OBJECTPROPERTY([so1].[id], 'ExecIsTriggerDisabled') AS [isDisabled],
    SC.Text AS [Source Code]
FROM
SYSOBJECTS SO1 
    Inner Join SYSOBJECTS SO2 On SO1.parent_obj = SO2.id
    Inner Join SYSCOMMENTS SC On SO1.id = SC.id
WHERE      
SO1.xtype = 'TR' And SO2.xtype = 'U'
ORDER BY 
SO2.Name, SO1.name
GO

Method 2: Works with SQL Server 2005 and above.

This method doesn't have the problem of text getting truncated beyond 4000 characters because the column "definition" of SYS.SQL_MODULES is declared as NVARCHAR(MAX).

/*
Written By: Vadivel Mohanakrishnan
Date: Oct 11, 2011
URL: http://vadivel.blogspot.com
Purpose: To list all triggers in the current database along with the actual text/source code. It also lists what of type of trigger it is.
*/
SELECT 
Object_name( TR.parent_id) AS [Table Name],
TR.[Name] AS [Trigger Name],
TR.is_disabled AS [isDisabled],
TR.is_Instead_of_trigger AS [isInsteadOfTrigger],
MO.definition AS [Source Code], 
TR.create_date AS [Created Date],
TR.modify_date AS [Modified Date]
FROM 
SYS.TRIGGERS TR INNER JOIN SYS.SQL_MODULES MO 
ON TR.Object_id = MO.Object_ID
WHERE 
TR.[Type] = 'TR' AND
TR.is_ms_shipped = 0 AND
TR.[parent_id] > 0
ORDER BY 
Object_name( TR.parent_id), TR.[Name]
GO

1 comment:

George said...

You don't need to join to sql_modules because you can use the object_definition function instead.

Select *, object_definition(object_id) from sys.triggers