October 21, 2011 at 12:27 pm
I want to create a referential integrity constraint to ensure values from a Lookup table are assigned to the correct referencing table.
tblReference: ID, RefName, Class
tblLookup: ColumnInt, ColumnValue, TableName, ColumnName
tblReference .Class needs to show tblLookup.ColumnInt but needs to be restricted to only allow values where tblLookup.TableName = 'tblReference' and tblLookup.ColumnName = 'Class'. Is there a way to create a check constraint to do this? I also want to ensure values from tblLookup that are used in tblRefence cannot be deleted.
Thanks!
October 21, 2011 at 1:17 pm
this is one of the ramificaitons of having the "universal" lookup table instead of one lookup table for each logical group of values.
to do what you are asking, you need a check constriant that uses a user defined function, and if you don't have a foreign key reference(which would prevent the deletes anyway) you also need a delete trigger on your lookups table.
ideally, you want to chop your lookups table into separate tables, and get away from the "One Lookup to Rule Them All" design, but I understand when that is not possible.
CREATE FUNCTION ONLYSPECIFICREFERENCES(@id INTEGER)
RETURNS INTEGER
AS
BEGIN
DECLARE @Results INT
IF EXISTS(SELECT 1
FROM tblLookup
WHERE TableName = 'tblReference'
AND tblLookup.ColumnName = 'Class'
AND LookupID = @id)
SET @Results =1
ELSE
SET @Results = 0
RETURN @Results
END --FUNCTION
GO
ALTER TABLE tblReference ADD CONSTRAINT CK_SpecificReferencesCHECK(dbo.OnlySpecificReferences(LookupID) = 1)
Lowell
October 21, 2011 at 2:07 pm
That is a pretty slick way to deal with that Lowell. I will have to add to my bag of tricks when dealing with other people's data structures. :w00t:
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 21, 2011 at 2:44 pm
Thank you! This is very slick!
I keep going back and forth on the one lookup table design. For UI purposes in this case it makes it easier to maintain, but then again... maybe not.....
October 21, 2011 at 3:05 pm
evaleah (10/21/2011)
Thank you! This is very slick!I keep going back and forth on the one lookup table design. For UI purposes in this case it makes it easier to maintain, but then again... maybe not.....
I created a user control in .net for this type of thing. That way I just set a few properties and let the class take care of the rest. It is all dynamic pass through queries so depending on usage it could be injection vulnerable. For my purposes all of the data elements are not set by the end user.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 21, 2011 at 10:05 pm
Although using a UDF as a CONSTRAINT is very clever, beware of "Hidden RBAR" folks. The addition of such a constraint that uses a Scalar UDF with an external table reference will make INSERTs run more than 12 times slower (thats best case... it's 16.4 times slower for this particular UDF, I measured it 😉 ) and that includes some proper indexing! A decent trigger like the one below will make it run only twice as slow.
CREATE TRIGGER dbo.CheckReferenceClass
ON dbo.tblReference
AFTER INSERT, UPDATE
AS
IF @@ROWCOUNT <> (
SELECT COUNT(ref.Class)
FROM dbo.tblLookup lu
INNER JOIN INSERTED ref
ON lu.ColumnInt = ref.Class
WHERE lu.TableName = 'tblReference'
AND lu.ColumnName = 'Class'
)
BEGIN
ROLLBACK;
RAISERROR('Bad "Class" on INSERT to dbo.tblReference. INSERT has been rolled back',16,1);
END;
GO
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply