SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


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


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

Author
Message
Melanie Peterson
Melanie Peterson
SSC-Addicted
SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)

Group: General Forum Members
Points: 411 Visits: 257
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
Steve Jones
Steve Jones
SSC Guru
SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)

Group: Administrators
Points: 139560 Visits: 19413
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
;



Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
Melanie Peterson
Melanie Peterson
SSC-Addicted
SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)

Group: General Forum Members
Points: 411 Visits: 257
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!
Steve Jones
Steve Jones
SSC Guru
SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)SSC Guru (139K reputation)

Group: Administrators
Points: 139560 Visits: 19413
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



Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
Melanie Peterson
Melanie Peterson
SSC-Addicted
SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)

Group: General Forum Members
Points: 411 Visits: 257
I believe this does it.

Thanks, Steve!
vinu512
vinu512
Hall of Fame
Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)

Group: General Forum Members
Points: 3467 Visits: 1626
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 ;-)
Melanie Peterson
Melanie Peterson
SSC-Addicted
SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)SSC-Addicted (411 reputation)

Group: General Forum Members
Points: 411 Visits: 257
Thank you, Vinu! The EXCEPT statement is new to me. Always nice to learn something new.
vinu512
vinu512
Hall of Fame
Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)

Group: General Forum Members
Points: 3467 Visits: 1626
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 ;-)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search