472,142 Members | 1,321 Online
Bytes | Software Development & Data Engineering Community
Post +

Home Posts Topics Members FAQ

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

AW: How many join do I need for a query on 3 table?

I learned MySQL last year without putting it into action; that is why
I face trouble in formulating my queries. Were it a test, then you
would have passed it, because your queries did help me solve my problem.
I'll turn to MySQL doc after getting through this pressing project.

Thanks a lot Roger!

Babale

-----Urspr=FCngliche Nachricht-----
Von: Roger Baklund [mailto:ro***@charlott.no]=20
Gesendet: Samstag, 16. August 2003 14:32
An: my***@lists.mysql.com
Cc: B. Fongo
Betreff: Re: How many join do I need for a query on 3 table?

* B. Fongo
I was able to extra the information from the first 2 tables yesterday
using following query:

SELECT Customers.Name, Customers.City, Orders.Product,
Order.Price FROM Customers inner join Orders USING (cust_id) WHERE
customers.cust_id =3D "2"

------------------------------------------------------------------------ --------------------------------------------------------
SELECT Customers.Name, Customers.City, Orders.Product,
Order.Price FROM Customers inner join Orders ON
Customers.cust_id=3DOrder.cust_id WHERE customers.cust_id =3D "2"
That was two queries, and they both have a typo preventing them from
working... are you testing us? ;)
Right now I need credit card details from a third table; and that make
the query more complicated for me.
I' m not sure weather 2 inner joins could be used. I' ll appreciate any help.
I can try. :)
I have 2 tables: Customers and orders.
What about the third table you just mentioned...?
The have following structures:
Customers Orders Payment
cust_id Product Order_id
Name Price Credit_Card
City cust_id
Order_id


This was not very readable on my screen...

When you want to show the structure of a table, use "DESC Customers;" or
even better: "SHOW CREATE TABLE Customers;". The last one will also
include
any index definitions, which is often relevant when you ask questions
about
query performance on this list. Just a friendly advice. :)

I think the above means something like this:

Customers:
cust_id INT PRIMARY KEY,
Name VARCHAR,
City VARCHAR
Orders:
Order_id INT PRIMARY KEY,
cust_id INT
Product VARCHAR,
Price INT,
Payment:
Order_id INT,
Credit_Card VARCHAR

(You can only have one product per order, and only full payments are
allowed, and you should record the date of order and date of payment,
but
that's not an issue here, I suppose.)

Ok, prepare for a "5 minute MySQL joining crash course". :)

We will build on your original query, but I will reformat it a little,
just
to make it easier to read. The original, two table query with INNER JOIN
and
ON, reformatted:

SELECT Customers.Name, Customers.City,
Orders.Product, Orders.Price
FROM Customers
INNER JOIN Orders ON
Customers.cust_id=3DOrders.cust_id
WHERE
Customers.cust_id =3D "2"

Then we can expand it with another table:

SELECT Customers.Name, Customers.City,
Orders.Product, Orders.Price,
Payment.Credit_Card // new line
FROM Customers
INNER JOIN Orders ON
Customers.cust_id=3DOrders.cust_id
INNER JOIN Payment ON // new line
Payment.Order_id=3DOrders.Order_id // new line
WHERE
Customers.cust_id =3D "2"

Now we can simplyfy this by removing some table names we don't need
(because
the column name is unique), and change the ON to USING:

SELECT Name, City, Product, Price, Credit_Card
FROM Customers
INNER JOIN Orders USING(cust_id)
INNER JOIN Payment USING(Order_id)
WHERE
Customers.cust_id =3D "2"

Note that the order of the tables are important when using USING(): the
previous table is joined with this table USING the named column(s). For
instance, you could not have joined Payment before Orders in the above
statement, because " ... Orders USING(cust_id)" then would have referred
to
the Payment table, which does not have any cust_id column.

We could have used the shortcut alias "," instead of INNER JOIN, but
then we
can not use ON or USING, and must move the join conditions to the WHERE
clause:

SELECT Name, City, Product, Price, Credit_Card
FROM Customers, Orders ,Payment
WHERE
Customers.cust_id=3DOrders.cust_id AND
Payment.Order_id=3DOrders.Order_id
Customers.cust_id =3D "2"

We could also have used NATURAL JOIN in this case, which is the same as
USING naming all columns with the same name in the two joining tables:

SELECT Name, City, Product, Price, Credit_Card
FROM Customers
NATURAL JOIN Orders
NATURAL JOIN Payment
WHERE
Customers.cust_id =3D "2"

The note about the order of the tables when using USING() also goes for
NATURAL JOIN. Regarding the question in the subject: when joining 'n'
tables, you need 'n-1' JOINS. The JOIN is always placed between two
table
names, and the first table name is always preceeded with "FROM".
Remember
that "," when used between table names in a SELECT is an alias for
"INNER
JOIN".

If you wanted to also include customers which have not payed, you would
use
LEFT JOIN:

SELECT Customers.Name, Customers.City,
Orders.Product, Orders.Price,
IF(Credit_Card,Credit_Card,'*no pay*') // changed line
FROM Customers
INNER JOIN Orders ON
Customers.cust_id=3DOrders.cust_id
LEFT JOIN Payment ON // changed line
Payment.Order_id=3DOrders.Order_id
WHERE
Customers.City =3D "Hamburg" // changed line

....or simply:

SELECT Name, City, Product, Price,
IF(Credit_Card,Credit_Card,'*no pay*') // changed line
FROM Customers
NATURAL JOIN Orders
NATURAL LEFT JOIN Payment // changed line
WHERE
Customers.City =3D "Hamburg" // changed line

Read more about joining in the manual:

<URL: http://www.mysql.com/doc/en/JOIN.html >

HTH,

--
Roger


--
MySQL General Mailing List
For list archives: http://lists.mysql.com/mysql
To unsubscribe: http://lists.mysql.com/my***********...ie.nctu.edu.tw

Jul 19 '05 #1
0 2923

This discussion thread is closed

Replies have been disabled for this discussion.

Similar topics

1 post views Thread by Phil W | last post: by
4 posts views Thread by Apple | last post: by
reply views Thread by leo001 | last post: by

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.