Login | Register   
LinkedIn
Google+
Twitter
RSS Feed
Download our iPhone app
TODAY'S HEADLINES  |   ARTICLE ARCHIVE  |   FORUMS  |   TIP BANK
Browse DevX
Sign up for e-mail newsletters from DevX


Tip of the Day
Language: SQL Server
Expertise: Beginner
Mar 25, 1997

Solving Multiple Conditions Within a Group

Question:
[Joe Celko's Work Order Puzzle]

Cenk Ersoy asked this question on the Gupta Forum on CompuServe. He has a table that looks like this:

    CREATE TABLE Projects
        (workorder CHAR(5) NOT NULL, 
        leg INTEGER NOT NULL,
        status CHAR(1) NOT NULL CHECK (status IN ('C', 'R')
        );
With some sample data like this:
    Projects
    workorder     leg     status
    ============================
    AA100           0       C
    AA100           1       R
    AA100           2       R
    AA200           0       R
    AA200           1       R
    AA300           0       C
    AA300           1       C
He would like to get the work orders where the leg is zero and the status is 'C', but all other legs for that work order have a status of 'R'. For example, the query should return only 'AA100' in the sample data.

Answer:
This is really fairly staightforward, but you have to re-word the query specification into the passive voice to see the answer. Instead of saying, "all other legs for that work order have status of R," instead say "R is the status of all the non-zero legs" and the answer falls out immediately, thus:

    SELECT workorder
        FROM Projects AS P1
        WHERE (leg = 0)
            AND (status = 'C')
            AND 'R' = ALL (SELECT status
                FROM Projects AS P2
                WHERE leg <> 0
                    AND P1.workorder = P2.workorder);

Puzzle provided courtesy of:
Joe Celko
71062.1056@compuserve.com

DevX Pro
 
Comment and Contribute

 

 

 

 

 


(Maximum characters: 1200). You have 1200 characters left.

 

 

Sitemap
Thanks for your registration, follow us on our social networks to keep up-to-date