Filter all of a group out if one or more parts aren't true

Gabbelgak

New Member
Joined
Dec 14, 2016
Messages
22
Drawing a blank on this and need help.

I have the following table:

SupplierItemStatus
SW39000013WP
SWM2000024M5
SW39000013M8
SWM2000006M5
GMFQPTG513M8
GMFQPTG513M5
GJCA137014WP
GJCA137015WP
SWM2000036M3
SHCPNA3294M3
SC22DDH150M5
SC22DDH027M8
SW1VNPB152M8
SC22DDH035M8
S5CHA35003M8
SC22DDH101M5
YZAA041985M5
SWGI000037M8
GDCCADL590M3
SW1VNPB152M5
SC22130666M3
SW39MRP026JC
GDHC475559JC
GDHC475565JC
SCCBDAN017M8
SC22DDH035M3
SC22DDH027M3
SH01620066JC
S5CHA35003JC
SWGI000037JC
SC22DDH158M8
SC22DDH158M3
SC22DDH129M8
SC22DDH129M3
SCCBDAN017M3
SWM2000008JC
SWM2000024JC
SC22DDH158M3
SC22DDH129M3
SWM2000008M3
SWM2000024M3
SWM2000008M3
SWM2000008JC
SWM2000008JC
SWM2000008M3
GMC6NA2055M3
GMC6NA2055M3
GMC6NA2055M3
SWM2000036M3
SWM2000008M3
<caption>active</caption>

<thead>


</thead>
<tbody>


</tbody>
<tfoot></tfoot>

I'm trying to filter the results so it only will show groups of Supplier / Item if all of the Status = JC

I was able to put together a query that counts the number of status for each group and another that counts the JC's but am drawing a blank now.

Count Query:
SELECT active.SUPPLIER, active.ITEM, Count(*) AS Expr1
FROM active
GROUP BY active.SUPPLIER, active.ITEM;

Job Complete Count:
SELECT active.SUPPLIER, active.ITEM, Count(*) AS Expr1
FROM active
WHERE STATUS = "JC"
GROUP BY active.SUPPLIER, active.ITEM;


If the count result = the same as the job complete count for the same group I'm trying to get it to show all of them, and if not filter the whole group out.
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Not sure of what you're asking. Try
Code:
SELECT tblSuplrStatus.Supplier, tblSuplrStatus.Item FROM tblSuplrStatus 
WHERE (((tblSuplrStatus.Status)="JC")) 
GROUP BY tblSuplrStatus.Supplier, tblSuplrStatus.Item;
 
Upvote 0
Your query will show me what has a JC which isn't really what I want. The desired result from the above table would be this:

SupplierItemStatus
GDHC475559JC
GDHC475565JC
SH01620066JC
SW39MRP026JC

<colgroup><col span="3"></colgroup><tbody>
</tbody>

I've removed all of the S5CH A35003's for example because at least one of the status codes not JC. If the M8 S5CH A35003 were to change to JC then the desired result would be

SupplierItemStatus
GDHC475559JC
GDHC475565JC
SH01620066JC
SW39MRP026JC
S5CHA35003JC
S5CHA35003JC

<colgroup><col span="3"></colgroup><tbody>
</tbody>

(Duplicates is fine)

I hope this clears things up or I can try to clarify further if need be. Thank you for taking the time to look at my question.
 
Upvote 0
OK, that's entirely different than what I thought this meant: at least one of the status codes not JC
I will have to think it over. In the meantime, maybe someone else who's way smarter than me will jump in. Goodness knows there's plenty of those souls out there.:rolleyes:
 
Upvote 0
OK, that's entirely different than what I thought this meant: at least one of the status codes not JC
I will have to think it over. In the meantime, maybe someone else who's way smarter than me will jump in. Goodness knows there's plenty of those souls out there.:rolleyes:
Also, does that mean you'd also eliminate these (just so I understand the constraints)
GMFQ because one is M5 and the other is M8?
That for SC22, you'd eliminate DDHO27, DDHO35, DDHO129, DDHO158?

I know I could examine your reposted results but I'm scanning a table here and just want to be sure. I didn't go through all of it; I figured those would be enough examples.
 
Last edited:
Upvote 0
That is correct.

For GMFQ we only have 1 Item, PTG513, since it has a single status that is not JC (it has one M5 and one M8) I don't want to see any of these.

For SC22 we have 7 different items, 130666, DDH027, DDH035, DDH101, DDH129, DDH150, DDH158 - None of these have a JC so we can eliminate all of them. But to be extra clear, let's say 13066 was JC and not M3 - I would want to see SC22 130666 JC and none of the other 6 SC22's.
 
Upvote 0
Between my last and this post, I came up with something, but it was finished before I saw your last post. I can only do it with 3 queries:

create 2 TOTALS queries:
- concatenate supplier & item to create a unique identifier (sort of a grouping) where status is JC and calculate counts for these groups
- in a 2nd query, concatenate again from the main table and get a count of the status for these groups
- in 3rd query, join 1 & 2 WHERE group = group AND status count = group count. Include main table to show status JC, because you can't filter on JC as well as include it in the results in a Totals query (i.e. it can't be criteria and as well as perform an aggregate function on it).
The logic is, if there are 3 counts of a group and a 3-count status for that group, the status must be the same. Otherwise, the status count would be different than the count of a group. I could see that early on, but it took a LOT of playing around to get the result I could envision. Probably is easier to read than understand. I think if you run the first 2 queries separately and in your table, filter to JC and sort by Supplier then Item and compare what the queries show, it might make more sense. The output is
SupplierItemStatus
GDHC475559JC
GDHC475565JC
SH01620066JC
SW39MRP026JC

<tbody>
</tbody>

Hope that is what you want - it seems to jive with your posted table of results. If you need to adapt this for other status' then I think you can probably figure out how to tweak it.
 
Last edited:
Upvote 0
Whooops! forgot to post the sql. Adding a new post because I may run out of time to edit the prior one.

GROUP COUNT
Code:
SELECT [supplier] & [Item] AS SuplrItem, Count([supplier] & [Item]) AS SuplrItemCnt, tblSuplrStatus.Supplier, tblSuplrStatus.Item
FROM tblSuplrStatus
WHERE (((tblSuplrStatus.Status)="JC"))
GROUP BY [supplier] & [Item], tblSuplrStatus.Supplier, tblSuplrStatus.Item;
STATUS COUNT
Code:
SELECT [supplier] & [Item] AS SuplrItem, Count(tblSuplrStatus.Status) AS CountOfStatus
FROM tblSuplrStatus
GROUP BY [supplier] & [Item];
RESULT
Code:
SELECT qryGroupCnt.Supplier, qryGroupCnt.Item, tblSuplrStatus.Status
FROM tblSuplrStatus INNER JOIN (qryGroupCnt INNER JOIN qryStatusCnt ON 
(qryGroupCnt.SuplrItem = qryStatusCnt.SuplrItem) AND 
(qryGroupCnt.SuplrItemCnt = qryStatusCnt.CountOfStatus)) ON 
(tblSuplrStatus.Item = qryGroupCnt.Item) AND (tblSuplrStatus.Supplier = qryGroupCnt.Supplier);
I put line wraps in the sql lines because they were going beyond rs of screen, so watch out for any missing spaces.
 
Upvote 0

Forum statistics

Threads
1,214,622
Messages
6,120,585
Members
448,972
Latest member
Shantanu2024

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top