Tags
Advanced SQL Interview Questions and Answers, Advanced SQL tutorial pdf, ALTER Table - [ WITH { CHECK | NOCHECK } ] { CHECK | NOCHECK } CONSTRAINT - A Deep Dive, alter table MyTable with check check constraint all - MSDN - Microsoft, any recommended websites for sql puzzles, Best SQL Puzzles, Buy SQL Server Interview Questions Book Online at Low Price, COmples tSQL puzzles, Complex SQL Challenges, complex sql statement(puzzle), Complex tsql, Complex TSQL Challenge, convert string to proper case in sql server, Create Check Constraints | Microsoft Docs, Creating and Modifying CHECK Constraints, Creating and Modifying CHECK Constraints - TechNet - Microsoft, Divide rows into two columns, Download SQL Questions, Download SQL Server Interview Question in PDF, Download SQL SERVER Interview questions, Download SQL Server Interview questions and answers, download sql server interview questions and answers pdf, download sql server interview questions by Pawan Khowal, download sql server interview questions by Pawan Kumar, download sql server interview questions by Pawan Kumar Khowal, Download T-SQL Interview Questions, Foreign Keys or Check Constraints Not Trusted, Free Download SQL SERVER Interview questions, Get Next Value Puzzle, Huge blank areas in database field, Improve SQL Skills, Interview Puzzles in SQL Server, Interview Qs.SQL SERVER Questions, Interview questions and Answers for MS SQL Server designing, Interview Questions and Answers For SQL, Interview questions on Joins, Interview Questions on SQL, Interview SQL Puzzles, InterviewQuestions, InterviewQuestions for SQL, Learn complex SQL, Learn SQL, Learn T-SQL, Microsoft SQL Server interview questions for DBA, MS SQL Server interview questions, MSBI Interview Questions, Objective Puzzle, Pawan, Pawan Khowal, Pawan Kumar, Pawan Kumar Khowal, PL/SQL Challenges, Puzzle SQL, puzzle sql developer, Puzzle SQl Server, Puzzles, PUzzles in SQL SERVER, Queries for SQL Interview, Remove Huge Multiple Spaces from a DB Fields, Remove Multiple Spaces from a DB Fields, Separate Int and char from a string column, Single Quote update SQL, SQL, SQL - The Pattern Puzzles, sql - WITH CHECK ADD CONSTRAINT followed by CHECK CONSTRA, SQL 2012, SQL 2014, SQL 2014 Interview Questions, SQL Challenge, SQL Challenges, SQL Extreme Difficult Puzzle, SQL FAQ, SQL FAQs, sql group by only rows which are in sequence, SQL Interview Q & A, SQL Interview Questions, SQL Interview Questions - Part 2, SQL Interview Questions for SQL Professionals, SQL Joins, SQL Pattern Puzzles, SQL pl/sql puzzles, SQL prime number puzzle, SQL puzzle, SQL Puzzles, sql puzzles & answers, sql puzzles and answers free download, sql puzzles and answers pdf, sql puzzles for interview, sql puzzles oracle, SQL Queries, SQL Queries asked in interviews, SQL QUERY PUZZLES, SQL Query to Find Nth Highest Salary of Employee, SQL Questions, SQL Quiz, SQL Replace Puzzle, SQL Server - Common Interview Questions and Answers, SQL SERVER - Find Nth Highest Salary of Employee, SQL Server - General Interview Questions and Answers, sql server - What is a WITH CHECK CHECK CONSTRAINT? - Database, sql server 2008 interview questions, SQL Server 2008 Interview Questions and Answers, SQL Server Database, SQL Server database developer interview questions and answers, sql server dba interview questions, SQL Server developer Interview questions and answers, SQL Server developer Interview questions with answers, SQL Server Developer T-SQL Interview Questions, SQL server filter index with LIKE and RIGHT function?, SQL Server Interview Puzzle, SQL SERVER Interview questions, SQL SERVER Interview questions & Answers, SQL Server Interview Questions - Part 1, SQL Server Interview questions and answers, SQL Server Interview Questions and Answers - Free PDF, SQL SERVER Interview questions and answers for experienced, sql server interview questions and answers for net developers, SQL Server Interview Questions And Answers.pdf, sql server interview questions by Pawan Khowal sql interview questions, SQL SERVER Interview questions pdf, SQL Server Interview Questions | MSBISKILLS.Com, SQL Server Interview Questions | MSBISKILLS.com Top 50 SQL Server Questions & Answers, SQL Server Interview Questions/Answers Part-1, SQL Server Puzzle, SQL SERVER Puzzles, SQL server Questions and Answers, SQL SERVER Tips, SQL Server: Check Constraints - TechOnTheNet, SQL Skills, SQL Sudoku, SQL Tips & Tricks, SQL Tips and Tricks, SQL Top clause, SQL Tough Puzzle, SQL Tricks, SQL Trikcy question, sql/database interview for puzzle sql developer, SQLBI Interview Questions, SQLSERVER, SUM of grouped COUNT in SQL Query, T SQL Puzzles, T-SQL Challenge, T-SQL Interview Questions | SQL Server Interviews and Jobs, T-SQL Puzzle, T-SQL Server Interview Questions, T-SQL Tricky Puzzles, The Status Puzzle, Top 10 Frequently Asked SQL Query Interview Questions, TOP 100 SQL SERVER INTERVIEW QUESTIONS QUERIES, Top 50 SQL Server Interview Question for Testers, Tough SQL Challenges, Tough SQL Puzzles, Tricky Questions, TSQL, TSQL Challenge, TSQL Challenges, TSQL Interview questions, TSQL Puzzle, TSQL Puzzles, TSQL Queries, What is a WITH CHECK CHECK CONSTRAINT?, WITH CHECK ADD CONSTRAINT followed by CHECK CONSTRAINT vs. ADD CONSTRAINT, WITH { CHECK | NOCHECK } ] { CHECK | NOCHECK } CONSTRAINT
ALTER Table – [ WITH { CHECK | NOCHECK } ] { CHECK | NOCHECK } CONSTRAINT – A Deep Dive
In this post we will understand what is [with Check/No] , where they will be used and what is check/nocheck constraint and how we can utilise them. Yesterday one of my fellow Senior architect asked this question so I thought of sharing the details with you guys. In this post we shall not discussing the types of constraints and how we can use each types of constraint with real life scenarios.
So basically we need use alter table command to modifies a table definition
1. by adding constraints or dropping constraints.
2. by disabling or enabling constraints.
Syntax of Alter Table with CONSTRAINT
-- ALTER TABLE [ database_name . [ schema_name ] . | schema_name . ] table_name .... | [ WITH { CHECK | NOCHECK } ] { CHECK | NOCHECK } CONSTRAINT { ALL | constraint_name [ ,...n ] } -- |
Let’s first understand what is CHECK OR NOCHECK CONSTRAINT or how we can enable or disable the constraint.
CHECK CONSTRAINT – is used to enable the constraint. Below is the syntax to enable a single constraint.
-- ALTER TABLE testConstraints CHECK CONSTRAINT chk_Vals GO -- |
NOCHECK CONSTRAINT – is used to disable the constraint. Below is the syntax to disable a single constraint.
-- ALTER TABLE testConstraints NOCHECK CONSTRAINT chk_Vals GO -- |
Now Let’s understand the concepts via examples
Let’s first create a sample table and insert some data into it.
-- /* Create a sample table*/ CREATE TABLE testConstraints ( Id INT PRIMARY KEY ,Vals INT ) GO /*Insert some data in the table*/ INSERT INTO testConstraints VALUES (1,1), (2,2), (3,2) GO -- |
Now let’s create a unique constraint on column Vals with name ak_Vals
/* Alter Table command to create a new constraint */
-- ALTER TABLE testConstraints ADD CONSTRAINT chk_Vals CHECK (Vals > 5); GO -- |
OUTPUT
-- Msg 547, Level 16, State 0, Line 19 The ALTER TABLE statement conflicted with the CHECK constraint "chk_Vals". The conflict occurred in database "master", table "dbo.testConstraints", column 'Vals'. -- |
So the output in layman terms is that we cannnot create the check constraint because we have conflicting data in our vals column. This also means that when we create a constraint SQL will verify the existing data with the constraint we are creating and it will only create the constraint if it succeeds.
Now let’s delete all the existing data from our table testConstraints and insert some fresh data which is in accordance with our check constraint
-- TRUNCATE TABLE testConstraints GO INSERT INTO testConstraints VALUES (1,10), (2,21), (3,25) GO -- |
Now let’s again create the new CHECK constaint using below command
-- ALTER TABLE testConstraints ADD CONSTRAINT chk_Vals CHECK (Vals > 5); GO -- |
This time we are able to sucessfully create the constraint because the existing data passed the constraint check.
Now let’s try to insert a value in vals column which is less than 5. So in this case I am inserting 4, Let’s see what happens.</span
-- INSERT INTO testConstraints VALUES (4,4) GO --OUTPUT Msg 547, Level 16, State 0, Line 50 The INSERT statement conflicted with the CHECK constraint "chk_Vals". The conflict occurred in database "master", table "dbo.testConstraints", column 'Vals'. The statement has been terminated. -- |
This means that the constraint worked and SQL does not allowed us to insert the data less than 5.
So for that lets now disable the index. The system for the same is –
Disable single constraint
-- INSERT INTO testConstraints VALUES (4,4) GO ALTER TABLE testConstraints NOCHECK CONSTRAINT chk_Vals GO -- |
Now let’s again try to insert the data using below command.
-- INSERT INTO testConstraints VALUES (4,4) GO -- (1 row affected) -- |
This time we are able to insert the data. Now let’s again enable the constraint.
Enable single constraint
-- ALTER TABLE testConstraints CHECK CONSTRAINT chk_Vals GO --OUTPUT Commands completed successfully. -- |
The constraint is enabled sucessfully. Also note that we have data in the table that conflicts with the CHECK constraint “chk_Vals” still SQL SERVER here does not gave any issues. This is because SQL SERVER has not compared the existing data according to the constraints we have created. So this is the default behaviour when you enable the constraint.
Now lets again try to insert conflicting data.
-- INSERT INTO testConstraints VALUES (5,2) GO -OUTPUT Msg 547, Level 16, State 0, Line 89 The INSERT statement conflicted with the CHECK constraint "chk_Vals". The conflict occurred in database "master", table "dbo.testConstraints", column 'Vals'. The statement has been terminated. -- |
Here clearly SQL SERVER checked the newly inserted data with the constraint and since the data fails SQL will not insert this row.
Lets checks the data in the table.
-- SELECT * FROM testConstraints GO Id Vals ----------- ----------- 1 10 2 21 3 25 4 4 (4 rows affected) -- |
With above output it is clear that (5,2) row has not been inserted.
So what we need to do if we need to check the existing data while enabling the constraint. For that we need to use the following command.
-- ALTER TABLE testConstraints WITH CHECK CHECK CONSTRAINT chk_Vals GO --OUTPUT Msg 547, Level 16, State 0, Line 116 The ALTER TABLE statement conflicted with the CHECK constraint "chk_Vals". The conflict occurred in database "master", table "dbo.testConstraints", column 'Vals'. -- |
So when you execute the command it will say that table has some data that conflicts with the constraint.
Another thing is that if you do not want SQL SERVER to verify the existing data with the constraint then you can use below.
-- ALTER TABLE testConstraints WITH NOCHECK CHECK CONSTRAINT chk_Vals GO -- |
OR
-- ALTER TABLE testConstraints CHECK CONSTRAINT chk_Vals GO -- |
Both the above commands will execute sucessfully. So it is clear that when you enable a constraint and if you provide WITH NOCHECK or if you dont provide this option SQL Server will not verify the existing data with the constraint
Notes –
Now there are two options available for CHECK CONSTRAINT.
1. CHECK CONSTRAINT – WITH CHECK
2. CHECK CONSTRAINT – WITH NOCHECK
CHECK CONSTRAINT – WITH CHECK
1. It will enable the constraint.
2. It can only be used with FOREIGN KEY and CHECK constraints.
3. Future inserts or updates will be validated against the constraint conditions
4. Existing data will also be validated against the constraint conditions.
Syntax-
-- ALTER TABLE testConstraints WITH CHECK CHECK CONSTRAINT chk_Vals GO -- |
CHECK CONSTRAINT – WITH NOCHECK
1. It will enable the constraint.
2. It can only be used with FOREIGN KEY and CHECK constraints.
3. Future inserts or updates will be validated against the constraint conditions
4. Existing data will NOT be validated against the constraint conditions.
Syntax-
-- ALTER TABLE testConstraints WITH NOCHECK CHECK CONSTRAINT chk_Vals GO -- |
CHECK CONSTRAINT (DEFAULT)
1. It is same as CHECK CONSTRAINT – WITH NOCHECK.
2. It will enable the constraint.
3. It can only be used with FOREIGN KEY and CHECK constraints.
4. Future inserts or updates will be validated against the constraint conditions
5. Existing data will NOT be validated against the constraint conditions.
Syntax-
-- ALTER TABLE testConstraints CHECK CONSTRAINT chk_Vals GO -- |
NOCHECK CONSTRAINT
1. It will disable the constraint.
2. It can only be used with FOREIGN KEY and CHECK constraints.
3. Here future inserts or updates to the column are not validated against the constraint conditions.
4. Note – Constraint types – DEFAULT, PRIMARY KEY, and UNIQUE cannot be disabled.
Syntax-
-- ALTER TABLE testConstraints NOCHECK CONSTRAINT chk_Vals GO -- |
Reference
https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-table-transact-sql |
Pawan Khowal
Pawan is a SQL Server Developer. If you need any help in writing code/puzzle or training please email at – pawankkmr”AT”gmail.com. Meanwhile please go throgh the top pages from his blog.
Page Detail | URL |
---|---|
☛ SQL Advance Puzzles | https://msbiskills.com/tsql-puzzles-asked-in-interview-over-the-years/ |
☛ SQL Tricky Queries | https://msbiskills.com/sql-puzzles-finding-outputs/ |
☛ SQL Server Perfomance tuning Articles | https://msbiskills.com/sql-performance-tuning/ |
☛ SQL Server Articles | https://msbiskills.com/t-sql/ |
☛ SQL Interview Questions & Answers | https://msbiskills.com/sql-server-interview-questions/ |
My SQL Groups on Facebook:
1. If you like this post, you may want to join my SQL SERVER Interview Puzzles/Interview Questions on Facebook: https://www.facebook.com/groups/1430882120556342/
2. If you like this post, you may want to join my SQL Server Puzzles on Facebook:
https://www.facebook.com/groups/206594023090781/
My SQL Page on Facebook:
2. For all the updates you may follow my page -> https://www.facebook.com/MSBISkillscom-1602779883299222/
Enjoy !!! Keep Learning
Http://MsbiSkills.com
Pingback: SQL SERVER | Enable or Disable CONSTRAINTs? | SQL Interview Questio | Improving my SQL BI Skills