If you take full backups using SQL Server maintenance plans and let SQL Server use the default naming convention, you have probably noticed that usually you’ll have file name in the format of “database name + backup + date + time + .bak”. For example, a backup from the master database may look like this: “master_backup_2012_10_02_220558_8601773.bak”. It can be a challenge to script out automatic restores because the numbers on the end of the backup name constantly change. In this tip I will explain how to script out RESTORE DATABASE statements using DateTime functions.
Let’s say we have a folder full of backups like this:
Let’s say our boss wants us to restore Monday’s production backup (Alabama) every Friday afternoon to our development database (Tide). To accomplish this task, we can use the built-in SQL Server DateTime functions.
The below script will restore from the backup created on the first day of the current week. I’ve added comments to explain the code.
-- Declare variables DECLARE @backup nvarchar(200) DECLARE @datebegin datetime DECLARE @dateend datetime -- Initalize variables -- Set @datebegin equal to the first day of the current week SELECT @datebegin = DATEADD(wk,DATEDIFF(wk,0,GETDATE()),0) -- Set @dateend equal to the second day of the current week SELECT @dateend = DATEADD(wk,DATEDIFF(wk,0,GETDATE()),1) -- Set @backup equal to query dependent on datebegin and dateend SELECT TOP 1 @backup = name + '.bak' FROM msdb..backupset WHERE database_name = 'Alabama' AND backup_start_date BETWEEN @datebegin AND @dateend AND type = 'D' -- D is for full backups ORDER BY backup_start_date ASC USE [master] -- Put DB in Single_User Mode ALTER DATABASE [Tide] SET SINGLE_USER WITH ROLLBACK IMMEDIATE -- Restore DB using query from @backup variable RESTORE DATABASE [Tide] FROM DISK = @backup WITH FILE = 1, NOUNLOAD, REPLACE, STATS = 5 GO
Below is a table of useful DateTime functions that you can use for the @datebegin and @dateend variables.
Day | SQL |
Today | SELECT GETDATE() |
Yesterday | SELECT DATEADD(d, -1, GETDATE()) |
First Day of Current Week | SELECT DATEADD(wk, DATEDIFF(wk, 0, GETDATE()), 0) |
Last Day of the Current Week | SELECT DATEADD(wk, DATEDIFF(wk, 0, GETDATE()), 6) |
First Day of the Current Month | SELECT DATEADD(mm,DATEDIFF(mm,0,GETDATE()),0) |
Last Day of the Current Month | SELECT DATEADD(ms,- 3,DATEADD(mm,0,DATEADD(mm,DATEDIFF(mm,0,GETDATE())+1,0))) |
First Day of the Current Year | SELECT DATEADD(yy,DATEDIFF(yy,0,GETDATE()),0) |
Last Day of the Current Year | SELECT DATEADD(ms,-3,DATEADD(yy,0,DATEADD(yy,DATEDIFF(yy,0,GETDATE())+1,0))) |
Another example may include where you need to take a backup from the first of the month of the production database and restore it weekly to the development database. In this situation you can edit the @datebegin and @dateend variables:
--Set @datebegin equal to the first day of the current month SELECT @datebegin = DATEADD(mm,DATEDIFF(mm,0,GETDATE()),0) --Set @dateend equal to the second day of the current month SELECT @dateend = SELECT DATEADD(mm,DATEDIFF(mm,0,GETDATE()),1)