Technical Article

Copy Triggers from One DB to Another

,

The other day I had to use the SQL scripts wizard (in SSMS right click the database name, select Tasks and then Generate Scripts) to create a copy of the database.  I selected all of the objects, went throught the motions and then created my new database without issue.

The wizard is a pretty good tool, but I came to realize that either I missed something or the wizard did.  My newly created database didn't contain any of the triggers in the old one, and there were a bunch.

In my case, the source database was stored on a remote SQL server, so I needed to write a script that would copy all of the triggers over to the new database which I was temporarily storing locally.

Hence I came up with the script here.  Before you run it, you should do a little checking.

Run the following:

SELECT *
FROM sys.servers

to see if the source server is listed.  If it is, you do not need to run the two EXECs:

EXEC sp_addlinkedserver @server='SOURCESQLSERVER'
...
EXEC sp_dropserver @server='SOURCESQLSERVER'

When the script runs, it prints each table for which it processes (CREATEs) a trigger in the messages pane.  This is so that it is easy to identify when there's an error in the CREATE step (if the names of your triggers aren't consistent or easily identifiable by which table they apply to).  This was beneficial to me because I was upgrading the database compatibility level from 80 to 100 and there were a few triggers that failed to CREATE due to some minor syntax incompatibilities.

Hope this is useful to you.

-- Attach to the source SQL Server
EXEC sp_addlinkedserver @server='SOURCESQLSERVER'
GO

CREATE TABLE #Triggers 
    (trigger_name VARCHAR(8000)
    ,trigger_definition NVARCHAR(MAX)
    ,table_name VARCHAR(8000))
GO

INSERT INTO #Triggers
SELECT b.name, a.definition, c.name
-- Put the name of your source SQL server into the first bracketed name (next 3 statements)
-- Put your source database into the second bracketed name (next 3 statements)
FROM [SOURCESQLSERVER].[SourceDatabase].sys.all_sql_modules a
INNER JOIN [SOURCESQLSERVER].[SourceDatabase].sys.all_objects b 
    ON a.object_id = b.object_id
INNER JOIN [SOURCESQLSERVER].[SourceDatabase].sys.all_objects c 
    ON b.parent_object_id = c.object_id
WHERE a.object_id > 0 AND b.type = 'TR'

-- Source SQL Server no longer needed
EXEC sp_dropserver @server='SOURCESQLSERVER'

USE [Your-Database]

DECLARE @SQL NVARCHAR(MAX), @table_name VARCHAR(8000)

DECLARE x_triggers CURSOR FOR
SELECT trigger_definition, table_name FROM #Triggers

OPEN x_triggers
FETCH NEXT FROM x_triggers 
INTO @SQL, @table_name

WHILE @@FETCH_STATUS = 0
BEGIN
    PRINT '******' + @table_name + '******'
    EXEC (@SQL)
    FETCH NEXT FROM x_triggers 
    INTO @SQL, @table_name
END
CLOSE x_triggers;
DEALLOCATE x_triggers;

DROP TABLE #Triggers

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating