Database Research & Development

  • Home
  • NoSQL
    • NoSQL
    • Cassandra
  • Databases
    • Database Theory
    • Database Designing
    • SQL Server Coding Standards
    • SQL Server
    • PostgreSQL
    • MySQL
    • Greenplum
    • Linux
  • Interviews
    • SQL Server Interviews
    • MySQL Interviews
    • SQL Puzzles
  • DBA Scripts
    • SQL Server DBA Scripts
    • PostgreSQL DBA Scripts
    • MySQL DBA Scripts
    • Greenplum DBA Scripts
  • Home
  • Blog Archives !
  • (: Laugh@dbrnd :)
  • Contact Me !
sqlserverinterviews
Home 2018 March SQL Server: Allow Multiple NULL Values in UNIQUE Constraint

SQL Server: Allow Multiple NULL Values in UNIQUE Constraint

UNIQUE Constraint

This article is half-done without your Comment! *** Please share your thoughts via Comment ***

In this post, I am sharing a demonstration on how to allow multiple NULLs for UNIQUE Constraint in SQL Server.

As per the ANSI, UNIQUE constraint allows multiple NULLs. But in the SQL Server, it allows only one NULL value.
With the UNIQUE constraint, you cannot insert multiple NULLs.

But you can create UNIQUE NONCLUSTERED INDEX with the NOT NULL filter and can insert multiple NULLs.

Please check the below demonstration:

Create a sample table with UNIQUE Constraint:

1
2
CREATE TABLE tbl_TestUnique (ID INT UNIQUE)
GO

Try to insert multiple NULLs:

1
2
3
4
5
6
7
INSERT INTO tbl_TestUnique
VALUES (1),(NULL),(NULL),(2),(NULL)
GO
 
 
Msg 2627, Level 14, State 1, Line 4
Violation of UNIQUE KEY constraint 'UQ__tbl_Test__3214EC26DBD9CD71'. Cannot insert duplicate key in object 'dbo.tbl_TestUnique'. The duplicate key value is ().

Now, try to insert with single NULL:

1
2
3
INSERT INTO tbl_TestUnique
VALUES (1),(2),(NULL)
GO

Drop the table:

1
2
DROP TABLE tbl_TestUnique
GO

Create the same table with UNIQUE NONCLUSTERED INDEX:

1
2
3
4
5
6
7
CREATE TABLE tbl_TestUnique (ID INT)
GO
 
CREATE UNIQUE NONCLUSTERED INDEX idx_tbl_TestUnique_ID
ON tbl_TestUnique(ID)
WHERE ID IS NOT NULL
GO

Now, INSERT Multiple Nulls:
As we defined UNIQUE on ID NOT NULL, so we can insert multiple NULLs.

1
2
3
4
5
6
7
INSERT INTO tbl_TestUnique
VALUES (1),(2),(NULL),(NULL)
GO
 
INSERT INTO tbl_TestUnique
VALUES (NULL),(NULL),(NULL)
GO

Mar 4, 2018Anvesh Patel
SQL Server: Create Full Text Search Index, Use CONTAINS for pattern matchingSQL Server 2016: System-versioned Temporal Table to store History of data change
Comments: 3
  1. Dinesh
    March 13, 2018 at 7:29 am

    If Create Unique from Index column Constraint will not create,
    If create Column Unique , Constraint will create

    ReplyCancel
  2. David Paranka
    April 30, 2020 at 6:32 pm

    Dear Anvesh thanks very much for this post. It not only answered my question about is it possible to implement a unique constraint on a column with null values, but it also showed how. I appreciate the ability to screen-scrape your example code.

    ReplyCancel
    • Anvesh Patel
      Anvesh Patel
      May 27, 2020 at 12:11 pm

      thanks,

      ReplyCancel

Leave a Reply Cancel reply

CAPTCHA
Refresh

*

Anvesh Patel
Anvesh Patel

Database Engineer

ImageMarch 4, 2018 3 Comments SQL ServerAnvesh Patel, database, database research and development, dbrnd, SQL Query, SQL Server, SQL Server Administrator, SQL Server Error, SQL Server Monitoring, SQL Server Performance Tuning, SQL Server Programming, SQL Server Tips and Tricks, TSQL, UNIQUE CONSTRAINT, UNIQUE NON NONCLUSTERED INDEX
About Me!

I'm Anvesh Patel, a Database Engineer certified by Oracle and IBM. I'm working as a Database Architect, Database Optimizer, Database Administrator, Database Developer. Providing the best articles and solutions for different problems in the best manner through my blogs is my passion. I have more than six years of experience with various RDBMS products like MSSQL Server, PostgreSQL, MySQL, Greenplum and currently learning and doing research on BIGData and NoSQL technology. -- Hyderabad, India.

About DBRND !

dbrnd

This is a personal blog (www.dbrnd.com).

Any views or opinions represented in this blog are personal and belong solely to the blog owner and do not represent those of people, institutions or organizations that the owner may or may not be associated with in professional or personal capacity, unless explicitly stated.

Feel free to challenge me, disagree with me, or tell me I’m completely nuts in the comments section of each blog entry, but I reserve the right to delete any comment for any reason whatsoever (abusive, profane, rude, or anonymous comments) - so keep it polite.

The content of this website is protected by copyright. No portion of this website may be copied or replicated in any form without the written consent of the website owner.

Recent Comments !
  • Anvesh Patel { Sure will do... } – May 27, 12:43 PM
  • Anvesh Patel { Great... } – May 27, 12:41 PM
  • Anvesh Patel { Great... } – May 27, 12:39 PM
  • Anvesh Patel { Great... } – May 27, 12:36 PM
  • Anvesh Patel { Great... } – May 27, 12:28 PM
  • Anvesh Patel { Great... } – May 27, 12:27 PM
  • Anvesh Patel { Great... } – May 27, 12:16 PM
  • Older »
Follow Me !
  • facebook
  • linkedin
  • twitter
  • youtube
  • google
  • flickr
© 2015 – 2019 All rights reserved. Database Research & Development (dbrnd.com)
Posting....