Beefy Boxes and Bandwidth Generously Provided by pair Networks
good chemistry is complicated,
and a little bit messy -LW
 
PerlMonks  

Re: Many-to-many relationships in databases

by Corion (Patriarch)
on Oct 28, 2005 at 06:30 UTC ( [id://503570]=note: print w/replies, xml ) Need Help??


in reply to Many-to-many relationships in databases : SOLVED

As I'm working my way through Celkos "SQL for Smarties", he points out an interesting way to map such boolean queries by using GROUP BY and HAVING:

-- find all book ids coauthored by Smith and Jones: -- (let's assume that the author_name is unique) select book_id, count(*) from authors where author_name = 'Smith' or author_name = 'Jones' group by book_id having count(*) = 2

Whether the performance of this is better or worse than selecting all books by one and all books by the other and scanning the lists in Perl, or worse than dynamically creating the self joins needs to be benchmarked. Another way to make this slightly less dynamic could be to use the IN predicate:

-- find all book ids coauthored by Smith and Jones: -- (let's assume that the author_name is unique) select book_id, count(*) from authors where author_name in ('Smith', 'Jones') group by book_id having count(*) = 2

To make it completely static, you could insert the authors into a (session-local) temporary table and cross-join that table.

Update: Oops - this approach will also return books co-authored by 'Smith', 'Jones' and 'Miller'. Depending on whether that's what you want or not, you will need to use a subselect to make sure you get all of the authors. But I'm not sure if I can come up with the correct subselect at the moment :-)

Replies are listed 'Best First'.
Re^2: Many-to-many relationships in databases
by !1 (Hermit) on Oct 28, 2005 at 20:31 UTC

    Well, you can fix it by using except on a query that gives all the book_id's where the author isn't one of 'Smith' or 'Jones'.

    select book_id from authors where author_name in ('Smith','Jones') group by book_id having count(*)=2 except select book_id from authors where author_name not in ('Smith','Jones');

    You could also alter the where clause to make certain book_id doesn't have a different author:

    select book_id from authors where author_name in ('Smith','Jones') and book_id not in ( select book_id from authors where author_name not in ('Smith','Jones') ) group by book_id having count(*)=2

    By the way, if anyone wants to read some of Joe Celko's old articles from DBMS magazine, here are some that are available from their website (the puzzles are really fun).

Log In?
Username:
Password:

What's my password?
Create A New User
Domain Nodelet?
Node Status?
node history
Node Type: note [id://503570]
help
Chatterbox?
and the web crawler heard nothing...

How do I use this?Last hourOther CB clients
Other Users?
Others exploiting the Monastery: (9)
As of 2024-04-18 09:33 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?

    No recent polls found