How to determine which items in one table do not appear in a second table

  • I have two tables, a table of actions and a table of items. They look like this:

    ActionID EmployeeResponsible

    1 12345

    2 67890

    3 54321

    4 09876

    ItemID ActionID

    1 1

    1 2

    2 4

    3 1

    3 2

    3 3

    I need to get the ActionIDs that have not been completed for each Item. The part that's giving me problems is that I also need the ItemIDs. So my results should be

    ItemID ActionID ResponsibleEmployee

    1 3 54321

    1 4 09876

    2 1 12345

    2 2 67890

    2 3 54321

    3 4 09876

    Help, please :unsure:

  • You are missing some data here. How can you tell an actionid for an item has been completed when the first table doesn't have ItemIDs? You have two actionIds of "1" for different items.

    Please also ask the question with DDL like this, so people can help you run tests.

    CREATE TABLE ActionEmp

    ( ActionID int

    , EmployeeResponsible int

    )

    ;

    go

    INSERT ActionEmp SELECT 1, 12345;

    INSERT ActionEmp SELECT 2, 67890;

    INSERT ActionEmp SELECT 3, 54321;

    INSERT ActionEmp SELECT 4, 09876;

    go

    CREATE TABLE Actions

    ( ItemID int

    , ActionID int

    )

    ;

    go

    INSERT Actions SELECT 1, 1;

    INSERT Actions SELECT 1, 2;

    INSERT Actions SELECT 2, 4;

    INSERT Actions SELECT 3, 1;

    INSERT Actions SELECT 3, 2;

    INSERT Actions SELECT 3, 3;

    GO

    SELECT

    a.ItemID

    , ae.ActionID

    , ae.EmployeeResponsible

    from ActionEmp ae

    LEFT OUTER JOIN Actions a

    ON ae.actionid = a.actionid

    ORDER BY

    a.ItemID

    , ae.actionid

    ;

  • OK, sorry, let me try to explain more fully. The Action Table contains actions that need to be completed for each Item and the person responsible for taking the action. It is essentially a lookup table. So:

    CREATE TABLE Actions

    ( ActionID int,

    ActionName varchar(30),

    , EmployeeResponsible int

    )

    ;

    go

    INSERT Actions SELECT 1, 'Emails Sent', 12345;

    INSERT Actions SELECT 2, 'Emails Archived', 67890;

    INSERT Actions SELECT 3, 'Project Folder Archived', 54321;

    INSERT Actions SELECT 4, 'Acknowledged Notification', 09876;

    go

    The Items table contains items for which each of the 4 actions must be completed. There can be a maximum of 4 rows per item, i.e., one row for each action. So:

    CREATE TABLE Items

    ( ItemID int

    , ActionID int

    )

    ;

    go

    INSERT Items SELECT 1, 1;

    INSERT Items SELECT 1, 2;

    INSERT Items SELECT 2, 4;

    INSERT Items SELECT 3, 1;

    INSERT Items SELECT 3, 2;

    INSERT Items SELECT 3, 3;

    GO

    So, for Item 1, Actions 1 and 2 have been completed, but not Actions 3 and 4. For Item 2, only Action 4 has been completed. For Item 3 all actions except Action 4 have been completed. I want a result set that reflects the uncompleted action IDs for each ItemID:

    ItemID ActionID

    1 3

    1 4

    2 1

    2 2

    2 3

    3 4

    Thanks!

  • There are probably better ways, but I think this works:

    ; WITH AllActions (ItemID, ActionID)

    AS

    (

    SELECT distinct

    i.itemid

    , a.actionid

    FROM items i

    CROSS APPLY

    ( select a.actionid

    FROM Actions a

    ) a

    )

    SELECT

    *

    FROM AllActions aa

    WHERE aa.itemid NOT IN (select i.itemid

    FROM items i

    WHERE aa.itemid = i.ItemID

    AND aa.ActionID = i.ActionID

    )

    ORDER BY

    itemid

    , ActionID

  • I believe this does it.

    Thanks, Steve!

  • Here is another way of doing it:

    Select a.ItemID, b.ActionID From

    (

    Select Distinct ItemID From Items

    ) As a

    CROSS JOIN Actions As b

    Except

    Select ItemID, ActionID From Items

    Vinu Vijayan

    For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden[/url] 😉

  • Thank you, Vinu! The EXCEPT statement is new to me. Always nice to learn something new.

  • Melanie Peterson (12/20/2012)


    Thank you, Vinu! The EXCEPT statement is new to me. Always nice to learn something new.

    Yes it is always good to learn something new Melanie.

    And what is even better is getting to know how to do things the right way. So, if this is not a one time requirement then I would recommend that you do a small test to get to know which of the above two solutions is better performance wise on a bigger set of data and use that one.

    Vinu Vijayan

    For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden[/url] 😉

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

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