by MAK [Muthusamy Anantha Kumar]
With
SQL Server 6.5, Microsoft gave us an opportunity to do a backup (DUMP Table) of
the tables. However, after 6.5, with both 7.0 and 2000, that feature has been
removed for some reason. Here is a stored procedure that I wrote which gives
similar functionality for backing up table data. This is very useful if the
database size is extremely large and you need to backup only a few tables.
Stored Procedure:
use master
go
Create procedure SP_BKUPTables
@Tablelist varchar(2000),
@BackupPath varchar(2000)
as
set nocount on
–Objective: To backup one or more tables
–Created by: MAK
–Date Created : May 2, 2003
–Error Checking
declare @count1 int
declare @i int
declare @table varchar(128)
declare @query varchar(1000)
declare @length int
declare @errorflag tinyint
declare @backupdbname varchar(38)
declare @Tablelist2 varchar(2000)
set @errorflag =0
set @backupdbname =”[”+convert(varchar(36),newid())+”]”If replace(@Tablelist,” “,””)=””
begin
set @errorflag=1
end
If replace(@Backuppath,” “,””)=”” begin
set @Backuppath =(select replace(replace(filename,”tempdb.mdf”,””),” “,””) +
“Mytable.TBL” from sysfiles where fileid =1)
endPrint “USP_BKUPTables Parameters”
Print “_________________________”
Print “Developed by : MAK [Muthusamy Anantha Kumar]”
Print “”
print “Database Name: “+ db_name()
print “Table List : “+ @tablelist
print “Backup Path : “+ @backuppathCreate table #backuptable (id int identity(1,1),name varchar(128))
set @Tablelist2 =@Tablelist +”,”
set @length =len(@tablelist2)
while @length >0
begin
insert into #backuptable select replace(left(@Tablelist2,charindex(‘,’,@Tablelist2,1)),’,’,”)
set @Tablelist2 = replace(@Tablelist2 ,left(@Tablelist2,charindex(‘,’,@Tablelist2,1)),””)
set @length =len(@tablelist2)
end
if (select count(*) from #backuptable) <> (select count(*) from
sysobjects where name in (select name from #backuptable) and type=’u’)
begin
set @errorflag =1
Print “Error********: One or More tables not found”
endset @i=1
–select * from #backuptable
if @errorflag =0
begin
print ” ”
print “Creating temporary database…”
print ” ”exec (“create database “+ @backupdbname )
checkpointselect @count1 = count(*) from #backuptable
print @count1
print ” ”
print “Enabling Select into bulk copy…”
print ” ”
set @query = “sp_dboption “+ @backupdbname+ “,’select into/bulkcopy’,true”
–print @query
exec (@query)
print ” ”
print “Copying Data…”
print ” ”
while @i <= @count1
begin
select @table = name from #backuptable where id = @i
print “Copying “+@Table+”…”
set @query = “select * into “+ @backupdbname +”.dbo.”+ @table + ” from ” + @table
exec (@query)
— print @query
set @i=@i+1
endprint ” ”
print “Backuping Database…”
print ” ”
exec (” backup database “+ @backupdbname + ” to disk = ‘” + @BackupPath + “‘ with init”)print ” ”
print “Dropping Temporary Database…”
print ” ”
exec (“Drop database “+@backupdbname )
end
Usage:
Use SNAR
go
SP_BKUPTables ‘SNAR_Request,mytable1,employee’,’d:mytable.bak’
Go
Process:
The basic concept of this
procedure is to:
- Create a temporary database on
the fly (uses uniqueidentifier as databasename) - Enable temporary database to
handle ‘Select into/bulk copy’ - Copy all the tables in the list
to the temporary database - Take a backup of the temporary
database. If database path is not given (SP_BKUPTables ‘SNAR_request’,”)
then it takes the tempdb’s path as the default path for backup file
location. - Delete the temporary database
Error Messages:
The user gets an error message
when there is no such table (given in the table list) available in the
database.
Conclusion:
Since we create this as a system
stored procedure, it can be executed from any database. Thus by using this
stored procedure, we can recreate the same functionality we had in SQL Server
6.5 (DUMP table). The database can be restored the same way and the data can be
retrieved when necessary. This stored procedure can be used in both SQL Server
7.0 and 2000.