Here is one solution for this problem using a view filtering on non NULL values with UNIQUE index on the view.
CREATE TABLE dbo.Foo (
keycol INT NULL,
datacol CHAR(1));
GO
CREATE VIEW UniqueFoo WITH SCHEMABINDING
AS
SELECT keycol, datacol
FROM dbo.Foo
WHERE keycol IS NOT NULL;
GO
CREATE UNIQUE CLUSTERED INDEX ix_UniqueFoo
ON UniqueFoo(keycol);
GO
-- OK, multiple NULL values allowed
INSERT INTO dbo.Foo VALUES(1, 'a');
INSERT INTO dbo.Foo VALUES(NULL, 'b');
INSERT INTO dbo.Foo VALUES(NULL, 'c');
GO
-- Error, attempt to insert duplicate keycol value
INSERT INTO dbo.Foo VALUES(1, 'd');
/*
Msg 2601, Level 14, State 1, Line 2
Cannot insert duplicate key row in object 'dbo.UniqueFoo' with unique index 'ix_UniqueFoo'.
The statement has been terminated.
*/
In SQL Server 2008 this can be accomplished much easier using UNIQUE filtered index.
CREATE UNIQUE NONCLUSTERED INDEX ix_Foo
ON Foo (keycol)
WHERE keycol IS NOT NULL;
cool stuff. I'll be implemented this today.
ReplyDeleteThanks.
This comment has been removed by the author.
ReplyDeleteHello everyone,
ReplyDeleteI am struggling with the following problem. I need to calculate hours between 2 dates. For example let say that the start day is 01.03.2018 -Thursday and the end day is 06.03.2018 - Tuesday. I want to be able to calculate only the working hours between these 2 days. Let say that working hours are between 9 and 18. I tried a few things but no luck. Any help will be much appreciated. Thanks