Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Snapshot Dynamicly


Snapshot Dynamicly

Author
Message
@fracionero
@fracionero
SSC Veteran
SSC Veteran (265 reputation)SSC Veteran (265 reputation)SSC Veteran (265 reputation)SSC Veteran (265 reputation)SSC Veteran (265 reputation)SSC Veteran (265 reputation)SSC Veteran (265 reputation)SSC Veteran (265 reputation)

Group: General Forum Members
Points: 265 Visits: 361
Comments posted to this topic are about the item Snapshot Dynamicly

Francisco Racionero
twitter: @fracionero
Robbert Hof
Robbert Hof
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1306 Visits: 834
I had trouble executing the original script. This one worked for me:
You only have to adjust the variable @dbname.
Snapshot will be created in the same folder as the original database.


declare @dbname sysname --Source database name to snapshot
declare @snap sysname --Snapshot Name to create
declare @snap2drop sysname --Sanpshot to drop
declare @command varchar(2000) --Command to execute during the operations
declare @time varchar(20) --Time to compose the snapshot name @snap
declare @filename sysname --Logical file name of source database to asign the new logical name os the sanp
declare @path sysname --Path where will be created the file
declare @snapNum varchar(1) --Suffix to create the snapshot file
declare @snapMinNum varchar(1) --
--Set variables
set nocount on
set @dbname='snap_test'
set @time=convert(varchar(16),GETDATE(),112)
set @snap=@dbname + '_snap_' + @time + '_'

select @filename=name from sys.master_files where database_id=DB_ID(@dbname) and file_id=1
SELECT @path=SUBSTRING(physical_name, 1, CHARINDEX(@dbname , LOWER(physical_name)) - 1)
FROM master.sys.master_files
WHERE database_id = DB_ID(@dbname) AND file_id = 1
IF NOT EXISTS (SELECT name FROM sys.databases WHERE name like @snap + '%')
set @snapNum= '1'
else
begin
select @snapNum=max(right(name,1))+1 from sys.databases where source_database_id =DB_ID(@dbname)
select @snapMinNum=min(right(name,1)) from sys.databases where source_database_id =DB_ID(@dbname)
if @snapNum>3 and @snapMinNum = 1
set @snapNum='2'
if @snapNum>3 and @snapMinNum = 2
set @snapNum='1'
end
-- Final value of new snapshot database
set @snap=@snap + @snapNum
print '***************************************************************************************'
--Drop old snapshot
if (select COUNT(*) from sys.databases where source_database_id=db_id(@dbname) )>=2
begin
select top 1 @snap2drop= DB_NAME(database_id) from sys.databases where source_database_id =db_id(@dbname) order by create_date
begin try
set @command= ('drop database ' + @snap2drop )
exec (@command)
print 'Old Snapshot ' + upper(@snap2drop) + ' of database ' + upper(@dbname) + ' was removed at: ' + convert(varchar(20),getdate(),113)

end try
begin catch
goto error
end catch
end
--Create command
set @command=
'CREATE DATABASE ' + @snap + '
ON (NAME = ' + @filename + ',
FILENAME = ''' + @path + ''+ @snap + '.snap'')
AS SNAPSHOT OF ' + @dbname
-- Snapshot Command execution

begin try
exec (@command)
print 'New Snapshot ' + upper(@snap) + ' of database ' + upper(@dbname) + ' was created at: ' + convert(varchar(20),getdate(),113)
end try
begin catch
goto error
end catch
print '***************************************************************************************'
error:
IF @@ERROR <> 0
SELECT
ERROR_NUMBER() AS ErrorNumber,
ERROR_SEVERITY() AS ErrorSeverity,
ERROR_STATE() as ErrorState,
ERROR_PROCEDURE() as ErrorProcedure,
ERROR_LINE() as ErrorLine,
ERROR_MESSAGE() as ErrorMessage;
set nocount off




Iwas Bornready
Iwas Bornready
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10074 Visits: 885
Thanks for the script.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search