Question:
[Joe Celko’s Milestones Puzzle]
This puzzle, in a little different form, came from Brian Young. His system tracks a series of dates (milestones) for each particular type of service (tos) that they sell. These dates constitute the schedule for the delivery of the service and vary with the type of service they are delivering. Their management would like to see a schedule for each shop horizontally, which I must admit is a reasonable request. They also want to be able to specify which task code (tos) to display.
Brain ran across a clever solution to this problem by Steve Roti (which is actually in the SQLServer manual p161), but it relies on the SUM function and a multiplication by 1 to yield the correct result. (That Roti guy is very clever!). Unfortunately, this technique doesn’t work with dates. So here is the table structure:
CREATE TABLE Schedule (shop CHAR (3) NOT NULL, order CHAR (10) NOT NULL, schseq SMALLINT NOT NULL CHECK (schseq IN (1,2,3), tos CHAR (2) NOT NULL, schactdate DATE);Where schseq is encoded as:
(1 = ‘processed’) (2 = ‘completed’) (3 = ‘confirmed’)The data normally appears like this:
Schedule shop order schseq tos schactdate =============================================== 002 4155526710 1 01 1994-Jul-16 002 4155526710 2 01 1994-Jul-30 002 4155526710 3 01 1994-Oct-01 002 4155526711 1 01 1994-Jul-16 002 4155526711 2 01 1994-Jul-30 002 4155526711 3 01 NULLThis is the way they would like it to appear, assuming they want to look at (tos = 01):
order processed completed confirmed ================================================ 4155526710 1994-Jul-16 1994-Jul-16 1994-Oct-01 4155526711 1994-Jul-16 1994-Jul-16 NULL
Answer:
In SQL-92, this is easy and very fast:
SELECT order, (SELECT schactdate FROM Schedule AS S1 WHERE S1.schseq = 1 AND S1.order = S0.order) AS processed, (SELECT schactdate FROM Schedule AS S2 WHERE S2.schseq = 2 AND S2.order = S0.order) AS completed, (SELECT schactdate FROM Schedule AS S3 WHERE S3.schseq = 3 AND S3.order = S0.order) AS confirmed FROM Schedule AS S0 WHERE tos = :n; — set task codeBut since Brian is working with SQL Server, which is not even close to the old SQL-89 standard, we have to fake it with UNIONS, which will run forever:
INSERT INTO Work (order, processed, completed, confirmed) SELECT order, NULL, NULL, NULL FROM Schedule AS S0 WHERE tos = :n — set task code UNION SELECT order, schactdate, NULL, NULL FROM Schedule AS S1 WHERE S1.schseq = 1 AND S1.order = :n AND tos = :nn — set task code UNION SELECT order, NULL, schactdate, NULL FROM Schedule AS S2 WHERE S2.schseq = 2 AND S2.order = :n AND tos = :nn — set task code UNION SELECT order, NULL, NULL, schactdate FROM Schedule AS S3 WHERE S3.schseq = 3 AND S3.order = :n AND tos = :nn — set task codeThis simple UNION might have to be broken down into four INSERTs.
The final query is simply:
SELECT order, MAX(processed), MAX(completed), MAX(confirmed) FROM Work GROUP BY order;The MAX() function picks the highest non-NULL value in the group, which also happens to be the only non-NULL value in the group.
Puzzle provided courtesy of:
Joe Celko
[email protected]