January 23, 2009 at 1:17 pm
I am in need of copying triggers from over 100+ tables to a another DB. Droping tables and recreating them is not an option.
Thanks
January 23, 2009 at 1:33 pm
How about something like:
select definition
from sys.sql_modules
inner join sys.triggers
on sql_modules.object_id = triggers.object_id
Does that give you what you need?
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
January 23, 2009 at 1:37 pm
Thanks but no.
I may have not been clear on what I want. I need to script out EVERY trigger as like a "Create to..." to a text file so I can run the create scripts on the other DB.
Does that make better sense?
Thanks
January 23, 2009 at 1:43 pm
If you want one file per trigger, you can do that from scripting the database. Right-click on the database in Management Studio, select Tasks, Generate Scripts, and then pick the triggers you want to script, and choose one file per object.
If you want a file that will create all your triggers, the query I gave you can do that. Set the output to "File" and run it, or copy-and-paste the results into Notepad, or whatever you want to do to file it. It will give you the create statements for each trigger. You might need to add "GO" between triggers, but that's just a string function.
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
January 23, 2009 at 1:47 pm
To clarify:
I set the output to Text, created a couple of triggers, and ran the query. Here's what I got:
create trigger Numbers_NoDel on dbo.Numbers
instead of delete
as
rollback;
go
create trigger Numbers_NoUpd on dbo.Numbers
instead of update
as
rollback;
go
Exact query run:
set nocount on
select definition + '
go'
from sys.sql_modules
inner join sys.triggers
on sql_modules.object_id = triggers.object_id
That result is good enough to run on another database and create all my triggers.
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
January 23, 2009 at 2:20 pm
The text formatting is all over the place and I get the error..
Incorrect syntax near 'inserted'.
Most likely because the text is all on a single line.
Any way of changing it to format it correctly where the carriage return should be?
January 23, 2009 at 2:37 pm
My fault, I forgot to do outout as text.
OK looks like it may work but the addition of the 'Go' statement isn't there. I'll tweak it a bit...
January 23, 2009 at 2:37 pm
Yes. Right-click on the query pane (in Management Studio), select "Results To", and change it to Text, instead of Grid. That's what I meant by setting the output to text. You can do the same thing from the menu or the toolbars, I'm just in the habit of using right-click for it.
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
January 23, 2009 at 2:44 pm
No dice. It doesn't look like it is returning the entire trigger script. These triggers have at least a min on 100 lines it them. Your scrip only returns the first 25 or so...
Thanks
January 23, 2009 at 5:42 pm
By default, I believe results to text only outputs the first 255 characters or so. Go to Tools >> Options, Expand Query Results, Expand SQL Server, and Highlight Results to Text. There you will see the option "Maximum number of characters to display". Set that to like 2000 and you should see everything.
January 23, 2009 at 5:45 pm
A simple way to set "Output to Text" is by pressing ctrl+t and ctrl+d sets the query results pane back to grid.
September 14, 2015 at 7:30 am
--Parameter:
-- @InclDrop bit
-- Possible values
-- 0 - Script to drop the triggers is not generated.
-- 1 - Script to drip the triggers is generated.
SET ansi_nulls ON
go
SET quoted_identifier ON
go
ALTER PROCEDURE [dbo].[Createscriptofalltriggers]
@InclDrop BIT =1
AS
DECLARE @sql VARCHAR(8000),
@Text NVARCHAR(4000),
@BlankSpaceAdded INT,
@BasePos INT,
@CurrentPos INT,
@TextLength INT,
@LineId INT,
@MaxID INT,
@AddOnLen INT,
@LFCR INT,
@DefinedLength INT,
@SyscomText NVARCHAR(4000),
@Line NVARCHAR(1000),
@UserName SYSNAME,
@ObjID INT,
@OldTrigID INT
SET nocount ON
SET @DefinedLength = 1000
SET @BlankSpaceAdded = 0
IF @InclDrop <> 0
SET @InclDrop =1
-- This Part Validated the Input parameters
DECLARE @Triggers TABLE
(
username SYSNAME NOT NULL,
trigname SYSNAME NOT NULL,
objid INT NOT NULL
)
DECLARE @TrigText TABLE
(
objid INT NOT NULL,
lineid INT NOT NULL,
linetext NVARCHAR(1000) NULL
)
INSERT INTO @Triggers
(username,
trigname,
objid)
SELECT DISTINCT A.NAME,
B.NAME,
B.id
FROM dbo.sysusers A,
dbo.sysobjects B,
dbo.syscomments C
WHERE A.uid = B.uid
AND B.type = 'Tr'
AND B.id = C.id
AND C.encrypted = 0
IF EXISTS(SELECT C.*
FROM syscomments C,
sysobjects O
WHERE O.id = C.id
AND O.type = 'Tr'
AND C.encrypted = 1)
BEGIN
PRINT '/*'
PRINT 'The following encrypted triggers were found'
PRINT 'The procedure could not write the script for it'
SELECT DISTINCT A.NAME,
B.NAME,
B.id
FROM dbo.sysusers A,
dbo.sysobjects B,
dbo.syscomments C
WHERE A.uid = B.uid
AND B.type = 'Tr'
AND B.id = C.id
AND C.encrypted = 1
PRINT '*/'
END
DECLARE ms_crs_syscom CURSOR local forward_only FOR
SELECT T.objid,
C.text
FROM @Triggers T,
dbo.syscomments C
WHERE T.objid = C.id
ORDER BY T.objid,
C.colid
FOR READ only
SELECT @LFCR = 2
SELECT @LineId = 1
OPEN ms_crs_syscom
SET @OldTrigID = -1
FETCH next FROM ms_crs_syscom INTO @ObjID, @SyscomText
WHILE @@fetch_status = 0
BEGIN
SELECT @BasePos = 1
SELECT @CurrentPos = 1
SELECT @TextLength = Len(@SyscomText)
IF @ObjID <> @OldTrigID
BEGIN
SET @LineID = 1
SET @OldTrigID = @ObjID
END
WHILE @CurrentPos != 0
BEGIN
--Looking for end of line followed by carriage return
SELECT @CurrentPos = Charindex(Char(13) + Char(10), @SyscomText,
@BasePos)
--If carriage return found
IF @CurrentPos != 0
BEGIN
WHILE ( Isnull(Len(@Line), 0) + @BlankSpaceAdded
+ @CurrentPos - @BasePos + @LFCR ) >
@DefinedLength
BEGIN
SELECT @AddOnLen = @DefinedLength - (
Isnull(Len(@Line),
0
) +
@BlankSpaceAdded )
INSERT @TrigText
VALUES ( @ObjID,
@LineId,
Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText, @BasePos,
@AddOnLen),
N''))
SELECT @Line = NULL,
@LineId = @LineId + 1,
@BasePos = @BasePos + @AddOnLen,
@BlankSpaceAdded = 0
END
SELECT @Line = Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText, @BasePos,
@CurrentPos
-@BasePos +
@LFCR),
N'')
SELECT @BasePos = @CurrentPos + 2
INSERT @TrigText
VALUES( @ObjID,
@LineId,
@Line )
SELECT @LineId = @LineId + 1
SELECT @Line = NULL
END
ELSE
--else carriage return not found
BEGIN
IF @BasePos <= @TextLength
BEGIN
/*If new value for @Lines length will be > then the
**defined length
*/
WHILE ( Isnull(Len(@Line), 0) + @BlankSpaceAdded
+ @TextLength - @BasePos + 1 ) >
@DefinedLength
BEGIN
SELECT @AddOnLen = @DefinedLength - (
Isnull(Len(@Line),
0
) +
@BlankSpaceAdded )
INSERT @TrigText
VALUES ( @ObjID,
@LineId,
Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText,
@BasePos,
@AddOnLen),
N''))
SELECT @Line = NULL,
@LineId = @LineId + 1,
@BasePos = @BasePos + @AddOnLen,
@BlankSpaceAdded = 0
END
SELECT @Line = Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText,
@BasePos,
@TextLength
-@BasePos+1
), N'')
IF Len(@Line) < @DefinedLength
AND Charindex(' ', @SyscomText, @TextLength + 1)
> 0
BEGIN
SELECT @Line = @Line + ' ',
@BlankSpaceAdded = 1
END
END
END
END
FETCH next FROM ms_crs_syscom INTO @ObjID, @SyscomText
END
IF @Line IS NOT NULL
INSERT @TrigText
VALUES( @ObjID,
@LineId,
@Line )
CLOSE ms_crs_syscom
PRINT '-- You should run this result under dbo if your triggers belong to multiple users'
PRINT ''
IF @InclDrop = 1
BEGIN
PRINT '-- Dropping the Triggers'
PRINT ''
SELECT 'If exists(Select * from sysObjects where id =Object_ID(''['
+ username + '].[' + trigname
+ ']'') and ObjectProperty(Object_ID(''['
+ username + '].[' + trigname + ']''), ''ISTRIGGER'')=1) Drop Trigger ['
+ username + '].[' + trigname + '] ' + Char(13)
+ Char(10) + 'GO' + Char(13) + Char(10) + Char(13)
+ Char(10)
FROM @Triggers
END
PRINT '----------------------------------------------'
PRINT '-- Creation of Triggers'
PRINT ''
PRINT ''
DECLARE ms_users CURSOR local forward_only FOR
SELECT T.username,
T.objid,
Max(D.lineid)
FROM @Triggers T,
@TrigText D
WHERE T.objid = D.objid
GROUP BY T.username,
T.objid
FOR READ only
OPEN ms_users
FETCH next FROM ms_users INTO @UserName, @ObjID, @MaxID
WHILE @@fetch_status = 0
BEGIN
PRINT 'SetUser N''' + @UserName + '''' + Char(13)
+ Char(10)
SELECT '-- Text of the Trigger'= CASE lineid
WHEN 1 THEN 'GO' + Char(13) + Char(
10)
+
linetext
WHEN @MaxID THEN linetext + 'GO'
ELSE linetext
END
FROM @TrigText
WHERE objid = @ObjID
ORDER BY lineid
PRINT 'Setuser'
FETCH next FROM ms_users INTO @UserName, @ObjID, @MaxID
END
CLOSE ms_users
PRINT 'GO'
PRINT '------End ------'
DEALLOCATE ms_crs_syscom
DEALLOCATE ms_users
SET nocount ON
DECLARE @return_value INT
How to execute it:
EXEC @return_value = [dbo].[Createscriptofalltriggers]
@InclDrop = 1
SELECT 'Return Value' = @return_value
go
September 14, 2015 at 7:31 am
--Parameter:
-- @InclDrop bit
-- Possible values
-- 0 - Script to drop the triggers is not generated.
-- 1 - Script to drip the triggers is generated.
SET ansi_nulls ON
go
SET quoted_identifier ON
go
ALTER PROCEDURE [dbo].[Createscriptofalltriggers]
@InclDrop BIT =1
AS
DECLARE @sql VARCHAR(8000),
@Text NVARCHAR(4000),
@BlankSpaceAdded INT,
@BasePos INT,
@CurrentPos INT,
@TextLength INT,
@LineId INT,
@MaxID INT,
@AddOnLen INT,
@LFCR INT,
@DefinedLength INT,
@SyscomText NVARCHAR(4000),
@Line NVARCHAR(1000),
@UserName SYSNAME,
@ObjID INT,
@OldTrigID INT
SET nocount ON
SET @DefinedLength = 1000
SET @BlankSpaceAdded = 0
IF @InclDrop <> 0
SET @InclDrop =1
-- This Part Validated the Input parameters
DECLARE @Triggers TABLE
(
username SYSNAME NOT NULL,
trigname SYSNAME NOT NULL,
objid INT NOT NULL
)
DECLARE @TrigText TABLE
(
objid INT NOT NULL,
lineid INT NOT NULL,
linetext NVARCHAR(1000) NULL
)
INSERT INTO @Triggers
(username,
trigname,
objid)
SELECT DISTINCT A.NAME,
B.NAME,
B.id
FROM dbo.sysusers A,
dbo.sysobjects B,
dbo.syscomments C
WHERE A.uid = B.uid
AND B.type = 'Tr'
AND B.id = C.id
AND C.encrypted = 0
IF EXISTS(SELECT C.*
FROM syscomments C,
sysobjects O
WHERE O.id = C.id
AND O.type = 'Tr'
AND C.encrypted = 1)
BEGIN
PRINT '/*'
PRINT 'The following encrypted triggers were found'
PRINT 'The procedure could not write the script for it'
SELECT DISTINCT A.NAME,
B.NAME,
B.id
FROM dbo.sysusers A,
dbo.sysobjects B,
dbo.syscomments C
WHERE A.uid = B.uid
AND B.type = 'Tr'
AND B.id = C.id
AND C.encrypted = 1
PRINT '*/'
END
DECLARE ms_crs_syscom CURSOR local forward_only FOR
SELECT T.objid,
C.text
FROM @Triggers T,
dbo.syscomments C
WHERE T.objid = C.id
ORDER BY T.objid,
C.colid
FOR READ only
SELECT @LFCR = 2
SELECT @LineId = 1
OPEN ms_crs_syscom
SET @OldTrigID = -1
FETCH next FROM ms_crs_syscom INTO @ObjID, @SyscomText
WHILE @@fetch_status = 0
BEGIN
SELECT @BasePos = 1
SELECT @CurrentPos = 1
SELECT @TextLength = Len(@SyscomText)
IF @ObjID <> @OldTrigID
BEGIN
SET @LineID = 1
SET @OldTrigID = @ObjID
END
WHILE @CurrentPos != 0
BEGIN
--Looking for end of line followed by carriage return
SELECT @CurrentPos = Charindex(Char(13) + Char(10), @SyscomText,
@BasePos)
--If carriage return found
IF @CurrentPos != 0
BEGIN
WHILE ( Isnull(Len(@Line), 0) + @BlankSpaceAdded
+ @CurrentPos - @BasePos + @LFCR ) >
@DefinedLength
BEGIN
SELECT @AddOnLen = @DefinedLength - (
Isnull(Len(@Line),
0
) +
@BlankSpaceAdded )
INSERT @TrigText
VALUES ( @ObjID,
@LineId,
Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText, @BasePos,
@AddOnLen),
N''))
SELECT @Line = NULL,
@LineId = @LineId + 1,
@BasePos = @BasePos + @AddOnLen,
@BlankSpaceAdded = 0
END
SELECT @Line = Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText, @BasePos,
@CurrentPos
-@BasePos +
@LFCR),
N'')
SELECT @BasePos = @CurrentPos + 2
INSERT @TrigText
VALUES( @ObjID,
@LineId,
@Line )
SELECT @LineId = @LineId + 1
SELECT @Line = NULL
END
ELSE
--else carriage return not found
BEGIN
IF @BasePos <= @TextLength
BEGIN
/*If new value for @Lines length will be > then the
**defined length
*/
WHILE ( Isnull(Len(@Line), 0) + @BlankSpaceAdded
+ @TextLength - @BasePos + 1 ) >
@DefinedLength
BEGIN
SELECT @AddOnLen = @DefinedLength - (
Isnull(Len(@Line),
0
) +
@BlankSpaceAdded )
INSERT @TrigText
VALUES ( @ObjID,
@LineId,
Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText,
@BasePos,
@AddOnLen),
N''))
SELECT @Line = NULL,
@LineId = @LineId + 1,
@BasePos = @BasePos + @AddOnLen,
@BlankSpaceAdded = 0
END
SELECT @Line = Isnull(@Line, N'')
+ Isnull(Substring(@SyscomText,
@BasePos,
@TextLength
-@BasePos+1
), N'')
IF Len(@Line) < @DefinedLength
AND Charindex(' ', @SyscomText, @TextLength + 1)
> 0
BEGIN
SELECT @Line = @Line + ' ',
@BlankSpaceAdded = 1
END
END
END
END
FETCH next FROM ms_crs_syscom INTO @ObjID, @SyscomText
END
IF @Line IS NOT NULL
INSERT @TrigText
VALUES( @ObjID,
@LineId,
@Line )
CLOSE ms_crs_syscom
PRINT '-- You should run this result under dbo if your triggers belong to multiple users'
PRINT ''
IF @InclDrop = 1
BEGIN
PRINT '-- Dropping the Triggers'
PRINT ''
SELECT 'If exists(Select * from sysObjects where id =Object_ID(''['
+ username + '].[' + trigname
+ ']'') and ObjectProperty(Object_ID(''['
+ username + '].[' + trigname + ']''), ''ISTRIGGER'')=1) Drop Trigger ['
+ username + '].[' + trigname + '] ' + Char(13)
+ Char(10) + 'GO' + Char(13) + Char(10) + Char(13)
+ Char(10)
FROM @Triggers
END
PRINT '----------------------------------------------'
PRINT '-- Creation of Triggers'
PRINT ''
PRINT ''
DECLARE ms_users CURSOR local forward_only FOR
SELECT T.username,
T.objid,
Max(D.lineid)
FROM @Triggers T,
@TrigText D
WHERE T.objid = D.objid
GROUP BY T.username,
T.objid
FOR READ only
OPEN ms_users
FETCH next FROM ms_users INTO @UserName, @ObjID, @MaxID
WHILE @@fetch_status = 0
BEGIN
PRINT 'SetUser N''' + @UserName + '''' + Char(13)
+ Char(10)
SELECT '-- Text of the Trigger'= CASE lineid
WHEN 1 THEN 'GO' + Char(13) + Char(
10)
+
linetext
WHEN @MaxID THEN linetext + 'GO'
ELSE linetext
END
FROM @TrigText
WHERE objid = @ObjID
ORDER BY lineid
PRINT 'Setuser'
FETCH next FROM ms_users INTO @UserName, @ObjID, @MaxID
END
CLOSE ms_users
PRINT 'GO'
PRINT '------End ------'
DEALLOCATE ms_crs_syscom
DEALLOCATE ms_users
SET nocount ON
DECLARE @return_value INT
How to execute it:
EXEC @return_value = [dbo].[Createscriptofalltriggers]
@InclDrop = 1
SELECT 'Return Value' = @return_value
go
November 20, 2015 at 5:25 am
Your first method will include tables schema as well and Moreover if a table have more than 1 triggers then all of them will be scripted in 1 file only.
Looking for a way where if a table have more than 1 trigger then all triggers can be scripted in different files.
Viewing 14 posts - 1 through 13 (of 13 total)
You must be logged in to reply to this topic. Login to reply