473,414 Members | 1,911 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,414 software developers and data experts.

SQL query question

Hi All,

I have a SQL query like this (I have tried to break the problem down
to simplify it),

select rowid from table where name in ('a', 'b', 'd') group by rowid

Here is an example of data in the table

rowid name
1 a
1 b
1 c
1 d
2 a
2 b

That query gives back row 1, and 2. But that is not what I want it to
do.

What I actually want it to do is give me back rowids of records which
have 'all' of the items in the 'name in ('a', 'b', 'd')' clause.

E.g. I want it to return back rowid 1 only because it has a row with
a, b, and d, but I don't want it to return back 2 because it doesn't
have a row with the name d (which is in my 'name in ('a', 'b', 'd')'
clause)

A bit obscure I know. Hopefully you can all follow. Please help.
Oct 29 '08 #1
3 2295
On Oct 29, 1:59*pm, bob laughland <peter.mcclym...@gmail.comwrote:
Hi All,

I have a SQL query like this (I have tried to break the problem down
to simplify it),

select rowid from table where name in ('a', 'b', 'd') group by rowid

Here is an example of data in the table

rowid * *name
1 * * * * * *a
1 * * * * * *b
1 * * * * * *c
1 * * * * * *d
2 * * * * * *a
2 * * * * * *b

That query gives back row 1, and 2. But that is not what I want it to
do.

What I actually want it to do is give me back rowids of records which
have 'all' of the items in the 'name in ('a', 'b', 'd')' clause.

E.g. I want it to return back rowid 1 only because it has a row with
a, b, and d, but I don't want it to return back 2 because it doesn't
have a row with the name d (which is in my 'name in ('a', 'b', 'd')'
clause)

A bit obscure I know. Hopefully you can all follow. Please help.
OK - so there is perhaps an obvious answer I think, what about

select rowid from table where name = 'a' and name = 'b' and name =
'd' group by rowid

But one thing I didn't mention before is that potentially I could have
1000 things to query on, e.g. where name = '1' and name =
'2' .......... and name = '1000'

Is that a problem? The query string could become massive, and how
would that affect performance?

Thanks.
Oct 29 '08 #2
This is called relational division. Here is a query that will solve the
problem:

SELECT rowid
FROM Foo
WHERE name in ('a', 'b', 'd')
GROUP BY rowid
HAVING COUNT(name) = 3;

A better approach is to define a table with the items you want to query
on (in your case names) and use that table as divisor.

CREATE TABLE Names (
name CHAR(1) PRIMARY KEY);

INSERT INTO Names VALUES ('a');
INSERT INTO Names VALUES ('b');
INSERT INTO Names VALUES ('d');

Then you can query like this:

SELECT rowid
FROM Foo AS F
JOIN Names AS N
ON F.name = N.name
GROUP BY rowid
HAVING COUNT(F.name) = (SELECT COUNT(name) FROM Names);

--
Plamen Ratchev
http://www.SQLStudio.com
Oct 29 '08 #3
>A bit obscure I know. <<

Actually, it is called Relational Division and it was one of Codd's
original 8 operations. Here is an old "cut & paste" of mine:
Relational division is one of the eight basic operations in Codd's
relational algebra. The idea is that a divisor table is used to
partition a dividend table and produce a quotient or results table.
The quotient table is made up of those values of one column for which
a second column had all of the values in the divisor. There is a
really good presentation on four ways to do this at:
http://www.cs.arizona.edu/people/mcc...esentation.pdf

This is easier to explain with an example. We have a table of pilots
and the planes they can fly (dividend); we have a table of planes in
the hangar (divisor); we want the names of the pilots who can fly
every plane (quotient) in the hangar. To get this result, we divide
the PilotSkills table by the planes in the hangar.

CREATE TABLE PilotSkills
(pilot CHAR(15) NOT NULL,
plane CHAR(15) NOT NULL,
PRIMARY KEY (pilot, plane));

PilotSkills
pilot plane
=========================
'Celko' 'Piper Cub'
'Higgins' 'B-52 Bomber'
'Higgins' 'F-14 Fighter'
'Higgins' 'Piper Cub'
'Jones' 'B-52 Bomber'
'Jones' 'F-14 Fighter'
'Smith' 'B-1 Bomber'
'Smith' 'B-52 Bomber'
'Smith' 'F-14 Fighter'
'Wilson' 'B-1 Bomber'
'Wilson' 'B-52 Bomber'
'Wilson' 'F-14 Fighter'
'Wilson' 'F-17 Fighter'

CREATE TABLE Hangar
(plane CHAR(15) NOT NULL PRIMARY KEY);

Hangar
plane
=============
'B-1 Bomber'
'B-52 Bomber'
'F-14 Fighter'

PilotSkills DIVIDED BY Hangar
pilot
=============================
'Smith'
'Wilson'

In this example, Smith and Wilson are the two pilots who can fly
everything in the hangar. Notice that Higgins and Celko know how to
fly a Piper Cub, but we don't have one right now. In Codd's original
definition of relational division, having more rows than are called
for is not a problem.

The important characteristic of a relational division is that the
CROSS JOIN (Cartesian product) of the divisor and the quotient
produces a valid subset of rows from the dividend. This is where the
name comes from, since the CROSS JOIN acts like a multiplication
operator.

Division with a Remainder

There are two kinds of relational division. Division with a remainder
allows the dividend table to have more values than the divisor, which
was Codd's original definition. For example, if a pilot can fly more
planes than just those we have in the hangar, this is fine with us.
The query can be written in SQL-89 as

SELECT DISTINCT pilot
FROM PilotSkills AS PS1
WHERE NOT EXISTS
(SELECT *
FROM Hangar
WHERE NOT EXISTS
(SELECT *
FROM PilotSkills AS PS2
WHERE (PS1.pilot = PS2.pilot)
AND (PS2.plane = Hangar.plane)));

The quickest way to explain what is happening in this query is to
imagine an old World War II movie where a cocky pilot has just walked
into the hangar, looked over the fleet, and announced, "There ain't no
plane in this hangar that I can't fly!" We are finding the pilots for
whom there does not exist a plane in the hangar for which they have no
skills. The use of the NOT EXISTS() predicates is for speed. Most
SQL systems will look up a value in an index rather than scan the
whole table. The SELECT * clause lets the query optimizer choose the
column to use when looking for the index.

This query for relational division was made popular by Chris Date in
his textbooks, but it is not the only method nor always the fastest.
Another version of the division can be written so as to avoid three
levels of nesting. While it is not original with me, I have made it
popular in my books.

SELECT PS1.pilot
FROM PilotSkills AS PS1, Hangar AS H1
WHERE PS1.plane = H1.plane
GROUP BY PS1.pilot
HAVING COUNT(PS1.plane) = (SELECT COUNT(plane) FROM Hangar);

There is a serious difference in the two methods. Burn down the
hangar, so that the divisor is empty. Because of the NOT EXISTS()
predicates in Date's query, all pilots are returned from a division by
an empty set. Because of the COUNT() functions in my query, no pilots
are returned from a division by an empty set.

In the sixth edition of his book, INTRODUCTION TO DATABASE SYSTEMS
(Addison-Wesley; 1995 ;ISBN 0-201-82458-2), Chris Date defined another
operator (DIVIDEBY ... PER) which produces the same results as my
query, but with more complexity.

Exact Division

The second kind of relational division is exact relational division.
The dividend table must match exactly to the values of the divisor
without any extra values.

SELECT PS1.pilot
FROM PilotSkills AS PS1
LEFT OUTER JOIN
Hangar AS H1
ON PS1.plane = H1.plane
GROUP BY PS1.pilot
HAVING COUNT(PS1.plane) = (SELECT COUNT(plane) FROM Hangar)
AND COUNT(H1.plane) = (SELECT COUNT(plane) FROM Hangar);

This says that a pilot must have the same number of certificates as
there planes in the hangar and these certificates all match to a plane
in the hangar, not something else. The "something else" is shown by a
created NULL from the LEFT OUTER JOIN.

Please do not make the mistake of trying to reduce the HAVING clause
with a little algebra to:

HAVING COUNT(PS1.plane) = COUNT(H1.plane)

because it does not work; it will tell you that the hangar has (n)
planes in it and the pilot is certified for (n) planes, but not that
those two sets of planes are equal to each other.

Note on Performance

The nested EXISTS() predicates version of relational division was made
popular by Chris Date's textbooks, while the author is associated with
popularizing the COUNT(*) version of relational division. The Winter
1996 edition of DB2 ON-LINE MAGAZINE (http://www.db2mag.com/
96011ar:htm) had an article entitled "Powerful SQL:Beyond the Basics"
by Sheryl Larsen which gave the results of testing both methods. Her
conclusion for DB2 was that the nested EXISTS() version is better when
the quotient has less than 25% of the dividend table's rows and the
COUNT(*) version is better when the quotient is more than 25% of the
dividend table.
Oct 29 '08 #4

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

9
by: majsen | last post by:
Hi, I have problem running this query. It will time out for me... My database are small just about 200 members. I have a site for swaping appartments (rental). my query should look for match in...
8
by: Együd Csaba | last post by:
Hi All, how can I improve the query performance in the following situation: I have a big (4.5+ million rows) table. One query takes approx. 9 sec to finish resulting ~10000 rows. But if I run...
3
by: John Ortt | last post by:
> I have a table of dates in ascending order but with varying intervals. I > would like to create a query to pull out the date (in field 1) and then pull > the date from the subsequent record...
3
by: Ekqvist Marko | last post by:
Hi, I have one Access database table including questions and answers. Now I need to give answer id automatically to questionID column. But I don't know how it is best (fastest) to do? table...
7
by: serge | last post by:
How can I run a single SP by asking multiple sales question either by using the logical operator AND for all the questions; or using the logical operator OR for all the questions. So it's always...
6
by: jjturon | last post by:
Can anyone help me?? I am trying to pass a Select Query variable to a table using Dlookup and return the value to same select query but to another field. Ex. SalesManID ...
2
by: mmitchell_houston | last post by:
I'm working on a .NET project and I need a single query to return a result set from three related tables in Access 2003, and I'm having trouble getting the results I want. The details: ...
22
by: Stan | last post by:
I am working with Access 2003 on a computer running XP. I am new at using Access. I have a Db with a date field stored as mm/dd/yyyy. I need a Query that will prompt for the month, ie. 6 for...
3
by: Richard Hollenbeck | last post by:
I am very sorry about the (almost) re-post, but you will see that my first question wasn't very clear; I have another question I posted this morning called, "in DAO: Run time error 3061 Too few...
16
by: ARC | last post by:
Hello all, So I'm knee deep in this import utility program, and am coming up with all sorts of "gotcha's!". 1st off. On a "Find Duplicates Query", does anyone have a good solution for...
0
by: emmanuelkatto | last post by:
Hi All, I am Emmanuel katto from Uganda. I want to ask what challenges you've faced while migrating a website to cloud. Please let me know. Thanks! Emmanuel
1
by: nemocccc | last post by:
hello, everyone, I want to develop a software for my android phone for daily needs, any suggestions?
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...
0
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each...
0
agi2029
by: agi2029 | last post by:
Let's talk about the concept of autonomous AI software engineers and no-code agents. These AIs are designed to manage the entire lifecycle of a software development project—planning, coding, testing,...
0
by: conductexam | last post by:
I have .net C# application in which I am extracting data from word file and save it in database particularly. To store word all data as it is I am converting the whole word file firstly in HTML and...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.