Applying constraints to WHERE statement

  • Hi,

    I have to write code to produce data along the lines of SIZE, COLOUR and PATTERN. I'm coming unstuck because I have to apply specific constraints on PATTERN given a specific SIZE and COLOUR. For example, SIZE=10; COLOUR=R; PATTERNID must not be in (001,009): SIZE=10; COLOUR=G; PATTERNID must not be in (001,002,008) and so on.

    I'm not new to programming, but am to SQL and I can't seem to get the syntax right. Any help would be much appreciated! πŸ™‚

  • Here's one way, but I'm not sure that it's the best. Create a table called ForbiddenPatterns with columns Size, Colour, Pattern. Insert one row for each forbidden combination. Write a function that takes Colour, Size and Pattern as parameters and returns Forbidden if the combination supplied appears in ForbiddenPatterns. Add a check constraint to your original table that checks that the result of the function is not Forbidden.

    John

    Edit - corrected typo

  • Hi John,

    Yes - that sounds as though it would work πŸ˜€ I'm on another task now for the rest of the day, but I'll be sure to give an update when I can. Many thanks!!

  • CROSS APPLY is an excellent tool for building complex WHERE clauses and would also help you to figure out if it's worthwhile building up an exclusion table as suggested. Once you've constructed your exclusions list in the CROSS APPLY block, you can drop it down into the WHERE clause.

    SELECT x.Exclusion, m.*

    FROM MyTable m

    CROSS APPLY (

    SELECT Exclusion = CASE

    WHEN m.SIZE = 10 AND m.COLOUR = 'R' AND m.PATTERNID IN (001,009) THEN 1

    WHEN m.SIZE = 10 AND m.COLOUR = 'G' AND m.PATTERNID IN (001,002,008) THEN 2

    ELSE NULL END

    ) x

    WHERE x.Exclusion IS NULL

    β€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Thanks Chris! That looks like it would be useful for other tasks that I have to perform as well πŸ™‚

  • Anytime.

    Third row up in my sig block has links to a couple of outstanding articles on APPLY. Well worth a read.

    β€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Update: using adaptations of the code/ideas you both supplied, I have been able to correct a troublesome report at work. My bosses were very pleased! πŸ˜‰ Thanks again!

  • Happy to help, and I'm glad it turned out so well. Please will you share your solution, in case anyone else has a similar issue and wonders how you resolved it?

    Thanks

    John

Viewing 8 posts - 1 through 7 (of 7 total)

You must be logged in to reply to this topic. Login to reply