November 24, 2010 at 8:39 am
I would like to create a SQL job that automatically runs the Generate Scripts process for certain Views, Functions and Stored Procedures.
A little background...we have a canned software package that uses an SQL 2005 database. I have created several views, functions and stored procedures in that database to accommodate some of our needs, reporting, etc. The problem is...whenever we apply an update from the software provider, all of my custom views etc get erased as part of their "upgrade" process. I then run my script from the Generate Scripts process to re-create everything.
As time has gone on, every time I make a change to something or add something new, I'm manually running the Generate Scripts option, then selecting the views, functions and stored procedures I want by hand. Now that we're up in the mid 80s on quantity of custom objects I've made, this is a bit of a pain in the butt to do every time. More of an annoyance than anything.
What I would like to do is create an SQL Server job that runs this for me daily. I know what objects I want to back up. Running a simple "SELECT * FROM dbo.sysobjects WHERE name LIKE 'KLL%' " shows me all of the objects I would want backed up, as all of my customizations I have prefixed with 'KLL'. I can also see that the xtype field in that table tells me what are views, functions, and procedures.
Is there some way I can create a script to run in a job that will run the Generate Scripts procedure, and output that result to a text file?
Your help is much appreciated.
Tony
November 24, 2010 at 9:05 am
well, here's a simple procedure that will return a table with the definitions of just the view/proc/function objects that begin with "KLL" in the correct dependancy order.
you could then create a scheduled job which calls bcp to output this to a single file.
if you have TABLEs that begin with KLL, i have a different version for that, but it's basicalyl the same.
CREATE PROCEDURE sp_export_KLLschema
AS
BEGIN
SET NOCOUNT ON
CREATE TABLE #MyObjectHierarchy
(
HID int identity(1,1) not null primary key,
ObjectId int,
TYPE int,OBJECTTYPE AS CASE
WHEN TYPE = 1 THEN 'FUNCTION'
WHEN TYPE = 4 THEN 'VIEW'
WHEN TYPE = 8 THEN 'TABLE'
WHEN TYPE = 16 THEN 'PROCEDURE'
WHEN TYPE =128 THEN 'RULE'
ELSE ''
END,
ONAME varchar(255),
OOWNER varchar(255),
SEQ int
)
--our results table
CREATE TABLE #Results(ResultsID int identity(1,1) not null,ResultsText varchar(max) )
--our list of objects in dependancy order
INSERT #MyObjectHierarchy (TYPE,ONAME,OOWNER,SEQ)
EXEC sp_msdependencies @intrans = 1
Update #MyObjectHierarchy SET ObjectId = object_id(OOWNER + '.' + ONAME)
--synonyns are object type 1 Function?!?!...gotta remove them
DELETE FROM #MyObjectHierarchy WHERE objectid in(
SELECT [object_id] FROM sys.synonyms UNION ALL
SELECT [object_id] FROM master.sys.synonyms)
--custom requirement: only objects starting with KLL
DELETE FROM #MyObjectHierarchy WHERE LEFT(ONAME,3) <> 'KLL'
DECLARE
@schemaname varchar(255),
@objname varchar(255),
@objecttype varchar(20),
@FullObjectName varchar(510)
DECLARE cur1 CURSOR FOR
SELECT OOWNER,ONAME,OBJECTTYPE FROM #MyObjectHierarchy ORDER BY HID
OPEN cur1
FETCH NEXT FROM cur1 INTO @schemaname,@objname,@objecttype
WHILE @@fetch_status <> -1
BEGIN
SET @FullObjectName = QUOTENAME(@schemaname) + '.' + QUOTENAME(@objname)
PRINT @FullObjectName
IF @objecttype IN( 'VIEW','FUNCTION','PROCEDURE')
BEGIN
INSERT INTO #Results(ResultsText)
EXEC sp_helptext @FullObjectName
--we need a batch seperator:
INSERT INTO #Results(ResultsText)
SELECT 'GO'
END
FETCH NEXT FROM cur1 INTO @schemaname,@objname,@objecttype
END
CLOSE cur1
DEALLOCATE cur1
SELECT ResultsText FROM #Results ORDER BY ResultsID
END
GO
Lowell
November 24, 2010 at 12:04 pm
Hi Lowell...thanks for your reply. I had to do some research on the BCP part but got it to work. Thanks!
One thing...it does output the specs, but it's not exactly the same as running it manually. It looks like it puts everything together without an sp_executesql statement. For example:
This is the code generated from one particular function that is generated out of the Generate Scripts Function:
/****** Object: UserDefinedFunction [dbo].[KLLfn_Get_Week_Start_Date] Script Date: 11/22/2010 16:26:28 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[KLLfn_Get_Week_Start_Date]') AND type in (N'FN', N'IF', N'TF', N'FS', N'FT'))
BEGIN
execute dbo.sp_executesql @statement = N'-- =============================================
-- Author:Tony Schmitt
-- Create date: 03/15/2010
-- Description:Return the starting day of a given week.
-- =============================================
CREATE FUNCTION [dbo].[KLLfn_Get_Week_Start_Date]
(
-- Add the parameters for the function here
@ParmDate DateTime
)
RETURNS DateTime
AS
BEGIN
-- Declare the return variable here
DECLARE @WkStartDate DateTime
-- Add the T-SQL statements to compute the return value here
SET @WkStartDate = (SELECT DATEADD(wk, DATEDIFF(wk, 6, @ParmDate), 6))
-- Return the result of the function
RETURN @WkStartDate
END
'
END
GO
This is from the process you provided me with:
-- =============================================
-- Author:Tony Schmitt
-- Create date: 03/15/2010
-- Description:Return the starting day of a given week.
-- =============================================
CREATE FUNCTION [dbo].[KLLfn_Get_Week_Start_Date]
(
-- Add the parameters for the function here
@ParmDate DateTime
)
RETURNS DateTime
AS
BEGIN
-- Declare the return variable here
DECLARE @WkStartDate DateTime
-- Add the T-SQL statements to compute the return value here
SET @WkStartDate = (SELECT DATEADD(wk, DATEDIFF(wk, 6, @ParmDate), 6))
-- Return the result of the function
RETURN @WkStartDate
END
It then goes to the next Create Function statement.
Basically, it looks like it's missing the step checking if it exists, then the execute statement. When I try running the new version, I get loads and loads of errors about variables etc not being defined.
Any ideas?
November 26, 2010 at 10:12 am
Have you tried doing this through Powershell? You can easily access the the SQL Server SMO to script out the objects to a file. I hadn't used powershell at all until this past Monday and within a few hours had a script that would dump the schema to a file. It's really really easy. And the code to do this is much more compact than using stored procedures.
November 26, 2010 at 12:54 pm
bjhogan (11/26/2010)
Have you tried doing this through Powershell? You can easily access the the SQL Server SMO to script out the objects to a file. I hadn't used powershell at all until this past Monday and within a few hours had a script that would dump the schema to a file. It's really really easy. And the code to do this is much more compact than using stored procedures.
Can you post the script, please?
--Jeff Moden
Change is inevitable... Change for the better is not.
November 28, 2010 at 1:45 pm
In general knowing that most vendors don't like client messing with their DBs, I've used a different approach to this problem. I would rather add my own database to the environment and have my code in this database, just referencing the other database.
This way you don't run the risk of breaking support contracts, or of lossing your code.
Leo
Leo
Nothing in life is ever so complicated that with a little work it can't be made more complicated.
November 28, 2010 at 8:15 pm
Jeff Moden (11/26/2010)
bjhogan (11/26/2010)
Have you tried doing this through Powershell? You can easily access the the SQL Server SMO to script out the objects to a file. I hadn't used powershell at all until this past Monday and within a few hours had a script that would dump the schema to a file. It's really really easy. And the code to do this is much more compact than using stored procedures.Can you post the script, please?
Yes, this would be very useful. Perhaps even worthy of an article here on SSC!
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
November 29, 2010 at 7:13 am
I have attached the script. It is extremely basic, but you can build on it very easily. Actually, if you are familiar with Informix, they have a built-in tool called dbschema...that's where i got the name from. I'm going to try to mimic the tool as much possible as it's been one of the best command line tools I have ever used for dumping schemas.
You can see the full usage here: http://publib.boulder.ibm.com/infocenter/idshelp/v10/index.jsp?topic=/com.ibm.mig.doc/mig170.htm
November 29, 2010 at 7:58 am
I use this to script all the objects to files. As I recall, the .exe is not in 2005, so I copied it, and maybe a couple others from my 2000 server: scptxfr.rll, scriptin.exe, sqlresld.dll.
I build a temp table with the databases I want to script, then loop through each database name:
--- Script out Database objects
set @code = '"C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\scptxfr.exe" /s MyServerName ' + ' /d ' + @DatabaseName + ' /I /F '
+ '\\UNCServerToWriteTo\SQLBACKUP\MyServerName\Object_Scripts\' + @DatabaseName + '_structure_'+ convert(varchar(8),getdate(),112) + '' + ' /q /A /r'
--select @code
EXEC master..xp_cmdshell @code
Looks like it scripts pretty much all the database objects. I started using it as an extra layer of backup before we had change controls in place, and as a way to recover code without having to restore a 1Tb database.
November 29, 2010 at 9:16 am
Why not create an SSIS package to create your objects in another DB?
December 2, 2010 at 4:01 pm
Hi,
this has been really useful, thanks 🙂
you mentioned you have a script that does tables too - could you possibly post that?
I'm newbie trying to build a script generator to update a list of 'config' tables in another database - so need to work through a list of tables (tbl_tablestoreplace) and create a script of them - including their fields, keys, indexes and data?
cheers
Brett
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply