Dynamically script Create Database For Attach For All Databases
This script will either script out the CREATE DATABASE FOR ATTACH statement for an individual database by passing in the database name or will script out all for the instance. This can be especially handy when migrating to a new server and the drives that the data files are on are moving across. This will work with SQL Server 2005 and 2008 and will work with databases that have Full Text indexing enabled.
Being that sp_attach_db is deprecated this script should be used over the script that was referenced at the beginning of this posting.
Please note, this is a modified version of a script that can be found at this LINK.
IF EXISTS (SELECT name
FROM sys.sysobjects
WHERE name = 'usp_CreateDBForAttach_WithFT')
DROP PROCEDURE usp_createdbforattach_withft
GO
CREATE PROC USP_CREATEDBFORATTACH_WITHFT
@db SYSNAME = NULL
AS
SET nocount ON
SET concat_null_yields_null OFF
DECLARE @cmd VARCHAR(1000),
@a VARCHAR(MAX),
@Filecnt INT,
@cnt INT,
@fileid INT,
@sq CHAR(1),
@dq CHAR(2),
@TempFilename VARCHAR(1000),
@TempFilename1 VARCHAR(1000)
SET @sq = ''''
SET @dq = ''''''
SET @cnt = 1
SET @fileid = 1
IF @db IS NOT NULL
BEGIN
CREATE TABLE #1 (
fileid INT,
filename SYSNAME,
name SYSNAME)
SET @cmd = 'Insert into #1 (fileid,filename,name) select file_id, physical_name, name
from sys.master_files where database_id = db_id('''
+ @db
+ ''')'
EXEC( @cmd)
SELECT @filecnt = (SELECT COUNT(* )
FROM #1)
WHILE @cnt <= @filecnt
BEGIN
SELECT @TempFileName = filename
FROM #1
WHERE fileid = @fileid
SELECT @TempFileName = RTRIM(@TempFileName)
SELECT @a = @a
+ CHAR(13)
+ CHAR(9)
SELECT @a = @a
+ '(Filename = '
+ @sq
+ @TempFilename
+ @sq
+ '),'
SET @cnt = @cnt
+ 1
SET @fileid = (SELECT MIN(fileid)
FROM #1
WHERE fileid > @fileid)
END
SELECT @a = 'CREATE DATABASE '
+ @db
+ ' ON '
+ @a
SELECT @a = (SELECT SUBSTRING(@a,1,LEN(@a)- 1)) --Trim off the final comma; I'm sure there is a better way to do this...
SELECT @a = @a
+ '
FOR ATTACH;
GO'
PRINT @a
END
ELSE
BEGIN
DECLARE db_cursor CURSOR FOR
SELECT name
FROM sysdatabases
WHERE name NOT IN ('tempdb','master','msdb','model')
AND dbid NOT IN (SELECT database_id
FROM sys.databases
WHERE state > 0)
ORDER BY dbid
OPEN db_cursor
FETCH NEXT FROM db_cursor
INTO @db
WHILE @@FETCH_STATUS = 0
BEGIN
CREATE TABLE #2 (
fileid INT,
filename SYSNAME,
name SYSNAME)
SET @cmd = 'Insert into #2 (fileid,filename,name) select file_id, physical_name, name
from sys.master_files where database_id = db_id('''
+ @db
+ ''')'
EXEC( @cmd)
SELECT @filecnt = (SELECT COUNT(* )
FROM #2)
WHILE @cnt <= @filecnt
BEGIN
SELECT @TempFileName = filename
FROM #2
WHERE fileid = @fileid
SELECT @TempFileName = RTRIM(@TempFileName)
SELECT @a = @a
+ CHAR(13)
+ CHAR(9)
SELECT @a = @a
+ '(Filename = '
+ @sq
+ @TempFilename
+ @sq
+ '),'
SET @cnt = @cnt
+ 1
SET @fileid = (SELECT MIN(fileid)
FROM #2
WHERE fileid > @fileid)
END
SELECT @a = 'CREATE DATABASE '
+ @db
+ ' ON '
+ @a
SELECT @a = (SELECT SUBSTRING(@a,1,LEN(@a)- 1)) --Trim off the final comma; I'm sure there is a better way to do this...
SELECT @a = @a
+ '
FOR ATTACH;
GO
'
PRINT @a
SELECT @a = ' '
DROP TABLE #2
SET @cnt = 1
SET @fileid = 1
FETCH NEXT FROM db_cursor
INTO @db
END
CLOSE db_cursor
DEALLOCATE db_cursor
END