ALTER TABLE SWITCH statement failed. Check constraint '%.*ls' in source table '%.*ls' and check constraint '%.*ls' in target table '%.*ls' have different 'Not For Replication' settings.

Error Message:
Msg 4972, Level 16, State 1, Line 2
ALTER TABLE SWITCH statement failed. Check constraint ‘%.*ls’ in source table ‘%.*ls’ and check constraint ‘%.*ls’ in target table ‘%.*ls’ have different ‘Not For Replication’ settings.

Severity level:
16.

Description:
This error message appears when you try to execute an ALTER TABLE SWITCH command, for which source and target table have a different replication setting for a CHECK constraint.

Consequences:
The T-SQL statement can be parsed, but causes the error at runtime.

Resolution:
Errors of the Severity Level 16 are generated by the user and can be fixed by the SQL Server user. The statement cannot be executed this way. Source and target table must have identical replication settings for CHECK constraints.

Versions:
This error message was introduced with SQL Server 2005.

Example(s):
USE Pubs
GO
SET NUMERIC_ROUNDABORT OFF;
SET ANSI_PADDING,
    ANSI_WARNINGS,
    CONCAT_NULL_YIELDS_NULL,
    ARITHABORT,
    QUOTED_IDENTIFIER,
    ANSI_NULLS ON;
GO

CREATE PARTITION FUNCTION myPartFunction (int)
    AS RANGE LEFT FOR VALUES (1, 10, 100);
GO

CREATE PARTITION SCHEME myPartScheme
    AS PARTITION myPartFunction
   ALL TO ([PRIMARY]);
GO

CREATE TABLE myPartTable
(
 c1 int
 CONSTRAINT chk_myNonPartTable_c0 CHECK NOT FOR REPLICATION (c1<>0)
)
ON myPartScheme (c1);

GO
CREATE TABLE myNonPartTable
(
 c1 int
 CONSTRAINT chk_myNonPartTable_c1 CHECK(c1<>0)
)
ON [PRIMARY];
GO

ALTER TABLE myPartTable SWITCH PARTITION 1 TO dbo.myNonPartTable ;
GO

DROP TABLE myNonPartTable, myPartTable;
DROP PARTITION SCHEME myPartScheme;
DROP PARTITION FUNCTION myPartFunction;

Remarks:
In the above example we try to execute an ALTER TABLE SWITCH command. Because the CHECK constraint has a “NOT FOR REPLICATION” setting in the source table, but not in the target tabel, the error is raised.

]]>

Leave a comment

Your email address will not be published.