Q
Problem solve Get help with specific problems with your technologies, process and projects.

Exactly one row? At least one row? (Part 1)

I am trying to retrieve data from one table, but I want specific data from two different columns. My example table...

is:

 ID LOC_NUMB LOC_PREC 000000000 TIRE01 P 000000001 TIRE02 P 000000002 TIRE03 P 000000003 TIRE04 P 000000004 TIRE05 P 000000001 TIRE06 S 000000002 TIRE07 S

The results I am looking for:

 ID LOC_NUMB LOC_PREC 000000001 TIRE02 P 000000002 TIRE03 P 000000001 TIRE06 S 000000002 TIRE07 S

I need ID with the LOC_PREC P and S.

 SELECT item_loc.id, item_loc.loc_numb, item_loc.loc_prec FROM item_loc WHERE item_loc.id contains **** this is where I am having a problem (item_loc.loc_prec 'S and P') GROUP BY item_loc.id ORDER BY item_loc.id asc

Is there any way I can get the data from column ID that contains only S and P for that specific ID. I don't need AND, OR; I need both? Thank you.


To answer your question, yes, you can do it. You didn't say whether you wanted exactly one S and and P, or at least one S and one P, so I'll show you how to do it either way. Let's start with this query:

select id , loc_numb , loc_prec from item_loc where id in ( select id from item_loc where loc_prec in ('S','P') group by id having count(*) = 2 )

Let's look first at the subselect. The subselect returns all S and P rows in the table. Then it groups them by ID. If a particular ID has exactly 2 rows, then it is selected, and both of its rows are included in the result set of the outer query.

But is this correct? We are assuming that there is one S and one P, but there's a "gotcha" in that logic. The subquery also chooses every ID that has two S's and no P's, or two P's and no S's. And if there's a particular ID that happens to have one S and two P's? It would not be chosen! We could fix this by using

 having count(*) >= 2

But this still lets an ID with only three P's or only three S's through.

This is familiar OR behaviour, the result of "mingling" the selected rows in the IN?('S','P') condition. Let's see what happens when we split the S and P conditions into separate subselects, so that the selected rows are not mingled.

select id , loc_numb , loc_prec from item_loc where id in ( select id from item_loc where loc_prec = 'S' group by id having count(*) = 1 ) and id in ( select id from item_loc where loc_prec = 'P' group by id having count(*) = 1 )

This query lists ID's which have exactly one S and one P. Use an equality condition in the HAVING clause to specify an exact number of rows.

To find one or more rows, use an inequality. For example, to find every ID with one S and at least one P, the query is:

select id , loc_numb , loc_prec from item_loc where id in ( select id from item_loc where loc_prec = 'S' group by id having count(*) = 1 ) and id in ( select id from item_loc where loc_prec = 'P' group by id having count(*) >= 1 )

If you think about it for a moment, a HAVING clause that says COUNT(*)?>=?1 is redundant. It's easy to see why, if you consider how a query with a GROUP BY clause is processed. First, rows are retrieved based on WHERE conditions. Then the selected rows are assembled into groups, typically by sorting. Then the groups are processed. There will not be a group with no rows, since during selection, no rows were selected for that group. Therefore each group that comes out of row selection and goes into group processing has to have one or more rows.

This answer is continued


This was last published in October 2002

Dig Deeper on Oracle and SQL

PRO+

Content

Find more PRO+ content and other member only offers, here.

Have a question for an expert?

Please add a title for your question

Get answers from a TechTarget expert on whatever's puzzling you.

You will be able to add details on the next page.

Start the conversation

Send me notifications when other members comment.

By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy

Please create a username to comment.

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide.com

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close