devxlogo

Solving Multiple Conditions Within a Group

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
[email protected]

devxblackblue

About Our Editorial Process

At DevX, we’re dedicated to tech entrepreneurship. Our team closely follows industry shifts, new products, AI breakthroughs, technology trends, and funding announcements. Articles undergo thorough editing to ensure accuracy and clarity, reflecting DevX’s style and supporting entrepreneurs in the tech sphere.

See our full editorial policy.

About Our Journalist