Write here your abstract

1 SQL ANSI Joins Example

Prepare tables for test execution and populate with data:

Copy
DROP TABLE IF EXISTS department;
CREATE TEMP TABLE department
(
  deptId INTEGER NOT NULL PRIMARY KEY,
  deptName CHAR(20) NOT NULL
);

DROP TABLE IF EXISTS employee;
CREATE TEMP TABLE employee 
(
  empId INTEGER NOT NULL PRIMARY KEY,
  empName CHAR(20) NOT NULL,
  deptId INTEGER REFERENCES department(deptId)
);


INSERT INTO department VALUES(101, "Research");
INSERT INTO department VALUES(102, "Customer Service");
INSERT INTO department VALUES(103, "Marketing");

INSERT INTO employee VALUES(1, "Dan", 102);
INSERT INTO employee VALUES(2, "Penny", 101);
INSERT INTO employee VALUES(3, "Sheldon", 101);
INSERT INTO employee VALUES(4, "Raj", null);

Normal WHERE clause INNER KOIN

Copy
SELECT empName, deptName
  FROM employee E, department D
 WHERE e.deptID = D.deptId;
+--------------------+--------------------+
|empname             |deptname            |
+--------------------+--------------------+
|Dan                 |Customer Service    |
|Penny               |Research            |
|Sheldon             |Research            |
+--------------------+--------------------+

The ANSI INNER JOIN syntax can be also used to perform a JOIN. It has the advantage of moving the JOIN syntax into the FROM clause

Copy
SELECT empName, deptName
  FROM employee E INNER JOIN department D
       ON e.deptId = d.deptId
 WHERE d.deptName NOT LIKE 'Account%';
+--------------------+--------------------+
|empname             |deptname            |
+--------------------+--------------------+
|Dan                 |Customer Service    |
|Penny               |Research            |
|Sheldon             |Research            |
+--------------------+--------------------+

The OUTER JOIN syntax can be used to obtain data that exists in one table without matching data in the other table

Copy
SELECT empName, deptName
  FROM employee E LEFT OUTER JOIN department D
       ON e.deptId = d.deptId;
+--------------------+--------------------+
|empname             |deptname            |
+--------------------+--------------------+
|Dan                 |Customer Service    |
|Penny               |Research            |
|Sheldon             |Research            |
|Raj                 |                    |
+--------------------+--------------------+

ANSI JOINS allows to add filtering of rows after the join operations descrived in the ON clause is performed:

Copy
SELECT empName, D.deptName
  FROM employee E LEFT OUTER JOIN department D
       ON e.deptId = d.deptId
WHERE D.deptName is null  ;
+--------------------+--------------------+
|empname             |deptname            |
+--------------------+--------------------+
|Raj                 |                    |
+--------------------+--------------------+

The unmatched data can come from either table ehere a RIGHT or LEFT OUTER JOIN is used

Copy
SELECT empName, D.deptName
  FROM employee E RIGHT OUTER JOIN department D
       ON e.deptId = d.deptId;
+--------------------+--------------------+
|empname             |deptname            |
+--------------------+--------------------+
|Penny               |Research            |
|Sheldon             |Research            |
|Dan                 |Customer Service    |
|                    |Marketing           |
+--------------------+--------------------+

The unmatched data from either table are included as a result of a FULL OUTER JOIN.

Copy
SELECT empName, deptName
  FROM employee E FULL OUTER JOIN department D
       ON e.deptId = d.deptId;
+--------------------+--------------------+
|empname             |deptname            |
+--------------------+--------------------+
|Dan                 |Customer Service    |
|Penny               |Research            |
|Sheldon             |Research            |
|Raj                 |                    |
|                    |Marketing           |
+--------------------+--------------------+