Skip to content
GitLab
Menu
Projects
Groups
Snippets
Loading...
Help
Help
Support
Community forum
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
Menu
Open sidebar
dwentzel
SQLScripts
Commits
4fe8bf93
Commit
4fe8bf93
authored
Mar 05, 2014
by
dwentzel
Browse files
moved CreateSnapshot from svn
parent
1613efdf
Changes
2
Hide whitespace changes
Inline
Side-by-side
CreateSnapshot.sql
0 → 100644
View file @
4fe8bf93
/*
creates a database snapshot of the current database, placing the NTFS sparse files into the same folder
as the actual datafiles. PRINTs out the command to restore the database back to the snapshot.
I use this to test quickly some code where transaction control may not be possible and I know I want to quickly
rollback my changes to the database.
EXEC dbo.CreateSnapshot 'Test_SNAP'
*/
if
exists
(
select
*
from
sys
.
objects
where
object_id
=
object_id
(
'dbo.CreateSnapshot'
))
BEGIN
drop
proc
dbo
.
CreateSnapshot
END
GO
CREATE
PROC
dbo
.
CreateSnapshot
(
@
SnapshotName
varchar
(
255
)
)
AS
BEGIN
DECLARE
@
exec_sql
VARCHAR
(
MAX
)
-- get logical file names
SELECT
name
,
physical_name
INTO
#
FileNames
FROM
sys
.
database_files
WHERE
type
=
0
--rows data, no ldf
SELECT
@
exec_sql
=
'CREATE DATABASE '
+
QUOTENAME
(
@
SnapshotName
)
+
' ON '
SELECT
@
exec_sql
=
@
exec_sql
+
CHAR
(
13
)
+
CHAR
(
10
)
+
'(NAME ='
+
QUOTENAME
(
Name
)
+
', FILENAME =
''
'
+
physical_name
+
'.snap
''
),'
FROM
#
FileNames
SELECT
@
exec_sql
=
LEFT
(
@
exec_sql
,
len
(
@
exec_sql
)
-
1
)
+
CHAR
(
13
)
+
CHAR
(
10
)
+
' AS SNAPSHOT OF '
+
DB_NAME
()
PRINT
'This is the command to run'
PRINT
@
exec_sql
--EXEC (@exec_sql)
PRINT
'This command can be used to RESTORE your db from the snapshot'
PRINT
'RESTORE DATABASE '
+
DB_NAME
()
+
' FROM DATABASE_SNAPSHOT = '
+
@
SnapshotName
+
';'
END
;
GO
\ No newline at end of file
README.txt
View file @
4fe8bf93
...
...
@@ -14,3 +14,9 @@ DatabaseBuildProcess : this is my old database build process. I have since migr
MD3 process which also resides in my git repo. MD3 uses PoSH so it's a little more
modern. It also has a ton of useability improvements. There is still some code in here that
I occassionally borrow however.
CreateSnapshot.sql : http://www.davewentzel.com/content/automatic-database-snapshot-creation-script. Quickly
creates a database snapshot and provides you with the commands to restore the db back to the
snapshot. This is great when testing some code (not in prod) where transaction control may
not be possible (such as testing service broker features). This will allow you to quickly
"roll back" any changes.
\ No newline at end of file
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
.
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment