Starting now, is the wrong date for insert…

This is part 2 of my log-shipping journey, if you missed part 1, you can find it here.

I collected all of the file names I need, but you will notice I left the dates off. When my files are moved from one domain to another, their created dates are being changed. I needed the real dates for the correct restore order and to match the backups to the logs. If I were a Dark Knight Powershell master, I am sure I would have figured out how to do it. Every time I started to get close, I would would have a production issue or another distraction that needed my time. In the end I landed in my happy place, so we are fixing the dates in the database!

How do I get the right date for a file when the created date is being changed after it has moved? I was super lucky that the date is being stored in the filename too! (Huge thank you to Ola for his awesome database maintenance solution.)

An example of my filename is this:

Batcentral$Alfred_Batman_LOG_20210610_224501.trn

This is how I dissect the filename to get the date and time from it:

  UPDATE [DBAStuff].[dbo].[LogshippingFile]
  SET CreatedDate = CAST(Substring(FileName, (LEN(FileName)-18),8)  +' '+ (Substring(FileName, (LEN(FileName)-9),2)+ ':' + Substring(FileName, (LEN(FileName)-7),2) + ':' + Substring(FileName, (LEN(FileName)-5),2)) AS DATETIME)
  WHERE CreatedDate IS NULL

My filenames are different lengths which means the the dates won’t always be in the same place, instead I go to the end of the string and count backwards because my dates are always consistent. Then I add all the parts back together to get my datetime and update it into my table.

Are we done yet? Nope, there is more.

The song for this post is Toad the Wet Sprockets’ Starting Now

Someone says “You’re in the wrong place master, you better leave”

Moving system databases. Whenever I have brought this up with a co-worker they seem to get a bit freaked out and want to avoid moving them.  I used to be the same, but happily now I am comfortable moving them around.

Let me first tell you why I want to move them.  I like to have my Data files on the D: drive, Log files on the E: drive, Backup files on the F: and my Tempdb files on the G: Drive.  These are all SAN drives.  This method keeps me consistent for all my servers and I am able to quickly know where to find everything I need.  I am also able to easily identify which drive my problem is on.  But my favorite reason is that in the past (three separate times), I have lost the OS to my SQL Server.  Because I had master, model, and msdb on the D: drive, after a quick re-install of SQL and the correct patch, I was able to re-point to master and everything came up beautifully without further recovery.  I had over 70 databases on one of these instances, and this method prevented me from having to restore each one along with log files. It was a wonderful surprise the first time it worked.

There are performance reasons for splitting out your files on to different drives, but we can get into that later because it requires its own post.

This step comes before I split out my tempdb files, so I am only moving one. You could easily add more lines of code to allow you to move more tempdb files.

So let’s get to the code and you will see how easy it is to do.  You will never fear moving the system databases again. This code is set up for SQL2008, but is easily modified for whatever version you are using.  Just set it up to match the folder structure.


--Check to see where your files are now.

SELECT *
FROM sys.master_files

--Move your files
USE master
GO

ALTER DATABASE model
MODIFY FILE (NAME = modeldev, FILENAME = 'D:\MSSQL10.MSSQLSERVER\MSSQL\DATA\model.mdf');
GO

ALTER DATABASE model
MODIFY FILE (NAME = modellog, FILENAME = 'E:\MSSQL10.MSSQLSERVER\MSSQL\DATA\modellog.ldf');
GO

ALTER DATABASE msdb
MODIFY FILE (NAME = MSDBData, FILENAME = 'D:\MSSQL10.MSSQLSERVER\MSSQL\DATA\MSDBData.mdf');
GO

ALTER DATABASE msdb
MODIFY FILE (NAME = MSDBLog, FILENAME = 'E:\MSSQL10.MSSQLSERVER\MSSQL\DATA\MSDBLog.ldf');
GO

ALTER DATABASE  tempdb
MODIFY FILE (NAME = tempdev, FILENAME = 'G:\MSSQL10.MSSQLSERVER\MSSQL\DATA\tempdb.mdf');
GO

ALTER DATABASE tempdb
MODIFY FILE (NAME = templog, FILENAME = 'G:\MSSQL10.MSSQLSERVER\MSSQL\DATA\templog.ldf');
GO

Stop the SQL Server and physically copy over the files. Restart the SQL Server and verify they moved your files moved.

SELECT *
FROM sys.master_files

Now here is the next part of the magic.  Go to the SQL Server Configuration Manager, right click on your SQL Server and go to Advanced.  There is a line for Start-up Parameters.  You will also need to modify this string to match your version, but I simply paste this in:

-dD:\MSSQL10.MSSQLSERVER\MSSQL\DATA\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\Log\ERRORLOG;-lE:\MSSQL10.MSSQLSERVER\MSSQL\DATA\mastlog.ldf

Then I stop my SQL Server, copy my master files to the right locations and start up SQL Server again.  It is so easy.  Test it out a few times until you are comfortable and then it will be like you are moving them around with a magic wand.

You’ve got to move it, move it!

I have been rushing all week trying to get new development environments upgraded to 2012 while leaving the old environments online. Everyone wants it done now and I wanted to share a few things that are making my job easier.
This first one is a script that makes copying logins across servers so easy. I found this online and feel terrible that I can’t properly accredit it to the person that wrote it. (If you wrote it, let me know and I will update this)

 

USE master
GO
IF OBJECT_ID (‘sp_hexadecimal’) IS NOT NULL
DROP PROCEDURE sp_hexadecimal
GO
CREATE PROCEDURE sp_hexadecimal
@binvalue varbinary(256),
@hexvalue varchar (514) OUTPUT
AS
DECLARE @charvalue varchar (514)
DECLARE @i int
DECLARE @length int
DECLARE @hexstring char(16)
SELECT @charvalue = ‘0x’
SELECT @i = 1
SELECT @length = DATALENGTH (@binvalue)
SELECT @hexstring = ‘0123456789ABCDEF’
WHILE (@i <= @length)
BEGIN
DECLARE @tempint int
DECLARE @firstint int
DECLARE @secondint int
SELECT @tempint = CONVERT(int, SUBSTRING(@binvalue,@i,1))
SELECT @firstint = FLOOR(@tempint/16)
SELECT @secondint = @tempint – (@firstint*16)
SELECT @charvalue = @charvalue +
SUBSTRING(@hexstring, @firstint+1, 1) +
SUBSTRING(@hexstring, @secondint+1, 1)
SELECT @i = @i + 1
END

SELECT @hexvalue = @charvalue
GO

IF OBJECT_ID (‘sp_help_revlogin’) IS NOT NULL
DROP PROCEDURE sp_help_revlogin
GO
CREATE PROCEDURE sp_help_revlogin @login_name sysname = NULL AS
DECLARE @name sysname
DECLARE @type varchar (1)
DECLARE @hasaccess int
DECLARE @denylogin int
DECLARE @is_disabled int
DECLARE @PWD_varbinary varbinary (256)
DECLARE @PWD_string varchar (514)
DECLARE @SID_varbinary varbinary (85)
DECLARE @SID_string varchar (514)
DECLARE @tmpstr varchar (1024)
DECLARE @is_policy_checked varchar (3)
DECLARE @is_expiration_checked varchar (3)

DECLARE @defaultdb sysname

IF (@login_name IS NULL)
DECLARE login_curs CURSOR FOR

SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM
sys.server_principals p LEFT JOIN sys.syslogins l
ON ( l.name = p.name ) WHERE p.type IN ( ‘S’, ‘G’, ‘U’ ) AND p.name <> ‘sa’
ELSE
DECLARE login_curs CURSOR FOR
SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM
sys.server_principals p LEFT JOIN sys.syslogins l
ON ( l.name = p.name ) WHERE p.type IN ( ‘S’, ‘G’, ‘U’ ) AND p.name = @login_name
OPEN login_curs

FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin
IF (@@fetch_status = -1)
BEGIN
PRINT ‘No login(s) found.’
CLOSE login_curs
DEALLOCATE login_curs
RETURN -1
END
SET @tmpstr = ‘/* sp_help_revlogin script ‘
PRINT @tmpstr
SET @tmpstr = ‘** Generated ‘ + CONVERT (varchar, GETDATE()) + ‘ on ‘ + @@SERVERNAME + ‘ */’
PRINT @tmpstr
PRINT ”
WHILE (@@fetch_status <> -1)
BEGIN
IF (@@fetch_status <> -2)
BEGIN
PRINT ”
SET @tmpstr = ‘– Login: ‘ + @name
PRINT @tmpstr
IF (@type IN ( ‘G’, ‘U’))
BEGIN — NT authenticated account/group

SET @tmpstr = ‘CREATE LOGIN ‘ + QUOTENAME( @name ) + ‘ FROM WINDOWS WITH DEFAULT_DATABASE = [‘ + @defaultdb + ‘]’
END
ELSE BEGIN — SQL Server authentication
— obtain password and sid
SET @PWD_varbinary = CAST( LOGINPROPERTY( @name, ‘PasswordHash’ ) AS varbinary (256) )
EXEC sp_hexadecimal @PWD_varbinary, @PWD_string OUT
EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT

— obtain password policy state
SELECT @is_policy_checked = CASE is_policy_checked WHEN 1 THEN ‘ON’ WHEN 0 THEN ‘OFF’ ELSE NULL END FROM sys.sql_logins WHERE name = @name
SELECT @is_expiration_checked = CASE is_expiration_checked WHEN 1 THEN ‘ON’ WHEN 0 THEN ‘OFF’ ELSE NULL END FROM sys.sql_logins WHERE name = @name

SET @tmpstr = ‘CREATE LOGIN ‘ + QUOTENAME( @name ) + ‘ WITH PASSWORD = ‘ + @PWD_string + ‘ HASHED, SID = ‘ + @SID_string + ‘, DEFAULT_DATABASE = [‘ + @defaultdb + ‘]’

IF ( @is_policy_checked IS NOT NULL )
BEGIN
SET @tmpstr = @tmpstr + ‘, CHECK_POLICY = ‘ + @is_policy_checked
END
IF ( @is_expiration_checked IS NOT NULL )
BEGIN
SET @tmpstr = @tmpstr + ‘, CHECK_EXPIRATION = ‘ + @is_expiration_checked
END
END
IF (@denylogin = 1)
BEGIN — login is denied access
SET @tmpstr = @tmpstr + ‘; DENY CONNECT SQL TO ‘ + QUOTENAME( @name )
END
ELSE IF (@hasaccess = 0)
BEGIN — login exists but does not have access
SET @tmpstr = @tmpstr + ‘; REVOKE CONNECT SQL TO ‘ + QUOTENAME( @name )
END
IF (@is_disabled = 1)
BEGIN — login is disabled
SET @tmpstr = @tmpstr + ‘; ALTER LOGIN ‘ + QUOTENAME( @name ) + ‘ DISABLE’
END
PRINT @tmpstr
END

FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin
END
CLOSE login_curs
DEALLOCATE login_curs
RETURN 0
GO

EXEC sp_help_revlogin

 

This next one is awesome too. When you have copied a database to a new server and have SQL logins that you want to sync up really quick, this script is awesome. Run it on each database that has that login.

ALTER USER [LoginName]
WITH LOGIN = [LoginName]

I hope this will save you some time and helps you get to the ball too!

Have a magical day!