I read a great article, by Pinal Dave, on SQL Joins  this week. I thought I’d add something for Non-SELECT joins as I’ve noticed a few developers missing these in their armoury. It doesn’t help that there is no standard so every database implements this differently. This is one of the few occasions where you will hear me rant about MySQL over SQL Server. The way you express Non-SELECT joins in MySQL just seems far more natural to me.

You’ll need both MySQL and SQL Server 2008 Express to follow this demo. I’ll be providing a simple script to create tables, and populate with data, for both systems. Then I’ll compare how Non-SELECT Joins are performed in each system. So get prepared to switch between environments.

SQL Server create tables and data

CREATE TABLE Employee
(
	id INTEGER IDENTITY(1, 1) NOT NULL PRIMARY KEY CLUSTERED,
	FirstName VARCHAR(20) NOT NULL,
	LastName VARCHAR(30) NOT NULL,
	Sex CHAR(1) NOT NULL,
	Dob DATE NOT NULL,
	Position VARCHAR(30) NOT NULL DEFAULT 'Unassigned',
	Salary MONEY NOT NULL
);
-- Insert some Employees
INSERT INTO Employee
(
	FirstName,
	LastName,
	Sex,
	Dob,
	Position,
	Salary
)
VALUES ('Dave','Smith','M','1978-01-01','Product Director',35000.00),
('Joe','Bloggs','M','1973-03-11','CEO',100000.00),
('John','Doe','M','1956-09-29','CFO',95000.00),
('Karen','Smith','F','1980-02-03','Marketing',60000.00),
('Clare','Jones','F','1970-10-30','Accounts',30000.00),
('Fernando','Cruz','M','1978-01-01','Technical Support',30000.00),
('Steve','Campbell','M','1975-05-17','IT Manager',45000.00);
-- Create a table for Salary adjustments
CREATE TABLE SalaryAdjustment
(
	EmployeeId INTEGER NOT NULL PRIMARY KEY CLUSTERED,
	NewSalary MONEY NOT NULL
);
-- Salary Adjustments
INSERT INTO SalaryAdjustment
(
	EmployeeId,
	NewSalary
)
VALUES
(2, 80000.00),(6, 40000.00);

-- Just a simple table containing Employee IDs
CREATE TABLE Leavers
(
	EmployeeId INTEGER NOT NULL PRIMARY KEY CLUSTERED
);
-- Insert some EmployeeIds
INSERT INTO Leavers (EmployeeId)
VALUES (2),(5);

MySQL create tables and data

CREATE TABLE Employee
(
	id INTEGER AUTO_INCREMENT NOT NULL PRIMARY KEY,
	FirstName VARCHAR(20) NOT NULL,
	LastName VARCHAR(30) NOT NULL,
	Sex CHAR(1) NOT NULL,
	Dob DATE NOT NULL,
	Position VARCHAR(30) NOT NULL DEFAULT 'Unassigned',
	Salary DECIMAL(10,2) NOT NULL
);
# Insert some Employees
INSERT INTO Employee
(
	FirstName,
	LastName,
	Sex,
	Dob,
	Position,
	Salary
)
VALUES ('Dave','Smith','M','1978-01-01','Product Director',35000.00),
('Joe','Bloggs','M','1973-03-11','CEO',100000.00),
('John','Doe','M','1956-09-29','CFO',95000.00),
('Karen','Smith','F','1980-02-03','Marketing',60000.00),
('Clare','Jones','F','1970-10-30','Accounts',30000.00),
('Fernando','Cruz','M','1978-01-01','Technical Support',30000.00),
('Steve','Campbell','M','1975-05-17','IT Manager',45000.00);
# Create a table for Salary adjustments
CREATE TABLE SalaryAdjustment
(
	EmployeeId INTEGER NOT NULL PRIMARY KEY,
	NewSalary DECIMAL(10,2) NOT NULL
);
# Salary Adjustments
INSERT INTO SalaryAdjustment
(
	EmployeeId,
	NewSalary
)
VALUES
(2, 80000.00),(6, 40000.00);
# Just a simple table containing Employee IDs
CREATE TABLE Leavers
(
	EmployeeId INTEGER NOT NULL PRIMARY KEY
);
# Insert some EmployeeIds
INSERT INTO Leavers (EmployeeId)
VALUES (2),(5);

SQL Server: UPDATE from another table with a JOIN

This SQL updates the records in Employee that are matched in the SalaryAdjustment table. While it’s second nature to me now I do recall thinking this was confusing once.

-- Update the Employee table with SalaryAdjustment
UPDATE emp
SET emp.Salary = NewSalary
FROM Employee emp
INNER JOIN SalaryAdjustment adj ON emp.id = adj.EmployeeId;

MySQL: UPDATE from another table with a JOIN

Learning Non-SELECT Joins in MySQL really was a breath of fresh air to me. This statement does the same as the SQL Server equivalent above. Doesn’t this look so more natural?

# Update the Employee table with SalaryAdjustment
UPDATE Employee, SalaryAdjustment
SET Employee.Salary = SalaryAdjustment.NewSalary
WHERE Employee.id = SalaryAdjustment.EmployeeId;

SQL Server: DELETE from another table with a JOIN

The statement will delete the records in Employee that are matched by the Leavers table. I’ve seen people act nervous about what this will actually delete!
-- Delete the Employees found in Leavers
DELETE FROM Employee
FROM Employee
INNER JOIN Leavers ON Employee.id = Leavers.EmployeeId;

MySQL: DELETE from another table with a JOIN

This statement does the same as the SQL Server equivalent above. Again, I find this syntax just so more natural to work with.

# Delete the Employees found in Leavers
DELETE FROM Employee
USING Employee, Leavers
WHERE Employee.id = Leavers.EmployeeId;

I hope these simple examples have been fun to follow and informative. Using these JOINs in your UPDATE and DELETE statements can be so much more performance pleasing, when compared to sub-selects, so they are worth knowing.