Resetting SQL folder and NTFS permissions after a mass move

  • I'm about to do a mass move of hundreds of databases located on a SQL 2012 failover Cluster. We are not migrating the databases regular way but we will attach those during a maintenance window. Both instances have access to the SAN and LUNs by the way.

    It is my understanding that after mounting the existing LUNs on the new SQL 2012 installation (having the Cluster off, of course, to avoid data corruption), the only required step is changing default Data and Log path to new ones, is that correct?

    As an examples, after mounting the LUNs, this is what the new SQL 2012 default instance should see:

    E:\SQLData1\MSSQL\

    E:\SQLlogs\MSSQL\

    So on above scenario, changing default Data and Log path to above should allow me to attach the databases, is that correct?

    Both machines are on the same Domain and the new one will use same Domain account for SQL. Both are plugged to the same SAN.

    I remember trying to do the same on SQL200R2 and even after that, SQL refused to attach the databases. But do not remember exactly what account or account I ended adding via NTFs. I would like to avoid that situation and let SQL to handle the permissions.

    Thanks in advance,

  • Answering myself, and hope it will help someone.

    On my testing environment, I fixed it this way:

    -On the original server, script attach commands using T-SQL, this way (of course, use your own SQL path below):

    SELECT 'CREATE DATABASE ['+ name +'] ON ( FILENAME = "'+ filename + '"),' + '( FILENAME = "F:\SQL_logs\' + name +'_Log.ldf") FOR ATTACH;'

    FROM sys.sysdatabases

    WHERE dbid > 4

    ORDER BY name ASC

    -Mount the LUNs via disk management

    -Change MS-SQL data and log path to the new mount points

    -Reboot SQL service

    -Attach the databases using the previously generated T-SQL attach script.

    After that, I was able to see my SQL databases and mount them via T-SQL.

    Now, SQL2008 and above should apply required NTFS permissions on the target folders after changing the data and log path. If not, it can be forced and reset using this command:

    icacls "E:\SQL_DATA\MSSQL\*" /q /c /t /reset

    ... then, attach the MS-SQL databases using the previous script.

    where the path inside, is the actual parent folder for MS-SQL data or logs. The "*" cannot be omitted.

    Once the NTFS permissions are properly defined, I

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply