[dba-SQLServer] Copy a database using Elizabeth's suggestionplusparameters

jwcolby jwcolby at colbyconsulting.com
Thu Mar 27 10:00:01 CDT 2008


Thanks James, much appreciated.  I copied it in and it Executes as entered.
I am quite capable of reading that example and understanding what you are
doing, and I very much appreciate the simplicity but functionality.

First question:

RESTORE FILELISTONLY  FROM DISK = @FileName

BOL actually helps me now... And says that you are getting back a list of
the file names involved.  But where does the list of names go?  IOW it isn't
obvious that you are setting some variable to be equal to that list of
filenames.  Are we actually getting it back and using the list somewhere?
Or is this just some code to demonstrate a principal that could be useful
sometime?  Or does executing the Restore Filelist cause SQL Server to get
"primed" internally to do the next step?

Next question, where do I place this USP?  I read somewhere that if it is
placed in the master database then it is accessible everywhere, yet Arthur
indicates that he does not like doing that.  Can I place it right in the DB
that I am copying?  That is my template and contains all of the UDPs that I
have designed so far to perform all of this stuff for me.  Can I execute
code from a database that I am about to make a copy of?

John W. Colby
Colby Consulting
www.ColbyConsulting.com 
-----Original Message-----
From: dba-sqlserver-bounces at databaseadvisors.com
[mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of James
Barash
Sent: Thursday, March 27, 2008 10:14 AM
To: 'Discussion concerning MS SQL Server'
Subject: Re: [dba-SQLServer] Copy a database using Elizabeth's
suggestionplusparameters

John:
Try this:

Create PROCEDURE [dbo].[usp_CopyDatabase]
	
(
	@strDBNameFrom varchar(100),
	@strDBNameTo varchar(100),
	@strDBDir  varchar(255)
)
AS
BEGIN
	SET NOCOUNT ON;
declare @FileName varchar(255),
@MDFName varchar(255),
@NDFName varchar(255),
@strDBNameData varchar(255),
@strDBNameLog varchar(255)

Select @FileName = @strDBDir + @strDBNameFrom + '.bak'

BACKUP DATABASE @strDBNameFrom  TO DISK = @FileName Select @FileName =
@strDBDir + @strDBNameFrom + '.bak'
RESTORE FILELISTONLY  FROM DISK = @FileName

Select @FileName = @strDBDir + @strDBNameFrom + '.bak'
Select @MDFName = @strDBDir + @strDBNameTo + '.mdf'
Select @NDFName = @strDBDir + @strDBNameTo + '.ldf'
Select @strDBNameData = @strDBNameFrom + '_Data'
Select @strDBNameLog = @strDBNameFrom + '_Log'


RESTORE DATABASE @strDBNameTo 
   FROM DISK = @FileName
   WITH MOVE @strDBNameData  TO  @MDFName,
   MOVE @strDBNameLog TO @NDFName

END

It should do exactly what you need.

James Barash
 

-----Original Message-----
From: dba-sqlserver-bounces at databaseadvisors.com
[mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of jwcolby
Sent: Thursday, March 27, 2008 9:34 AM
To: 'Discussion concerning MS SQL Server'
Subject: [dba-SQLServer] Copy a database using Elizabeth's suggestion
plusparameters

Thanks Elizabeth and Gustav.

I tried to get it working using passed in parameters, but promptly got
bogged down in the ever helpful "error near ." error messages.

I need a "FromDbName", a "ToDbName", and a "DbLocationPath" parameter.  Just
to show the kinds of issues that more advanced users never even think about
anymore, but which stop me cold...

I created these parameters in a stored procedure, copied the code in and
started replacing the various pieces with @ParamThis and @paramThat.  I
immediately got the one and only error message that SQL Server knows "error
near @".  

I got out BOL "the ever helpful.." ... Oh, different rant.

I immediately commented out the code pasted in to the SP template and voila,
it "ran".  Uncommented just the first line and get "error near +"

ALTER PROCEDURE [dbo].[usp_CopyDatabase]
	-- Add the parameters for the stored procedure here
	@strDBNameFrom varchar(100),
	@strDBNameTo varchar(100),
	@strDBDir  varchar(255)
AS
BEGIN
	-- SET NOCOUNT ON added to prevent extra result sets from
	-- interfering with SELECT statements.
	SET NOCOUNT ON;

    -- Insert statements for procedure here --BACKUP DATABASE @strDBNameFrom

--   TO DISK = @strDBDir + @strDBNameFrom + '.bak'

--RESTORE FILELISTONLY 
--   FROM DISK = @strDBDir + @strDBNameFrom + '.bak'

--RESTORE DATABASE @strDBNameTo 
--   FROM DISK = @strDBDir + @strDBNameFrom + '.bak'
--   WITH MOVE strDBNameFrom + '_Data' TO  @strDBDir + @strDBNameTo +
'.mdf',
--   MOVE strDBNameFrom + '_Log' TO @strDBDir + @strDBNameTo + '.ldf'
END

My uneducated guess is that as soon as I start actually trying to run this
thing, the parameters have nothing in them so they will not run.  But...

Running it is the only way to "SAVE" the changes right?  So I am kind of
stuck.  So do I have to make my parameters have default values just so the
changes to the code will save?  Or is it even that?  

I can't imagine why I would get frustrated when I get the ever helpful
"error near +".  

John W. Colby
Colby Consulting
www.ColbyConsulting.com
-----Original Message-----
From: dba-sqlserver-bounces at databaseadvisors.com
[mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of Gustav
Brock
Sent: Thursday, March 27, 2008 4:57 AM
To: dba-sqlserver at databaseadvisors.com
Subject: Re: [dba-SQLServer] Copy a database using a store procedureor
function

Hi Elizabeth - and John

The gun smoke distracted me so much from the original question that I had
lost the request of John - to be able to perform this parameterized from
code.

But it seems like your suggestion could be the key of a solution. I found a
minor error ('AdventureWorks_Data' should read just 'AdventureWorks'). With
that corrected I  simply moved your code (skipping the GO) into a
pass-through query in Access:

BACKUP DATABASE somedb 
   TO DISK = 'c:\template2.bak'

RESTORE FILELISTONLY 
   FROM DISK = 'c:\template2.bak'

RESTORE DATABASE newfromtemplate2 
   FROM DISK = 'c:\template2.bak'
   WITH MOVE 'somedb' TO 'c:\newfromtemplate2.mdf',
   MOVE 'somedb_log' TO 'c:\newfromtemplate2.ldf'

Wow! In a few seconds you have a brand new database.
Of course, once a template has been created you can skip the first part with
the backup.

Now, for this to work as to fulfill John's request, you will have to rewrite
the SQL above to reflect the name of the new database but that can be done
with a simple replace of "newfromtemplate2" to the actual new database name
and then execute the query. This John can code with his left hand in Access
and it shouldn't take much to write a small class in VB.net to perform the
same two actions: replace the database name and send the SQL command to the
server.

/gustav

>>> Elizabeth.J.Doering at wellsfargo.com 25-03-2008 21:10 >>>
I haven't used this (being pretty new to this myself), but I'm sure some one
else here can speak to it:

E. Make a copy of a database using BACKUP and RESTORE This example uses both
the BACKUP and RESTORE statements to make a copy of the AdventureWorks
database. The MOVE statement causes the data and log file to be restored to
the specified locations. The RESTORE FILELISTONLY statement is used to
determine the number and names of the files in the database being restored.
The new copy of the database is named TestDB. For more information, see
RESTORE FILELISTONLY (Transact-SQL). 

 Copy Code
BACKUP DATABASE AdventureWorks 
   TO DISK = 'C:\AdventureWorks.bak'

RESTORE FILELISTONLY 
   FROM DISK = 'C:\AdventureWorks.bak'

RESTORE DATABASE TestDB 
   FROM DISK = 'C:\AdventureWorks.bak'
   WITH MOVE 'AdventureWorks_Data' TO 'C:\testdb.mdf',
   MOVE 'AdventureWorks_Log' TO 'C:\testdb.ldf'
GO
 
This is from BOL for SQL Server 2005, which is often amazingly helpful.

HTH,


Liz 


Liz Doering
elizabeth.j.doering at wellsfargo.com
612.667.2447 



_______________________________________________
dba-SQLServer mailing list
dba-SQLServer at databaseadvisors.com
http://databaseadvisors.com/mailman/listinfo/dba-sqlserver
http://www.databaseadvisors.com

_______________________________________________
dba-SQLServer mailing list
dba-SQLServer at databaseadvisors.com
http://databaseadvisors.com/mailman/listinfo/dba-sqlserver
http://www.databaseadvisors.com

_______________________________________________
dba-SQLServer mailing list
dba-SQLServer at databaseadvisors.com
http://databaseadvisors.com/mailman/listinfo/dba-sqlserver
http://www.databaseadvisors.com




More information about the dba-SQLServer mailing list