Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server 2016 (13.x) and later
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics
Analytics Platform System (PDW)
SQL database in Microsoft Fabric
You can disable foreign key constraints for replication in SQL Server by using SQL Server Management Studio or Transact-SQL. This can be useful if you are publishing data from a previous version of SQL Server.
Note
If a table is published using replication, foreign key constraints are automatically disabled for operations performed by replication agents. The NOT FOR REPLICATION option is specified by default for foreign key constraints and check constraints; the constraints are enforced for user operations but not agent operations. When a replication agent performs an insert, update, or delete at a Subscriber, the constraint is not checked; if a user performs an insert, update, or delete, the constraint is checked. The constraint is disabled for the replication agent because the constraint was already checked at the Publisher when the data was originally inserted, updated, or deleted.
Requires ALTER permission on the table.
In Object Explorer, expand the table with the foreign key constraint you want to modify, and then expand the Keys folder.
Right-click the foreign key constraint and then select Modify.
In the Foreign Key Relationships dialog box, select a value of No for Enforce For Replication.
Select Close.
To perform this task in Transact-SQL, script out the foreign key constraint. In Object Explorer, expand the table with the foreign key constraint you want to modify, and then expand the Keys folder.
Right-click the foreign key constraint, select Script Key As, then select DROP and CREATE To, then select New Query Editor Window. The resulting script should look similar the following example from the AdventureWorks2022
sample database:
ALTER TABLE [Sales].[SalesTerritoryHistory]
DROP CONSTRAINT [FK_SalesTerritoryHistory_SalesPerson_BusinessEntityID]
GO
ALTER TABLE [Sales].[SalesTerritoryHistory] WITH CHECK
ADD CONSTRAINT [FK_SalesTerritoryHistory_SalesPerson_BusinessEntityID]
FOREIGN KEY([BusinessEntityID])
REFERENCES [Sales].[SalesPerson] ([BusinessEntityID]);
GO
ALTER TABLE [Sales].[SalesTerritoryHistory]
CHECK CONSTRAINT [FK_SalesTerritoryHistory_SalesPerson_BusinessEntityID]
GO
In the ALTER TABLE ... ADD CONSTRAINT
portion of the script, modify the new foreign key constraint and specify the NOT FOR REPLICATION option. For example:
ALTER TABLE [Sales].[SalesTerritoryHistory]
DROP CONSTRAINT [FK_SalesTerritoryHistory_SalesPerson_BusinessEntityID]
GO
ALTER TABLE [Sales].[SalesTerritoryHistory] WITH CHECK
ADD CONSTRAINT [FK_SalesTerritoryHistory_SalesPerson_BusinessEntityID]
FOREIGN KEY([BusinessEntityID])
REFERENCES [Sales].[SalesPerson] ([BusinessEntityID])
NOT FOR REPLICATION; --added to disable constraint for replication
GO
ALTER TABLE [Sales].[SalesTerritoryHistory]
CHECK CONSTRAINT [FK_SalesTerritoryHistory_SalesPerson_BusinessEntityID]
GO
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining
Learning path
Design and implement a replication strategy for Azure Cosmos DB for NoSQL - Training
Design and implement a replication strategy for Azure Cosmos DB for NoSQL
Documentation
Disable Foreign Key Constraints in INSERT and UPDATE Statements - SQL Server
Disable Foreign Key Constraints with INSERT and UPDATE Statements
Disable check constraints with INSERT and UPDATE statements - SQL Server
Disable Check Constraints with INSERT and UPDATE Statements
View Foreign Key Properties - SQL Server
View the foreign key attributes of a relationship with SQL Server Management Studio or T-SQL queries.