|
| 1 | +-- StagingTurkey / StatingFiltered / MosaicFiltered and MosaicFiltered |
| 2 | + |
| 3 | +-- ============================================================================================================= |
| 4 | +-- Created By: Ajay Kumar Dwivedi |
| 5 | +-- Usage: Generate TSQL Script to move databases from Old path to New Path |
| 6 | +-- https://dba.stackexchange.com/questions/52007/how-do-i-move-sql-server-database-files |
| 7 | +-- Total INPUTS: 3 |
| 8 | +-- ============================================================================================================= |
| 9 | +SET NOCOUNT ON; |
| 10 | + |
| 11 | +-- INPUT 01 -> Path for Data Files |
| 12 | +DECLARE @p_Old_Data_Path varchar(255) = 'K:\'; -- Leave NULL if no change required |
| 13 | +DECLARE @p_New_Data_Path varchar(255) = 'Q:\'; -- Leave NULL if no change required |
| 14 | + |
| 15 | +-- INPUT 02 -> Path for Log Files |
| 16 | +DECLARE @p_Old_Log_Path varchar(255) = 'L:'; -- Leave NULL if no change required |
| 17 | +DECLARE @p_New_Log_Path varchar(255) = 'Q:'; -- Leave NULL if no change required |
| 18 | + |
| 19 | +-- INPUT 03 -> Comma separated list of Databases |
| 20 | +IF OBJECT_ID('tempdb..#Dbs2Consider') IS NOT NULL |
| 21 | + DROP TABLE #Dbs2Consider; |
| 22 | +SELECT d.database_id, d.name, d.recovery_model_desc INTO #Dbs2Consider FROM sys.databases as d |
| 23 | + WHERE d.database_id > 4 |
| 24 | + AND d.name IN ('MosaicFiltered')--,'StagingFiltered','StagingTurkey','MosaicFiltered','MosaicFiltered') |
| 25 | + |
| 26 | +-- Parameter Validations |
| 27 | +DECLARE @NewLineChar AS CHAR(2) = CHAR(13) + CHAR(10) |
| 28 | +DECLARE @_errorMSG VARCHAR(2000); |
| 29 | +DECLARE @_IsValidParameter BIT = 1; |
| 30 | +DECLARE @_Old_Data_Path varchar(255); |
| 31 | +DECLARE @_New_Data_Path varchar(255); |
| 32 | +DECLARE @_DataFileCounts int = 0; |
| 33 | +DECLARE @_Old_Log_Path varchar(255); |
| 34 | +DECLARE @_New_Log_Path varchar(255); |
| 35 | +DECLARE @_LogFileCounts int = 0; |
| 36 | +DECLARE @_robocopy_DataFiles VARCHAR(3000); |
| 37 | +DECLARE @_robocopy_LogFiles VARCHAR(3000); |
| 38 | + |
| 39 | +IF @p_Old_Data_Path IS NULL AND @p_New_Data_Path IS NULL AND @p_Old_Log_Path IS NULL AND @p_New_Log_Path IS NULL BEGIN SET @_IsValidParameter = 0 END |
| 40 | +IF NOT((@p_Old_Data_Path IS NULL AND @p_New_Data_Path IS NULL) OR (@p_Old_Data_Path IS NOT NULL AND @p_New_Data_Path IS NOT NULL)) BEGIN SET @_IsValidParameter = 0 END |
| 41 | +IF NOT((@p_Old_Log_Path IS NULL AND @p_New_Log_Path IS NULL) OR (@p_Old_Log_Path IS NOT NULL AND @p_New_Log_Path IS NOT NULL)) BEGIN SET @_IsValidParameter = 0 END |
| 42 | + |
| 43 | +IF @_IsValidParameter = 0 |
| 44 | +BEGIN |
| 45 | + SET @_errorMSG = 'Kindly provide correct values for @p_Old_Data_Path/@p_New_Data_Path and @p_Old_Log_Path/@p_New_Log_Path.'; |
| 46 | + IF (select CAST(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS VARCHAR(50)),charindex('.',CAST(SERVERPROPERTY('ProductVersion') AS VARCHAR(50)))-1) AS INT)) >= 12 |
| 47 | + EXECUTE sp_executesql N'THROW 50000,@_errorMSG,1',N'@_errorMSG VARCHAR(200)', @_errorMSG; |
| 48 | + ELSE |
| 49 | + EXECUTE sp_executesql N'RAISERROR (@_errorMSG, 16, 1)', N'@_errorMSG VARCHAR(200)', @_errorMSG; |
| 50 | +END |
| 51 | + |
| 52 | +IF @_IsValidParameter = 1 |
| 53 | +BEGIN -- Begin block for @_IsValidParameter = 1 |
| 54 | + SET @_Old_Data_Path = @p_Old_Data_Path; |
| 55 | + SET @_Old_Log_Path = @p_Old_Log_Path; |
| 56 | + |
| 57 | + ;WITH T_File_Paths AS |
| 58 | + ( |
| 59 | + SELECT LEFT(mf.physical_name,LEN(mf.physical_name)-CHARINDEX('\',REVERSE(mf.physical_name))+1) as FilePath, COUNT(*) as FileCounts |
| 60 | + FROM sys.master_files as mf |
| 61 | + WHERE mf.database_id IN (SELECT d.database_id FROM #Dbs2Consider AS d) |
| 62 | + AND (mf.physical_name LIKE (@p_Old_Data_Path+'%') OR mf.physical_name LIKE (@p_Old_Log_Path+'%')) |
| 63 | + GROUP BY LEFT(mf.physical_name,LEN(mf.physical_name)-CHARINDEX('\',REVERSE(mf.physical_name))+1) |
| 64 | + ) |
| 65 | + SELECT @_Old_Data_Path = CASE WHEN LEN(@p_Old_Data_Path) <= 3 THEN CASE WHEN FilePath LIKE (@p_Old_Data_Path+'%') AND @_DataFileCounts < FileCounts THEN FilePath ELSE @_Old_Data_Path END ELSE @_Old_Data_Path END |
| 66 | + ,@_Old_Log_Path = CASE WHEN LEN(@p_Old_Log_Path) <= 3 THEN CASE WHEN FilePath LIKE (@p_Old_Log_Path+'%') AND @_LogFileCounts < FileCounts THEN FilePath ELSE @_Old_Log_Path END ELSE @_Old_Log_Path END |
| 67 | + ,@_New_Data_Path = CASE WHEN LEN(@p_New_Data_Path) <= 3 THEN CASE WHEN FilePath LIKE (@p_Old_Data_Path+'%') AND @_DataFileCounts < FileCounts THEN (LEFT(@p_New_Data_Path,1)+SUBSTRING(FilePath,2,LEN(FilePath))) ELSE @_New_Data_Path END ELSE @p_New_Data_Path END |
| 68 | + ,@_New_Log_Path = CASE WHEN LEN(@p_New_Log_Path) <= 3 THEN CASE WHEN FilePath LIKE (@p_Old_Log_Path+'%') AND @_LogFileCounts < FileCounts THEN (LEFT(@p_New_Log_Path,1)+SUBSTRING(FilePath,2,LEN(FilePath))) ELSE @_New_Log_Path END ELSE @p_New_Log_Path END |
| 69 | + |
| 70 | + ,@_DataFileCounts = CASE WHEN FilePath LIKE (@_Old_Data_Path+'%') AND @_DataFileCounts < FileCounts THEN FileCounts ELSE @_DataFileCounts END |
| 71 | + --,@_LogFileCounts = CASE WHEN FilePath LIKE (@_Old_Log_Path+'%') AND @_LogFileCounts < FileCounts THEN FileCounts ELSE @_LogFileCounts END |
| 72 | + FROM T_File_Paths |
| 73 | + ORDER BY FileCounts desc; |
| 74 | + |
| 75 | + --SELECT [@p_Old_Data_Path] = @p_Old_Data_Path, [@_Old_Data_Path] = @_Old_Data_Path, [@p_New_Data_Path] = @p_New_Data_Path, [@_New_Data_Path] = @_New_Data_Path |
| 76 | + -- ,[@p_Old_Log_Path] = @p_Old_Log_Path, [@_Old_Log_Path] = @_Old_Log_Path, [@p_New_Log_Path] = @p_New_Log_Path, [@_New_Log_Path] = @_New_Log_Path |
| 77 | + |
| 78 | + PRINT '----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' |
| 79 | + SELECT 'ALTER DATABASE '+QUOTENAME(DB_NAME(mf.database_id))+ |
| 80 | + ' MODIFY FILE ( NAME = '''+mf.name+''', FILENAME = '''+ (CASE WHEN mf.type_desc = 'ROWS' THEN ISNULL(@_New_Data_Path,'@_New_Data_Path\') ELSE ISNULL(@_New_Log_Path,'@_New_Log_Path\') END) + (RIGHT(mf.physical_name,CHARINDEX('\',REVERSE(mf.physical_name))-1)) + ''');' + @NewLineChar + 'GO' |
| 81 | + AS [-- ************************* Modify MetaData to Move Data/Log Files *********************] |
| 82 | + FROM sys.master_files as mf |
| 83 | + WHERE mf.database_id IN (SELECT d.database_id FROM #Dbs2Consider AS d) |
| 84 | + AND (mf.physical_name LIKE (@p_Old_Data_Path+'%') OR mf.physical_name LIKE (@p_Old_Log_Path+'%')); |
| 85 | + |
| 86 | + SELECT 'ALTER DATABASE '+QUOTENAME(d.DbName)+' SET OFFLINE WITH ROLLBACK IMMEDIATE;' + @NewLineChar + 'GO' |
| 87 | + FROM ( |
| 88 | + SELECT DISTINCT DB_NAME(mf.database_id) as DbName FROM sys.master_files as mf |
| 89 | + WHERE mf.database_id IN (SELECT d.database_id FROM #Dbs2Consider AS d) AND (mf.physical_name LIKE (@p_Old_Data_Path+'%') OR mf.physical_name LIKE (@p_Old_Log_Path+'%')) |
| 90 | + ) AS d; |
| 91 | + |
| 92 | + -- Move Data Files |
| 93 | + IF @p_Old_Data_Path IS NOT NULL |
| 94 | + BEGIN |
| 95 | + SET @_robocopy_DataFiles = NULL |
| 96 | + PRINT '----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' |
| 97 | + SELECT @_robocopy_DataFiles = COALESCE(@_robocopy_DataFiles+' '+'"'+f.FileBaseName+'"','"'+f.FileBaseName+'"') |
| 98 | + FROM ( |
| 99 | + SELECT (RIGHT(mf.physical_name,CHARINDEX('\',REVERSE(mf.physical_name))-1)) AS FileBaseName FROM sys.master_files as mf WHERE mf.database_id IN (SELECT d.database_id FROM #Dbs2Consider AS d) AND mf.physical_name LIKE (@p_Old_Data_Path+'%') |
| 100 | + ) as f |
| 101 | + SET @_robocopy_DataFiles = 'robocopy "'+ @_Old_Data_Path +'" "'+ @_New_Data_Path + '" '+ @_robocopy_DataFiles + ' /it /MT'; |
| 102 | + |
| 103 | + PRINT 'New-Item -Path "'+@_New_Data_Path+'" -ItemType "directory" -Force | Out-Null;' |
| 104 | + PRINT @_robocopy_DataFiles; |
| 105 | + END |
| 106 | + |
| 107 | + -- Move Log Files |
| 108 | + IF @p_Old_Log_Path IS NOT NULL |
| 109 | + BEGIN |
| 110 | + SET @_robocopy_LogFiles = NULL; |
| 111 | + SELECT @_robocopy_LogFiles = COALESCE(@_robocopy_LogFiles+' '+'"'+f.FileBaseName+'"','"'+f.FileBaseName+'"') |
| 112 | + FROM ( |
| 113 | + SELECT (RIGHT(mf.physical_name,CHARINDEX('\',REVERSE(mf.physical_name))-1)) AS FileBaseName FROM sys.master_files as mf WHERE mf.database_id IN (SELECT d.database_id FROM #Dbs2Consider AS d) AND mf.physical_name LIKE (@p_Old_Log_Path+'%') |
| 114 | + ) as f |
| 115 | + |
| 116 | + SET @_robocopy_LogFiles = 'robocopy "'+ @_Old_Log_Path +'" "'+ @_New_Log_Path + '" '+ @_robocopy_LogFiles + ' /it /MT'; |
| 117 | + |
| 118 | + PRINT 'New-Item -Path "'+@_New_Log_Path+'" -ItemType "directory" -Force | Out-Null;' |
| 119 | + PRINT @_robocopy_LogFiles; |
| 120 | + END |
| 121 | + |
| 122 | + SELECT 'ALTER DATABASE '+QUOTENAME(d.DbName)+' SET ONLINE;' + @NewLineChar + 'GO' |
| 123 | + FROM ( |
| 124 | + SELECT DISTINCT DB_NAME(mf.database_id) as DbName FROM sys.master_files as mf |
| 125 | + WHERE mf.database_id IN (SELECT d.database_id FROM #Dbs2Consider AS d) AND (mf.physical_name LIKE (@p_Old_Data_Path+'%') OR mf.physical_name LIKE (@p_Old_Log_Path+'%')) |
| 126 | + ) AS d; |
| 127 | + |
| 128 | +--SELECT db_name(database_id),* FROM sys.master_files mf where mf.database_id = db_id('Babel') |
| 129 | +END -- End block for @_IsValidParameter = 1 |
0 commit comments