One of the very common activities a SQL developer face is to flush records from ALL the tables in their development database.
Though “Delete” and “Truncate” commands can be used to flush records in a table the issue is we can’t use them directly if we have constraints attached to some of the tables.
One of the solutions is to “Delete” records in the tables in an orderly fashion. Like, “Delete” the child table first and then the parent table. As long as there are limited number of tables in the Database this solution is more than enough. But for those databases where there are lots of tables with constraints this solution would be pretty tough to implement. In those cases, try out my solution which I have explained later in this article.
Code snippet to reproduce the foreign key conflict error:
Create Table TruncateTblDemo
(
[Sno] int identity,
[FirstName] varchar(50),
[SalaryBandID] int
)
Go
Create Table TruncateTblDemo_SalaryBand
(
[BandID] int identity primary key,
[BandName] varchar(50)
)
Go
Alter table TruncateTblDemo Add
Constraint [FK_TruncateTblDemo_TruncateTblDemo_SalaryBand] Foreign Key
(
[SalaryBandID]
)
References [TruncateTblDemo_SalaryBand]
(
[BandID]
)
Go
Insert into TruncateTblDemo_SalaryBand Values ('Analyst')
Insert into TruncateTblDemo_SalaryBand Values ('Sr. Analyst')
Insert into TruncateTblDemo_SalaryBand Values ('Module Lead')
Insert into TruncateTblDemo_SalaryBand Values ('Technical Lead')
Go
Insert into TruncateTblDemo Values ('Vadivel', 1)
Insert into TruncateTblDemo Values ('Sailakshmi', 2)
Go
/*
The below code would throw an error message saying "it cannot delete / truncate because it is being referenced by a FOREIGN KEY constraint."
*/
Truncate table TruncateTblDemo_SalaryBand
Delete from TruncateTblDemo_SalaryBand
Usual or Normal Solution
Delete from TruncateTblDemo -– Child Table
Delete from TruncateTblDemo_SalaryBand –- Parent Table
Easiest Solution which would work for any [SQL Server] Database design
This solution is a 3 step process.
- Disable all constraints
- Delete or Truncate data
- Enable Constraints back
Code snippet
Alter Procedure usp_FlushRecords_AllTables
As
/*********************************************************
Stored Procedure: usp_FlushRecords_AllTables
Creation Date: 07/24/2006
Written by: Vadivel Mohanakrishnan
P
Test: Exec usp_FlushRecords_AllTables **********************************************************/
Set nocount on
Exec sp_MSForEachTable 'Alter Table ? NoCheck Constraint All'
Exec sp_MSForEachTable
'
If ObjectProperty(Object_ID(''?''), ''TableHasForeignRef'')=1
Begin
-- Just to know what all table used delete syntax.
Print ''Delete from '' + ''?''
Delete From ?
End
Else
Begin
-- Just to know what all table used Truncate syntax.
Print ''Truncate Table '' + ''?''
Truncate Table ?
End
'
Exec sp_MSForEachTable 'Alter Table ? Check Constraint All'
Points to note
- This stored procedure can be used against any SQL Server database design.
- Try this out in your local or development box ONLY.
- “sp_MSForEachTable” is an undocumented stored procedure of Microsoft
- You could save this SP within “Model” database. That way, all future databases which are created on that server would by default get this SP in it.
Technorati tags: SQL, Databases, SQL Server
Comments
Suggestion:
To see progress, because PRINT has to wait until the buffer is full before it will show you "progress" in the messages tab, try:
EXEC sp_MSForEachTable '
DECLARE @MSG nvarchar(4000)
If ObjectProperty(Object_ID(''?''), ''TableHasForeignRef'') = 1
BEGIN
-- Just to know which tables used delete syntax.
SET @MSG = ''DELETE FROM '' + ''?''
RAISERROR(@MSG,0,1) WITH NOWAIT
DELETE FROM ?
END
ELSE
BEGIN
-- Just to know which tables used Truncate syntax.
SET @MSG = ''TRUNCATE TABLE '' + ''?''
RAISERROR(@MSG,0,1) WITH NOWAIT
TRUNCATE TABLE ?
End
'
Sorry, don't know HTML or I'd have preserved the formatting :(
Thanks to both of you.
Made short work of what would have been an onerous task on a big database.
Cheers.
Ed.
Sapnah
Thanks
Siva
Set nocount on
Exec sp_MSForEachTable 'Alter Table ? NoCheck Constraint All'
EXEC sp_MSForEachTable '
DECLARE @MSG nvarchar(4000)
If CHARINDEX(''[dbo].[sys'', ''?'') = 0
BEGIN
If ObjectProperty(Object_ID(''?''), ''TableHasForeignRef'') = 1
BEGIN
-- Just to know which tables used delete syntax.
SET @MSG = ''DELETE FROM '' + ''?''
RAISERROR(@MSG,0,1) WITH NOWAIT
DELETE FROM ?
END
ELSE
BEGIN
-- Just to know which tables used Truncate syntax.
SET @MSG = ''TRUNCATE TABLE '' + ''?''
RAISERROR(@MSG,0,1) WITH NOWAIT
TRUNCATE TABLE ?
End
End
'
Exec sp_MSForEachTable 'Alter Table ? Check Constraint All'