Question:
[Joe Celko’s Budget Versus Actual Puzzle]
C. Conrad Cady posted a simple SQL problem on the CompuServe Gupta Forum. He has two tables, Budgeted and Actual, which describe how a project is being done. Budgeted has a one-to-many relationship with Actual. The tables are defined like this:
CREATE TABLE Budgeted (task INTEGER NOT NULL PRIMARY KEY, category INTEGER NOT NULL, est_cost DECIMAL(8,2) NOT NULL); CREATE TABLE Actual (voucher DECIMAL(8,2) NOT NULL PRIMARY KEY, task INTEGER NOT NULL REFERENCES Budgeted(task), act_cost DECIMAL(8,2) NOT NULL);He wants a Budgeted versus Actual comparison for each category. This is easier to see with an example.
Budgeted task category est_cost ====================== 1 9100 $100.00 2 9100 $15.00 3 9100 $6.00 4 9200 $8.00 5 9200 $11.00 Actual voucher task act_cost ====================== 1 1 $10.00 2 1 $20.00 3 1 $15.00 4 2 $32.00 5 4 $8.00 6 5 $3.00 7 5 $4.00The output he wants is this:
Result category estimated spent ========================== 9100 $121.00 $77.00 9200 $19.00 $15.00The $121 is the sum of the est_cost of the three task items in category 9100. The $77 is the sum of the act_cost of the four voucher items related to those three task items (three amounts are related to the first item, one to the second and none to the third).
He tried the query:
SELECT category, SUM(est_cost) AS estimated, SUM(act_cost) AS spent FROM (Budgeted LEFT OUTER JOIN Actual ON Budgeted.task = Actual.task) GROUP BY category;And he got:
Result category estimated spent ========================== 9100 $321.00 $77.00 9200 $31.00 $15.00The problem is that the $100.00 is counted three times in the join, giving $321.00 instead of $121.00 and the $11.00 is counted twice giving $31.00 instead of $19.00 in the join.
Is there a simple, single piece of SQL which will give him the output he wants, given the above tables?
Answer:
Bob Badour suggested that he can get the required result by creating a view in SQL-89:
CREATE VIEW cat_costs (category, est_cost, act_cost) AS SELECT category, est_cost, 0.00 FROM Budgeted UNION SELECT category, 0.00, act_cost FROM Budgeted, Actual WHERE Budgeted.task = Actual.task;Followed by the query:
SELECT category, SUM(est_cost), SUM(act_cost) FROM cat_costs GROUP BY category;In SQL-92, we can join the total amounts spent on each task to the category in the Budgeted table, like this:
SELECT B1.category, SUM(est_cost), SUM(spent) FROM Budgeted AS B1 LEFT OUTER JOIN (SELECT task, SUM(act_cost) AS spent FROM Actual AS A1 GROUP BY task) ON A1.task = B1.task GROUP BY B1.category;The LEFT OUTER JOIN will handle situations where no money has been spent yet. If you have a transitional SQL which does not allow subqueries in a JOIN, then extract the subquery shown here and put it in a VIEW.
Puzzle provided courtesy of:
Joe Celko
[email protected]