4D v14Support of joins |
|||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||
|
4D v14
Support of joins
|
name | depID | cityID |
Alan | 10 | 30 |
Anne | 11 | 39 |
Bernard | 10 | 33 |
Mark | 12 | 35 |
Martin | 15 | 30 |
Philip | NULL | 33 |
Thomas | 10 | NULL |
depID | depName |
10 | Program |
11 | Engineering |
NULL | Marketing |
12 | Development |
13 | Quality |
cityID | cityName |
30 | Paris |
33 | New York |
NULL | Berlin |
Note: The example structure above will be used throughout this chapter.
Here is an example of an implicit inner join:
SELECT *
FROM employees, departments
WHERE employees.DepID = departments.DepID;
In 4D, you can also use the JOIN keyword to specify an explicit inner join:
SELECT *
FROM employees
INNER JOIN departments
ON employees.DepID = departments.DepID;
You can insert this query into 4D code as follows:
ARRAY TEXT(aName;0)
ARRAY TEXT(aDepName;0)
ARRAY INTEGER(aEmpDepID;0
ARRAY INTEGER(aDepID;0)
Begin SQL
SELECT *
FROM employees
INNER JOIN departments
ON employees.depID = departments.depID
INTO :aName, :aEmpDepID, :aDepID, :aDepName;
End SQL
Here are the results of this join:
aName | aEmpDepID | aDepID | aDepName |
Alan | 10 | 10 | Program |
Anne | 11 | 11 | Engineering |
Bernard | 10 | 10 | Program |
Mark | 12 | 12 | Development |
Thomas | 10 | 10 | Program |
Note that neither the employees named Philip or Martin nor the Marketing or Quality departments appear in the resulting join because:
A cross or Cartesian join is an inner join for which no WHERE nor ON clauses have been specified. It consists in associating each row of one table with each row of another table.
The result of a cross join is the Cartesian product of the tables, containing a x b rows, where a is the number of rows in the first table and b is the number of rows in the second table. This product represents every possible combination formed by the concatenation of the rows of both tables.
Each of the following syntaxes are equivalent:
SELECT * FROM T1 INNER JOIN T2
SELECT * FROM T1, T2
SELECT * FROM T1 CROSS JOIN T2;
Here is an example of 4D code with a cross join:
ARRAY TEXT(aName;0)
ARRAY TEXT(aDepName;0)
ARRAY INTEGER(aEmpDepID;0
ARRAY INTEGER(aDepID;0)
Begin SQL
SELECT *
FROM employees CROSS JOIN departments
INTO :aName, :aEmpDepID, :aDepID, :aDepName;
End SQL
Here is the result of this join with our example database:
aName | aEmpDepID | aDepID | aDepName |
Alan | 10 | 10 | Program |
Anne | 11 | 10 | Program |
Bernard | 10 | 10 | Program |
Mark | 12 | 10 | Program |
Martin | 15 | 10 | Program |
Philip | NULL | 10 | Program |
Thomas | 10 | 10 | Program |
Alan | 10 | 11 | Engineering |
Anne | 11 | 11 | Engineering |
Bernard | 10 | 11 | Engineering |
Mark | 12 | 11 | Engineering |
Martin | 15 | 11 | Engineering |
Philip | NULL | 11 | Engineering |
Thomas | 10 | 11 | Engineering |
Alan | 10 | NULL | Marketing |
Anne | 11 | NULL | Marketing |
Bernard | 10 | NULL | Marketing |
Mark | 12 | NULL | Marketing |
Martin | 15 | NULL | Marketing |
Philip | NULL | NULL | Marketing |
Thomas | 10 | NULL | Marketing |
Alan | 10 | 12 | Development |
Anne | 11 | 12 | Development |
Bernard | 10 | 12 | Development |
Mark | 12 | 12 | Development |
Martin | 15 | 12 | Development |
Philippe | NULL | 12 | Development |
Thomas | 10 | 12 | Development |
Alain | 10 | 13 | Quality |
Anne | 11 | 13 | Quality |
Bernard | 10 | 13 | Quality |
Mark | 12 | 13 | Quality |
Martin | 15 | 13 | Quality |
Philip | NULL | 13 | Quality |
Thomas | 10 | 13 | Quality |
Note: For performance reasons, cross joins should be used with precaution.
You can now generate outer joins with 4D. With outer joins, it is not necessary for there to be a match between the rows of joined tables. The resulting table contains all the rows of the tables (or of at least one of the joined tables) even if there are no matching rows. This means that all the information of a table can be used, even if the rows are not completely filled in between the different joined tables.
There are three types of outer joins, specified using the LEFT, RIGHT and FULL keywords. LEFT and RIGHT are used to indicate the table (located to the left or right of the JOIN keyword) where all the data must be processed. FULL indicates a bilateral outer join.
Note: Only explicit outer joins are supported by 4D.
The result of a left outer join (or left join) always contains all the records for the table located to the left of keyword even if the join condition does not find a matching record in the table located to the right. This means that for each row in the left table where the search does not find any matching row in the right table, the join will still contain this row but it will have NULL values in each column of the right table. In other words, a left outer join returns all the rows of the left table plus any of those of the right table that match the join condition (or NULL if none match). Note that if the right table contains more than one row that matches the join predicate for a single row of the left table, the values of the left table will be repeated for each distinct row of the right table.
Here is an example of 4D code with a left outer join:
ARRAY TEXT(aName;0)
ARRAY TEXT(aDepName;0)
ARRAY INTEGER(aEmpDepID;0
ARRAY INTEGER(aDepID;0)
Begin SQL
SELECT *
FROM employees
LEFT OUTER JOIN departments
ON employees.DepID = departments.DepID;
INTO :aName, :aEmpDepID, :aDepID, :aDepName;
End SQL
Here is the result of this join with our example database (additional rows shown in red):
aName | aEmpDepID | aDepID | aDepName |
Alan | 10 | 10 | Program |
Anne | 11 | 11 | Engineering |
Bernard | 10 | 10 | Program |
Mark | 12 | 12 | Development |
Thomas | 10 | 10 | Program |
Martin | 15 | NULL | NULL |
Philip | NULL | NULL | NULL |
A right outer join is the exact opposite of a left outer join. Its result always contains all the records of the table located to the right of the JOIN keyword even if the join condition does not find any matching record in the left table.
Here is an example of 4D code with a right outer join:
ARRAY TEXT(aName;0)
ARRAY TEXT(aDepName;0)
ARRAY INTEGER(aEmpDepID;0
ARRAY INTEGER(aDepID;0)
Begin SQL
SELECT *
FROM employees
RIGHT OUTER JOIN departments
ON employees.DepID = departments.DepID;
INTO :aName, :aEmpDepID, :aDepID, :aDepName;
End SQL
Here is the result of this join with our example database (additional rows shown in red):
aName | aEmpDepID | aDepID | aDepName |
Alan | 10 | 10 | Program |
Anne | 11 | 11 | Engineering |
Bernard | 10 | 10 | Program |
Mark | 12 | 12 | Development |
Thomas | 10 | 10 | Program |
NULL | NULL | NULL | Marketing |
NULL | NULL | 13 | Quality |
A full outer join simply combines together the results of a left outer join and a right outer join. The resulting join table contains all the records of the left and right tables and fills in the missing fields on each side with NULL values.
Here is an example of 4D code with a full outer join:
ARRAY TEXT(aName;0)
ARRAY TEXT(aDepName;0)
ARRAY INTEGER(aEmpDepID;0
ARRAY INTEGER(aDepID;0)
Begin SQL
SELECT *
FROM employees
FULL OUTER JOIN departments
ON employees.DepID = departments.DepID;
INTO :aName, :aEmpDepID, :aDepID, :aDepName;
End SQL
Here is the result of this join with our example database (additional rows shown in red):
aName | aEmpDepID | aDepID | aDepName |
Alan | 10 | 10 | Program |
Anne | 11 | 11 | Engineering |
Bernard | 10 | 10 | Program |
Mark | 12 | 12 | Development |
Thomas | 10 | 10 | Program |
Martin | 15 | NULL | NULL |
Philip | NULL | NULL | NULL |
NULL | NULL | NULL | Marketing |
NULL | NULL | 13 | Quality |
It is possible to combine several joins in the same SELECT statement. It is also possible to mix implicit or explicit inner joins and explicit outer joins.
Here is an example of 4D code with multiple joins:
ARRAY TEXT(aName;0)
ARRAY TEXT(aDepName;0)
ARRAY TEXT(aCityName;0)
ARRAY INTEGER(aEmpDepID;0
ARRAY INTEGER(aEmpCityID;0)
ARRAY INTEGER(aDepID;0)
ARRAY INTEGER(aCityID;0)
Begin SQL
SELECT *
FROM (employees RIGHT OUTER JOIN departments
ON employees.depID = departments.depID)
LEFT OUTER JOIN cities
ON employees.cityID = cities.cityID
INTO :aName, :aEmpDepID, :aEmpCityID, :aDepID, :aDepName, :aCityID, :aCityName;
End SQL
Here is the result of this join with our example database:
aName | aEmpDepID | aEmpCityID | aDepID | aDepName | aCityID | aCityName |
Alan | 10 | 30 | 10 | Program | 30 | Paris |
Anne | 11 | 39 | 11 | Engineering | 0 | |
Bernard | 10 | 33 | 10 | Program | 33 | New York |
Mark | 12 | 35 | 12 | Development | 0 | |
Thomas | 10 | NULL | 10 | Program | 0 |
Product: 4D
Theme: Using SQL in 4D
4D SQL Reference ( 4D v14)
4D SQL Reference ( 4D v12.1)
4D SQL Reference ( 4D v13.4)
4D SQL Reference ( 4D v14 R2)
4D SQL Reference ( 4D v14 R3)
4D SQL Reference ( 4D v14 R4)