Training, Open Source Programming Languages

This is page http://www.wellho.net/mouth/1574_.html

Our email: info@wellho.net • Phone: 01144 1225 708225

 
For 2023 (and 2024 ...) - we are now fully retired from IT training.
We have made many, many friends over 25 years of teaching about Python, Tcl, Perl, PHP, Lua, Java, C and C++ - and MySQL, Linux and Solaris/SunOS too. Our training notes are now very much out of date, but due to upward compatability most of our examples remain operational and even relevant ad you are welcome to make us if them "as seen" and at your own risk.

Lisa and I (Graham) now live in what was our training centre in Melksham - happy to meet with former delegates here - but do check ahead before coming round. We are far from inactive - rather, enjoying the times that we are retired but still healthy enough in mind and body to be active!

I am also active in many other area and still look after a lot of web sites - you can find an index ((here))
Joining MySQL tables revisited - finding nonmatching records, etc

A join lets me connect two tables one to the right of the other. Here's an example. First table - estate agents:

mysql> select agent,town,aid from agents;
+--------------------------+------------------+-----+
| agent | town | aid |
+--------------------------+------------------+-----+
| Alder King | Trowbridge | 1 |
| Connells | Trowbridge | 2 |
| DK Residential | Trowbridge | 3 |
| Jayson Kent | Melksham | 4 |
| Halifax | Trowbridge | 5 |
| Halifax | Melksham | 6 |
| Greg Pullen | Devizes | 7 |
| Town and Country Estates | Westbury | 8 |
| Davies and Davies | Bradford on Avon | 9 |
| Kavanaghs | Melksham | 10 |
+--------------------------+------------------+-----+
10 rows in set (0.17 sec)


And second table - homes for sale:

mysql> select agid,locate,asking,sid from sales;
+------+------------+--------+-----+
| agid | locate | asking | sid |
+------+------------+--------+-----+
| 10 | Semington | 225000 | 1 |
| 10 | Melksham | 195000 | 2 |
| 10 | Atworth | 237500 | 3 |
| 8 | Westbury | 152000 | 4 |
| 8 | Trowbridge | 205000 | 5 |
| 6 | Melksham | 229950 | 6 |
| 5 | Trowbridge | 335000 | 7 |
| 1 | Trowbridge | 96950 | 17 |
| 5 | Hilperton | 279950 | 8 |
| 4 | Melksham | 149950 | 9 |
| 1 | Trowbridge | 220000 | 18 |
| 4 | Melksham | 127500 | 10 |
| 11 | Melksham | 465000 | 11 |
| 3 | Semington | 222000 | 12 |
| 3 | Hilperton | 465000 | 13 |
| 2 | Westbury | 140000 | 14 |
| 2 | Trowbridge | 116000 | 15 |
| 11 | Melksham | 275000 | 16 |
| 4 | Semington | 250000 | 20 |
+------+------------+--------+-----+
19 rows in set (0.17 sec)


By default, a join connects all records in the first table with all records in the second table , so with 19 rows in one and 10 rows in the other, a joine gives me no less that 190 records!

(If the following outputs clip or folds - see here for an alternative display)

mysql> select agid,locate,asking,sid,agent,town,aid 
from sales join agents;

+------+------------+--------+-----+--------------------------+------------------+-----+
| agid | locate | asking | sid | agent | town | aid |
+------+------------+--------+-----+--------------------------+------------------+-----+
| 10 | Semington | 225000 | 1 | Alder King | Trowbridge | 1 |
| 10 | Melksham | 195000 | 2 | Alder King | Trowbridge | 1 |
| 10 | Atworth | 237500 | 3 | Alder King | Trowbridge | 1 |
| 8 | Westbury | 152000 | 4 | Alder King | Trowbridge | 1 |
| 8 | Trowbridge | 205000 | 5 | Alder King | Trowbridge | 1 |
| 6 | Melksham | 229950 | 6 | Alder King | Trowbridge | 1 |
| 5 | Trowbridge | 335000 | 7 | Alder King | Trowbridge | 1 |
| 1 | Trowbridge | 96950 | 17 | Alder King | Trowbridge | 1 |
| 5 | Hilperton | 279950 | 8 | Alder King | Trowbridge | 1 |
| 4 | Melksham | 149950 | 9 | Alder King | Trowbridge | 1 |
| 1 | Trowbridge | 220000 | 18 | Alder King | Trowbridge | 1 |
| 4 | Melksham | 127500 | 10 | Alder King | Trowbridge | 1 |
(etc)
| 3 | Hilperton | 465000 | 13 | Kavanaghs | Melksham | 10 |
| 2 | Westbury | 140000 | 14 | Kavanaghs | Melksham | 10 |
| 2 | Trowbridge | 116000 | 15 | Kavanaghs | Melksham | 10 |
| 11 | Melksham | 275000 | 16 | Kavanaghs | Melksham | 10 |
| 4 | Semington | 250000 | 20 | Kavanaghs | Melksham | 10 |
+------+------------+--------+-----+--------------------------+------------------+-----+
190 rows in set (0.36 sec)


Clearly that's not what I want - I usually want so see what connects to what, so I add an on clause to give me all the records that match as appropriate:

mysql> select agid,locate,asking,sid,agent,town,aid 
from sales join agents on aid = agid;

+------+------------+--------+-----+--------------------------+------------+-----+
| agid | locate | asking | sid | agent | town | aid |
+------+------------+--------+-----+--------------------------+------------+-----+
| 10 | Semington | 225000 | 1 | Kavanaghs | Melksham | 10 |
| 10 | Melksham | 195000 | 2 | Kavanaghs | Melksham | 10 |
| 10 | Atworth | 237500 | 3 | Kavanaghs | Melksham | 10 |
| 8 | Westbury | 152000 | 4 | Town and Country Estates | Westbury | 8 |
| 8 | Trowbridge | 205000 | 5 | Town and Country Estates | Westbury | 8 |
| 6 | Melksham | 229950 | 6 | Halifax | Melksham | 6 |
| 5 | Trowbridge | 335000 | 7 | Halifax | Trowbridge | 5 |
| 1 | Trowbridge | 96950 | 17 | Alder King | Trowbridge | 1 |
| 5 | Hilperton | 279950 | 8 | Halifax | Trowbridge | 5 |
| 4 | Melksham | 149950 | 9 | Jayson Kent | Melksham | 4 |
| 1 | Trowbridge | 220000 | 18 | Alder King | Trowbridge | 1 |
| 4 | Melksham | 127500 | 10 | Jayson Kent | Melksham | 4 |
| 3 | Semington | 222000 | 12 | DK Residential | Trowbridge | 3 |
| 3 | Hilperton | 465000 | 13 | DK Residential | Trowbridge | 3 |
| 2 | Westbury | 140000 | 14 | Connells | Trowbridge | 2 |
| 2 | Trowbridge | 116000 | 15 | Connells | Trowbridge | 2 |
| 4 | Semington | 250000 | 20 | Jayson Kent | Melksham | 4 |
+------+------------+--------+-----+--------------------------+------------+-----+
17 rows in set (0.18 sec)


Which gives me just 17 out of 190 records.

I can even ask for the other 173 records if I wish by switching to a not equals operator and getting a list of who is NOT selling what - the Estate agents you can walk into and enquire about a specific house to be told "Sorry - that one's NOT on our books". Sounds silly, doesn't it - but the query IS possible:

mysql> select agid,locate,asking,sid,agent,town,aid 
from sales join agents on aid != agid;

+------+------------+--------+-----+--------------------------+------------+-----+
| agid | locate | asking | sid | agent | town | aid |
+------+------------+--------+-----+--------------------------+------------+-----+
| 10 | Semington | 225000 | 1 | Kavanaghs | Melksham | 10 |
| 10 | Melksham | 195000 | 2 | Kavanaghs | Melksham | 10 |
| 10 | Atworth | 237500 | 3 | Kavanaghs | Melksham | 10 |
(etc}

| 2 | Trowbridge | 116000 | 15 | Kavanaghs | Melksham | 10 |
| 11 | Melksham | 275000 | 16 | Kavanaghs | Melksham | 10 |
| 4 | Semington | 250000 | 20 | Kavanaghs | Melksham | 10 |
+------+------------+--------+-----+--------------------------+------------------+-----+
173 rows in set (0.35 sec)


You may have noticed that we had 19 properties for sale, but only 17 of them came up on the "reasonable" join. That's because my data includes two properties which are not listed with any agent at all - they're for sale by owner. If I want to include extra records to ensure that I have one output row for EVERY incoming row in the leftmost of the tables in my join, I can generate the extra records by specifiying a LEFT JOIN rather than a JOIN, and the extra records are generated, NULL filled. There's a full explanation and example of left and right joins [here] and that page also shows you how to find ONLY those records which don't match - the "for sale by owner" orphans, and the estate agents with nothing for sale.
(written 2008-03-15)

 
Associated topics are indexed as below, or enter http://melksh.am/nnnn for individual articles
S157 - More MySQL commands
  [158] MySQL - LEFT JOIN and RIGHT JOIN, INNER JOIN and OUTER JOIN - (2004-12-20)
  [159] MySQL - Optimising Selects - (2004-12-21)
  [279] Getting a list of unique values from a MySQL column - (2005-04-14)
  [449] Matching in MySQL - (2005-09-24)
  [494] MySQL - a score of things to remember - (2005-11-12)
  [502] SELECT in MySQL - choosing the rows you want - (2005-11-22)
  [513] MySQL - JOIN or WHERE to link tables correctly? - (2005-12-01)
  [515] MySQL - an FAQ - (2005-12-03)
  [517] An occasional chance, and reducing data to manageable levels - (2005-12-04)
  [567] Combining similar rows from a MySQL database select - (2006-01-17)
  [572] Giving the researcher power over database analysis - (2006-01-22)
  [581] Saving a MySQL query results to your local disc for Excel - (2006-01-29)
  [591] Key facts - SQL and MySQL - (2006-02-04)
  [673] Helicopter views and tartans - (2006-04-06)
  [1213] MySQL - the order of clauses and the order of actions - (2007-06-01)
  [1235] Outputting numbers as words - MySQL with Perl or PHP - (2007-06-17)
  [1331] MySQL joins revisited - (2007-09-03)
  [1735] Finding words and work boundaries (MySQL, Perl, PHP) - (2008-08-03)
  [1904] Ruby, Perl, Linux, MySQL - some training notes - (2008-11-23)
  [2110] MySQL - looking for records in one table that do NOT correspond to records in another table - (2009-03-31)
  [2259] Grouping rows for a summary report - MySQL and PHP - (2009-06-27)
  [2448] MySQL - efficiency and other topics - (2009-10-10)
  [2643] Relating tables with joins in MySQL - (2010-02-21)
  [2644] Counting rows in joined MySQL tables - (2010-02-22)
  [2645] Optimising and caching your MySQL enquiries - (2010-02-22)
  [2647] Removing duplicates from a MySQL table - (2010-02-22)
  [3061] Databases - why data is split into separate tables, and how to join them - (2010-11-20)
  [3270] SQL - Data v Metadata, and the various stages of data selection - (2011-04-29)
  [4481] Extracting data from backups to restore selected rows from MySQL tables - (2015-05-01)


Back to
Budget tax increases hit vehicle market
Previous and next
or
Horse's mouth home
Forward to
Database design for a shopping application (MySQL)
Some other Articles
Please don't shout at me!
Spring and early summer training courses
Making PHP and MySQL training relevant to the course delegates
Database design for a shopping application (MySQL)
Joining MySQL tables revisited - finding nonmatching records, etc
Budget tax increases hit vehicle market
C - structs and unions, C++ classes and polymorphism
Await guests in the early hours
London Midland ... Merrymaker ... Percy Danks
I dont care - goodbye
4759 posts, page by page
Link to page ... 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96 at 50 posts per page


This is a page archived from The Horse's Mouth at http://www.wellho.net/horse/ - the diary and writings of Graham Ellis. Every attempt was made to provide current information at the time the page was written, but things do move forward in our business - new software releases, price changes, new techniques. Please check back via our main site for current courses, prices, versions, etc - any mention of a price in "The Horse's Mouth" cannot be taken as an offer to supply at that price.

Link to Ezine home page (for reading).
Link to Blogging home page (to add comments).

© WELL HOUSE CONSULTANTS LTD., 2024: 48 Spa Road • Melksham, Wiltshire • United Kingdom • SN12 7NY
PH: 01144 1225 708225 • EMAIL: info@wellho.net • WEB: http://www.wellho.net • SKYPE: wellho

PAGE: http://www.wellho.net/mouth/1574_.html • PAGE BUILT: Sun Oct 11 16:07:41 2020 • BUILD SYSTEM: JelliaJamb