Employee sales commission rates increase with sales totals according to specified bands of sales total amounts—like a graduated income tax in reverse. To compute total commissions due each employee, we need to aggregate twice: first to get sales per employee, then to get commissions per employee:
The first problem is to work out how commission ranges map to sales totals to determine base amounts for calculation of each part-commission. We assume the ranges are inclusive, ie a range that starts at 1 euro is meant to include that first euro:
if amt < comstart, base amount = 0
if amt <= commend, base amount = amt-comstart+1
if amt > commend, base amount = commend-comstart+1
The second problem is how to apply every commission range row to every employee sales sum. That's a CROSS JOIN between aggregated sales and commissions:
Finally, SUM formula results to aggregate commissions on aggregated sales:
SELECT
s.employeeID,
ROUND(s.amt,2) AS Amount,
ROUND( SUM(IF(s.amt<=c.comstart,0,
IF(s.amt<=c.commend,
s.amt-c.comstart+1,
c.commend-c.comstart+1
)
) * c.pct/100),2 ) AS Commissions
FROM (
SELECT employeeID,SUM(sales) AS amt
FROM sales
GROUP BY employeeID
) AS s
JOIN commissions c
GROUP BY s.employeeID;
+------------+--------+-------------+
| employeeID | Amount | Commissions |
+------------+--------+-------------+
| 1 | 14.00 | 2.00 |
| 2 | 36.00 | 8.00 |
+------------+--------+-------------+
Here is another example. We track passenger flight bookings in three tables: flight, booking, passenger. To report all destinations per passenger, retrieve DISTINCT passenger-destination combos, then count them:
DROP TABLES IF EXISTS
flight, booking, passenger;
CREATE TABLE flight
(flight CHAR(12),source CHAR(12),
destination CHAR(12)
);
INSERT INTO flight VALUES
('ab123','dublin','london'),
('bc123','prague','london'),
('cd123','stuttgart','paris'),
('de123','paris','madrid');
CREATE TABLE booking(
flight CHAR(5),seat CHAR(2),
passenger_id INT NOT NULL
);
INSERT INTO booking VALUES
('ab123','a2',1),('bc123','a1',2),
('bc123','a2',1),('cd123','a3',1);
CREATE TABLE passenger(
passenger_id INT, name VARCHAR(12));
INSERT INTO passenger VALUES
(1,'john'),(2,'bill'),(3,'david');
SELECT x.*,COUNT(b.passenger_id) bookings
FROM (
SELECT DISTINCT
p.passenger_id, p.name, d.destination
FROM passenger p
CROSS JOIN flight d
) x
LEFT JOIN flight d
ON d.destination = x.destination
LEFT JOIN booking b
ON b.passenger_id = x.passenger_id
AND b.flight = d.flight
GROUP BY passenger_id, destination;
+--------------+-------+-------------+----------+
| passenger_id | name | destination | bookings |
+--------------+-------+-------------+----------+
| 1 | john | london | 2 |
| 1 | john | madrid | 0 |
| 1 | john | paris | 1 |
| 2 | bill | london | 1 |
| 2 | bill | madrid | 0 |
| 2 | bill | paris | 0 |
| 3 | david | london | 0 |
| 3 | david | madrid | 0 |
| 3 | david | paris | 0 |
+--------------+-------+-------------+----------+