Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to determine which items in one table do not appear in a second table Expand / Collapse
Author
Message
Posted Tuesday, December 18, 2012 10:34 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, February 24, 2014 10:02 AM
Points: 78, Visits: 186
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
Post #1397921
Posted Tuesday, December 18, 2012 10:53 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: Today @ 11:24 AM
Points: 32,781, Visits: 14,942
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
Post #1397930
Posted Tuesday, December 18, 2012 11:17 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, February 24, 2014 10:02 AM
Points: 78, Visits: 186
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!
Post #1397947
Posted Tuesday, December 18, 2012 11:47 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: Today @ 11:24 AM
Points: 32,781, Visits: 14,942
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
Post #1397967
Posted Tuesday, December 18, 2012 11:51 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, February 24, 2014 10:02 AM
Points: 78, Visits: 186
I believe this does it.

Thanks, Steve!
Post #1397971
Posted Wednesday, December 19, 2012 8:01 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, January 15, 2013 11:11 AM
Points: 1,945, Visits: 2,782
>> 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. <,

Remember the first week of your first database class? Keys?? How NULLs work? You can not ever have a key in this non-table! Can I assume that that the actions have to be done in some order? Why is one single employee an inherent attributive of an action? There should be a job assignment relationship with an employee and an action.

CREATE TABLE Actions
(action_seq INTEGER NOT NULL PRIMARY KEY,
action_name VARCHAR(30) NOT NULL);

There is no reason to write dialect insertions today:

INSERT INTO Actions
VALUES (1, 'Emails Sent'),
(2, 'Emails Archived'),
(3, 'Project Folder Archived'),
(4, 'Acknowledged Notification');

Do you want 1:1 , 1:m or m:1 relationship in employee:action? Add UNIQUE as needed.

CREATE TABLE Job_Assignments
(action_seq INTEGER NOT NULL,
REFERENCES Actions (action_seq),
responsible_emp_id INTEGER NOT NULL
REFERENCES Personnel (emp_id),
PRIMARY KEY (action_seq, responsible_emp_id));

>> 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. <<

You really hate keys! Do this in the DDL:

CREATE TABLE Items
(item_id INTEGER NOT NULL,
action_seq INTEGER NOT NULL
CHECK (action_seq IN (1,2,3,4),
PRIMARY KEY (item_id, action_seq));

Again, use ANSI/ISO Standard SQL, not dialect.

INSERT INTO Items
VALUES (1, 1), (1, 2), (2, 4), (3, 1), (3, 2), (3, 3);

>> I want a result set that reflects the uncompleted actions for each item_id <<

SELECT X.*
FROM (SELECT I1.item_id, A.action_seq -- all combinations
FROM A.actions, Items AS I1
EXCEPT -- remove existing ones
SELECT item_id, action_seq
FROM Items)
AS X(item_id, action_seq)


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1398743
Posted Thursday, December 20, 2012 1:47 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, April 08, 2014 2:40 AM
Points: 1,118, Visits: 1,573
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
Post #1398857
Posted Thursday, December 20, 2012 8:25 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, February 24, 2014 10:02 AM
Points: 78, Visits: 186
Thank you, Vinu! The EXCEPT statement is new to me. Always nice to learn something new.
Post #1399005
Posted Thursday, December 20, 2012 10:23 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, April 08, 2014 2:40 AM
Points: 1,118, Visits: 1,573
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
Post #1399185
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse