Wednesday, November 21, 2012

How to Use xp_delete_file to Purge Old Backup Files

Continuing on my recent trend of using undocumented stored procedures, this week I thought we can cover using xp_delete_file to purge old backup files from a folder.  This is stored procedure used by the maintenance plans to clean up old backup files, but it makes for a handy purge tool when creating your own backup scripts.

Let's suppose we have a simple script (taken from a recent post on stackoverflow.com) to backup all databases on a server.

DECLARE @name VARCHAR(50); -- Database name
DECLARE @path VARCHAR(256); -- Path for backup files
DECLARE @fileName VARCHAR(256); -- Filename for backup
DECLARE @fileDate VARCHAR(20); -- Used for file name

-- Path to backups.
SET @path = 'D:\Backup\';

-- Get date to include in file name.
SELECT @fileDate = CONVERT(VARCHAR(20),GETDATE(),112);

-- Dynamically get each database on the server.
DECLARE db_cursor CURSOR FOR
SELECT name
FROM master.sys.databases
WHERE name NOT IN ('master','model','msdb','tempdb');

OPEN db_cursor;
FETCH NEXT FROM db_cursor INTO @name;

-- Loop through the list to backup each database.
WHILE @@FETCH_STATUS = 0
BEGIN 
      -- Build the path and file name.
      SET @fileName = @path + @name + '_' + @fileDate + '.BAK';
      -- Backup the database.
      BACKUP DATABASE @name TO DISK = @fileName WITH INIT;
      -- Loop to the next database.
      FETCH NEXT FROM db_cursor INTO @name;
END 

-- Clean up.
CLOSE db_cursor;
DEALLOCATE db_cursor;
GO

The script will create a new database backup file of every database on the server each time it's executed.  However, the path may not have unlimited disk space.  This is where we need to use xp_delete_file.

Xp_delete_file takes a five parameters:

  1. File Type = 0 for backup files or 1 for report files.
  2. Folder Path = The folder to delete files.  The path must end with a backslash "\".
  3. File Extension = This could be 'BAK' or 'TRN' or whatever you normally use.
  4. Date = The cutoff date for what files need to be deleted.
  5. Subfolder = 0 to ignore subfolders, 1 to delete files in subfolders.

To incorporate this into our backup script, we just need to add another parameter to define the cutoff date.

DECLARE @DeleteDate DATETIME = DATEADD(wk,-1,GETDATE());

In this example, we want to purge any backup files that are more than one week old and have a file extension of 'BAK'.

Next we just need to add the xp_delete_file after the backup loop completes.

EXEC master.sys.xp_delete_file 0,@path,'BAK',@DeleteDate,0;

We only need to execute xp_delete_file once with subfolder=0 parameter since all backup files are being stored in the same folder.  If there was a separate subfolder for each database, then we'd change the subfolder parameter to 1 to delete files from each of those database subfolders.

The updated script would look like this.

DECLARE @name VARCHAR(50); -- Database name
DECLARE @path VARCHAR(256); -- Path for backup files
DECLARE @fileName VARCHAR(256); -- Filename for backup
DECLARE @fileDate VARCHAR(20); -- Used for file name
DECLARE @DeleteDate DATETIME = DATEADD(wk,-1,GETDATE()); -- Cutoff date

-- Path to backups.
SET @path = 'D:\Backup\';

-- Get date to include in file name.
SELECT @fileDate = CONVERT(VARCHAR(20),GETDATE(),112);

-- Dynamically get each database on the server.
DECLARE db_cursor CURSOR FOR
SELECT name
FROM master.sys.databases
WHERE name NOT IN ('master','model','msdb','tempdb');

OPEN db_cursor;
FETCH NEXT FROM db_cursor INTO @name;

-- Loop through the list to backup each database.
WHILE @@FETCH_STATUS = 0
BEGIN 
      -- Build the path and file name.
      SET @fileName = @path + @name + '_' + @fileDate + '.BAK';
      -- Backup the database.
      BACKUP DATABASE @name TO DISK = @fileName WITH INIT;
      -- Loop to the next database.
      FETCH NEXT FROM db_cursor INTO @name;
END 

-- Purge old backup files from disk.
EXEC master.sys.xp_delete_file 0,@path,'BAK',@DeleteDate,0;

-- Clean up.
CLOSE db_cursor;
DEALLOCATE db_cursor;
GO

Don't let the stored procedure file name, xp_delete_file, fool you.  Microsoft has some internal code that only allows for the deletion of database and transaction log backup files.  The stored procedure cannot be used to delete any other type of file.

Yes, it really is that simple.


Tuesday, November 13, 2012

How to Use xp_dirtree to List All Files in a Folder

UPDATED -- Dec 31, 2012 -- Be sure to read Part 2 of this post discussing xp_dirtree.

Last week I blogged about how to use an undocumented stored procedures to create folders.  This week we need to do the opposite.  We need to get a list of all files from a subfolder in order to process them.  In order to do that, we'll use another undocumented extended stored procedure; master.sys.xp_dirtree.  This stored procedure will display a list of every folder, every subfolder, and every file for path you give it.

Xp_dirtree has three parameters: 
  1. directory - This is the directory you pass when you call the stored procedure; for example 'D:\Backup'.
  2. depth  - This tells the stored procedure how many subfolder levels to display.  The default of 0 will display all subfolders.
  3. file - This will either display files as well as each folder.  The default of 0 will not display any files.
For today's example, we just want to display all of our backup files (*.BAK) in a particular folder. We need to all of the other parameters in order to show the files as well as any subfolders.

EXEC master.sys.xp_dirtree 'D:\Backup\TRON4\TEST2\MyDb1',0,1;

The output below will show us each subfolder and every file for the given directory.


We're only concerned about the BAK files.  So we'll need to create a temp table to hold the output of xp_dirtree.  Then we can select only the rows that are an actual file (isfile = 1) and that have a file extension of BAK.

IF OBJECT_ID('tempdb..#DirectoryTree') IS NOT NULL
      DROP TABLE #DirectoryTree;

CREATE TABLE #DirectoryTree (
       id int IDENTITY(1,1)
      ,subdirectory nvarchar(512)
      ,depth int
      ,isfile bit);

INSERT #DirectoryTree (subdirectory,depth,isfile)
EXEC master.sys.xp_dirtree 'D:\Backup\TRON4\TEST2\MyDb1',1,1;

SELECT * FROM #DirectoryTree
WHERE isfile =AND RIGHT(subdirectory,4) = '.BAK'
ORDER BY id;
GO

Below is the output.


This example only shows the files for a specific subfolder, which is used to get a list of files that are needed for purging before another database backup runs.  This stored procedure also can accept UNC paths (\\Server\Folder) to get a list of files and subfolders from a network drive.  In a future post, I will add on to this script to show all files in all subfolders for a given directory.  Until then, play around with xp_dirtree and its parameters to see the different outputs.  You may be able to incorporate this into your own code.

Tuesday, November 6, 2012

Dynamically Create a Folder for Each Database

If you're a DBA like me then you're probably pretty detail-oriented and like to keep things very organized.  For example, when doing database backups, I like to have a specific folder structure to hold the backup files for each database.  See below:


D:\Backup\Server\Instance\MyDb1
D:\Backup\Server\Instance\MyDb2
D:\Backup\Server\Instance\MyDb3

In order to make this happen automatically, my TSQL backup jobs need to have code that will create folders when a new database is added or when the jobs are initially setup.  SQL offers an undocumented extended stored procedures that allow us to create them on the fly; master.sys.xp_create_subdir.

Master.sys.xp_create_subdir will create whatever folder listing you pass it.  For example, if you pass it 'D:\Backup\Server\Instance\MyDb1', it will create each of those folders.  If any of those folders already exist, then it will ignore it and move on to the next one.

So if we need to create a folder for each database before running our backup job, then we can execute a block of code such as this.


DECLARE
       @BaseFolder nvarchar(128)
      ,@DatabaseFolder nvarchar(256)
      ,@DbName sysname
     
-- Only one input parameter needed from the user.
SET @BaseFolder = 'D:\Backup';

DECLARE Db CURSOR FOR
SELECT name FROM sys.databases WHERE name <> 'tempdb';

OPEN Db;
FETCH NEXT FROM Db INTO @DbName;
WHILE @@FETCH_STATUS = 0
BEGIN
      -- Dynamically create a folder for each database.
      SET @DatabaseFolder = @BaseFolder + '\'
      + CONVERT(nvarchar,SERVERPROPERTY('MachineName')) + '\'
      + ISNULL(CONVERT(nvarchar,SERVERPROPERTY('InstanceName')),'DEFAULT')
      + '\' + @DbName;
      EXEC master.sys.xp_create_subdir @DatabaseFolder;
      FETCH NEXT FROM Db INTO @DbName;
END

-- Clean up
CLOSE Db;
DEALLOCATE Db;
GO

On our test server we have three user databases plus the usual system databases, so we end up with a folder structure like this.


This example creates folders for backups; however, the same code can be adapted for any number of uses, and you can even pass UNC paths (\\Server\Folder\) so you can create network folders as well.