SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Calculate component percents without a cursor


Calculate component percents without a cursor

Author
Message
gcresse
gcresse
Mr or Mrs. 500
Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)

Group: General Forum Members
Points: 504 Visits: 436
Thanks for your reply, R.P.Rozema.
Isn't the essence of your problem that you are trying to calculate off of percentages of a volume per shipment? In other words, shouldn't you store absolute quantities of the components inserted instead of percentages of the received shipment? I.e. from the volume and percentages of a receipt you can easily calculate the absolute quantities of each component and merge those into the quantities already there (very much like the liquids themselves). Calculating the percentages over the contents over the entire tank or a partial shipment taken from it will be an easy task given the volume of the tank/shipment and the absolute quantities in your table.

Yes, you are correct. If I could store the running balances of the individual components at each transactions, my problem would be solved. But, users are not perfect, and they often discover that they made a mistake (or a receiving document was incorrect) and six months ago the product that came in as 100% (1000 GA) of Napa Valley Zinfanel was actually only 75% Napa Valley Zinfandel and 25% Bakersfield Merlot. All the component qtys stored for the last 6 months are incorrect once the mistake is discovered. In reality, I don't use a cursor for this. We have a nightly batch job that builds the running totals beginning from the earliest date that any transaction was changed. This data is stored in a data warehouse and is growing exponentially large, requiring more and more database space. At one time we did use the cursor approach but the performance was unacceptable, which is why the data warehouse method was developed. I was hoping to find an alternative to the data warehousing approach (users have to wait till the next day to get the most accurate data, and if we have to make a correction farther back in time than, say, 1 year, the process takes many hours) and since the cursor approach already failed, I knew that was out of the question.
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42855 Visits: 20015
gcresse (9/1/2011)
Oops. You are correct, I have a mistake in the spreadsheet calculations.

I forgot to mention in my original post that the product is liquid and stored in a tank. As new receipts come in, they are mixed with the current inventory, changing the overall ingredient percents, so that the next shipment must take into consideration the new percents.

I have been looking at Jeff Moden's article about Quirky Updates and wonder if somehow I can use that logic. The biggest issue I see is that I have multiple "running total" variables to keep track of (several ingredients for the same product) so I'm not sure if I can make it work. Has anyone used any variation of the Quirky Update that might work for this?


Thanks for the confirmation - The formulas in J7 and J8 are incorrect, consequently the figures in rows 10 and 11 are incorrect also. With that out of the way, here's a cursorless solution:

IF(OBJECT_ID('TempDB..#PreparedData') IS NOT NULL) DROP TABLE #PreparedData;

-- Prepare a temporary table which has everything we need in place to perform the calculation
;WITH ABC AS (
SELECT
NewKey = DENSE_RANK() OVER (PARTITION BY t.trnProductID ORDER BY t.trnProductID, t.trnTranDate, t.trnShipRecv),
t.trnKey,
t.trnTranDate,
t.trnProductID,
t.trnShipRecv,
t.trnTranQty,
t.trnTranUOM,
i.ingIngrientDesc,
recIngPct = CASE WHEN trnShipRecv = 'R' AND r.recIngPct IS NULL THEN 0 ELSE r.recIngPct END,
[Ingr Qty] = CAST(NULL AS DECIMAL(18,5)),
[Ingr Pct] = CAST(NULL AS DECIMAL(7,3)),
[Inventory Qty] = CAST(NULL AS DECIMAL(18,5)),
[Inventory Pct] = CAST(NULL AS DECIMAL(7,3))
FROM Transactions t
INNER JOIN (
SELECT trnProductID, ingKey, ingIngrientDesc
FROM Transactions t
INNER JOIN Receipts r ON r.recTrnKey = t.trnKey
INNER JOIN Ingredients i ON i.ingKey = r.recIngKey
GROUP BY trnProductID, ingKey, ingIngrientDesc
) i ON i.trnProductID = t.trnProductID
LEFT JOIN Receipts r ON r.recTrnKey = t.trnKey AND i.ingKey = r.recIngKey
)
SELECT
seq = ROW_NUMBER() OVER(ORDER BY trnProductID, trnKey, ingIngrientDesc),
NewKey,
Batchkey = ROW_NUMBER() OVER(PARTITION BY trnProductID, trnKey ORDER BY ingIngrientDesc),
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM,
ingIngrientDesc,
recIngPct,
[Inventory Qty] = CASE WHEN NewKey = 1 THEN recIngPct/100.00000*trnTranQty ELSE NULL END,
[Inventory Pct] = CASE WHEN NewKey = 1 THEN recIngPct ELSE NULL END,
[Ingr Qty] = CASE WHEN NewKey = 1 THEN recIngPct/100.000*trnTranQty ELSE NULL END,
[Ingr Pct] = CASE WHEN NewKey = 1 THEN recIngPct ELSE NULL END,
TotalVolume = CASE WHEN NewKey = 1 THEN trnTranQty ELSE NULL END
INTO #PreparedData
FROM ABC
ORDER BY trnProductID, trnKey, ingIngrientDesc

-- put an index on this to make it faster:
CREATE UNIQUE CLUSTERED INDEX [CX_seq] ON #PreparedData (seq ASC)



-- run the calculation: the result is an output set.
;WITH Calculator AS (
SELECT
seq,
NewKey,
Batchkey,
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM,
ingIngrientDesc,
recIngPct,
[Ingr Qty] = CAST([Ingr Qty] AS DECIMAL(18,5)),
[Ingr Pct] = CAST([Ingr Pct] AS DECIMAL(7,3)),
[Inventory Qty] = CAST([Inventory Qty] AS DECIMAL(18,5)),
[Inventory Pct] = CAST([Inventory Pct] AS DECIMAL(7,3)),
TotalVolume
FROM #PreparedData
WHERE seq IN (1,2,3) -- first 3 rows are first block for this product
UNION ALL
SELECT
tr.seq,
tr.NewKey,
tr.Batchkey,
tr.trnKey,
tr.trnTranDate,
tr.trnProductID,
tr.trnShipRecv,
tr.trnTranQty,
tr.trnTranUOM,
tr.ingIngrientDesc,
recIngPct = CASE
WHEN tr.trnShipRecv = 'R' THEN tr.recIngPct
WHEN tr.trnShipRecv = 'S' THEN NULL --lr.[Inventory Pct]
END,
[Ingr Qty] = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN tr.[Ingr Qty] -- first tran for ingredient
WHEN tr.trnShipRecv = 'R' THEN tr.trnTranQty*tr.recIngPct/100.00000
WHEN tr.trnShipRecv = 'S' THEN tr.trnTranQty*lr.[Inventory Pct]/100.00000
END AS DECIMAL(18,5)),
[Ingr Pct] = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN tr.[Ingr Pct]
WHEN tr.trnShipRecv = 'R' THEN tr.recIngPct
WHEN tr.trnShipRecv = 'S' THEN lr.[Inventory Pct]
END AS DECIMAL(7,3)),
[Inventory Qty] = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN (tr.trnTranQty*tr.recIngPct/100.00000)
WHEN tr.trnShipRecv = 'R' THEN lr.[Inventory Qty]+(tr.trnTranQty*tr.recIngPct/100.00000)
WHEN tr.trnShipRecv = 'S' THEN lr.[Inventory Qty]+(tr.trnTranQty*lr.[Inventory Pct]/100.00000)
END AS DECIMAL(18,5)),
[Inventory Pct] = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN tr.[Inventory Pct]
WHEN tr.trnShipRecv = 'R' THEN 100.00000*(lr.[Inventory Qty]+(tr.trnTranQty*tr.recIngPct/100.00000)) / (tr.trnTranQty+lr.[TotalVolume])
WHEN tr.trnShipRecv = 'S' THEN lr.[Inventory Pct]
END AS DECIMAL(7,3)),
TotalVolume = CAST(CASE
WHEN tr.NewKey = 1 AND tr.trnShipRecv = 'R' THEN tr.trnTranQty
WHEN tr.NewKey > 1 THEN tr.trnTranQty+lr.[TotalVolume]
ELSE NULL END AS DECIMAL(18,5))
FROM #PreparedData tr -- this set of 3 rows
INNER JOIN Calculator lr -- last set of 3 rows
ON lr.seq+3 = tr.seq -- 3 rows at a time
) SELECT
[Date] = trnTranDate,
[Ship/Recv] = trnShipRecv,
[Product] = trnProductID,
[Tran Qty] = trnTranQty,
[UOM] = trnTranUOM,
[Ingredient] = ingIngrientDesc,
[Ingr Pct],
[Ingr Qty],
[Inventory Qty],
[Inventory Pct]
FROM Calculator ORDER BY seq



If this works ok on a decent set of sample data, then there's scope for altering it to run over different products.

You could do this with the QU if you pivoted the ingredient rows to columns.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42855 Visits: 20015
Here's a mod which works across different products with different numbers of ingredients:

USE tempdb
GO
CREATE TABLE Transactions(
trnKey INTEGER NOT NULL,
trnTranDate DATETIME NOT NULL,
trnProductID INTEGER NOT NULL,
trnShipRecv CHAR(1) NOT NULL,
trnTranQty DECIMAL(18,5) NOT NULL,
trnTranUOM CHAR(2) NOT NULL,
PRIMARY KEY (trnKey)
)

CREATE TABLE Ingredients(
ingKey INTEGER NOT NULL,
ingIngrientDesc VARCHAR(20) NOT NULL,
PRIMARY KEY (ingKey)
)

CREATE TABLE Receipts(
recKey INTEGER NOT NULL,
recTrnKey INTEGER NOT NULL,
recIngKey INTEGER NOT NULL,
recIngPct DECIMAL(18,5) NOT NULL,
PRIMARY KEY (recKey)
)

INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT 1,'Ingredient A'
INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT 2,'Ingredient B'
INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT 3,'Ingredient C'
INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT 4,'Ingredient D'

INSERT INTO Transactions(trnKey, trnTranDate, trnProductID, trnShipRecv, trnTranQty, trnTranUOM)
SELECT 1, '1/1/2011', 123, 'R', 1000, 'GA' UNION ALL
SELECT 2, '1/2/2011', 123, 'S', -100, 'GA' UNION ALL
SELECT 3, '1/2/2011', 123, 'S', -200, 'GA' UNION ALL
SELECT 4, '1/3/2011', 123, 'R', 500, 'GA' UNION ALL
SELECT 5, '1/4/2011', 123, 'S', -100, 'GA' UNION ALL
SELECT 6, '1/1/2011', 124, 'R', 100, 'GA' UNION ALL
SELECT 7, '1/2/2011', 124, 'S', -50, 'GA' UNION ALL
SELECT 8, '1/3/2011', 124, 'R', 100, 'GA' UNION ALL
SELECT 9, '1/4/2011', 124, 'S', -150, 'GA'

INSERT INTO Receipts(recKey, recTrnKey, recIngKey, recIngPct)
SELECT 1, 1, 1, 75 UNION ALL
SELECT 2, 1, 2, 25 UNION ALL
SELECT 3, 4, 1, 80 UNION ALL
SELECT 4, 4, 2, 10 UNION ALL
SELECT 5, 4, 3, 10 UNION ALL
SELECT 6, 6, 1, 78 UNION ALL
SELECT 7, 6, 2, 22 UNION ALL
SELECT 8, 8, 1, 80 UNION ALL
SELECT 9, 8, 2, 10 UNION ALL
SELECT 10, 8, 3, 5 UNION ALL
SELECT 11, 8, 4, 5;

IF(OBJECT_ID('TempDB..#PreparedData') IS NOT NULL) DROP TABLE #PreparedData;

-- Prepare a temporary table which has everything we need in place to perform the calculation
;WITH ABC AS (
SELECT
seq = ROW_NUMBER() OVER(ORDER BY t.trnProductID, t.trnKey, ingIngrientDesc),
NewKey = DENSE_RANK() OVER (PARTITION BY t.trnProductID ORDER BY t.trnProductID, t.trnTranDate, t.trnShipRecv),
ingCount = COUNT(*) OVER(PARTITION BY t.trnProductID, t.trnKey),
t.trnKey,
t.trnTranDate,
t.trnProductID,
t.trnShipRecv,
t.trnTranQty,
t.trnTranUOM,
i.ingIngrientDesc,
r.recIngPct
FROM Transactions t
INNER JOIN (
SELECT trnProductID, ingKey, ingIngrientDesc
FROM Transactions t
INNER JOIN Receipts r ON r.recTrnKey = t.trnKey
INNER JOIN Ingredients i ON i.ingKey = r.recIngKey
GROUP BY trnProductID, ingKey, ingIngrientDesc
) i ON i.trnProductID = t.trnProductID
LEFT JOIN Receipts r ON r.recTrnKey = t.trnKey AND i.ingKey = r.recIngKey
)
SELECT
seq,
NewKey,
ingCount,
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM,
ingIngrientDesc,
recIngPct = CASE WHEN trnShipRecv = 'R' THEN ISNULL(recIngPct,0) END,
[Ingr Qty] = CAST(CASE WHEN trnShipRecv = 'R' THEN ISNULL(trnTranQty*recIngPct,0)/100.00000 END AS DECIMAL(18,5)),
[Ingr Pct] = CAST(CASE WHEN trnShipRecv = 'R' THEN ISNULL(recIngPct,0) END AS DECIMAL(9,5)),
[Inventory Qty] = CAST(CASE WHEN NewKey = 1 THEN ISNULL(trnTranQty*recIngPct,0)/100.00000 ELSE NULL END AS DECIMAL(18,5)),
[Inventory Pct] = CAST(CASE WHEN NewKey = 1 THEN ISNULL(recIngPct,0) ELSE NULL END AS DECIMAL(9,5)),
TotalVolume = CASE WHEN NewKey = 1 THEN trnTranQty ELSE NULL END
INTO #PreparedData
FROM ABC
ORDER BY trnProductID, trnKey, ingIngrientDesc

-- This index is required for sensible performance
CREATE UNIQUE CLUSTERED INDEX [CX_seq] ON #PreparedData (seq ASC)


--SELECT * FROM #PreparedData -- 31 rows

-- run the calculation: the result is an output set.
;WITH Calculator AS (
SELECT
seq, NewKey, ingCount, trnKey, trnTranDate, trnProductID,
trnShipRecv, trnTranQty, trnTranUOM, ingIngrientDesc, recIngPct,
[Ingr Qty],
[Ingr Pct],
[Inventory Qty],
[Inventory Pct],
TotalVolume
FROM #PreparedData
WHERE trnKey = 1 -- seq IN (1,2,3) -- first 3 rows are first block for this product
UNION ALL
SELECT
tr.seq, tr.NewKey, tr.ingCount, tr.trnKey, tr.trnTranDate, tr.trnProductID,
tr.trnShipRecv, tr.trnTranQty, tr.trnTranUOM, tr.ingIngrientDesc, tr.recIngPct,
[Ingr Qty] = CAST(CASE
WHEN tr.trnShipRecv = 'R' THEN tr.[Ingr Qty]
WHEN tr.trnShipRecv = 'S' THEN tr.trnTranQty*lr.[Inventory Pct]/100.00000
END AS DECIMAL(18,5)),
[Ingr Pct] = CAST(CASE
WHEN tr.trnShipRecv = 'R' THEN tr.[Ingr Pct]
WHEN tr.trnShipRecv = 'S' THEN lr.[Inventory Pct]
END AS DECIMAL(9,5)),
[Inventory Qty] = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN tr.[Ingr Qty]
WHEN tr.trnShipRecv = 'R' THEN lr.[Inventory Qty]+tr.[Ingr Qty]
WHEN tr.trnShipRecv = 'S' THEN lr.[Inventory Qty]+(tr.trnTranQty*lr.[Inventory Pct]/100.00000)
END AS DECIMAL(18,5)),
[Inventory Pct] = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN tr.[Inventory Pct]
WHEN tr.trnShipRecv = 'R' THEN 100.00000*(lr.[Inventory Qty]+tr.[Ingr Qty]) / (tr.trnTranQty+lr.[TotalVolume])
WHEN tr.trnShipRecv = 'S' THEN lr.[Inventory Pct]
END AS DECIMAL(9,5)),
TotalVolume = CAST(CASE
WHEN tr.trnShipRecv = 'R' AND tr.NewKey = 1 THEN tr.trnTranQty
ELSE tr.trnTranQty+lr.[TotalVolume]
END AS DECIMAL(18,5))
FROM #PreparedData tr -- this set
INNER JOIN Calculator lr -- last set
ON lr.seq + tr.ingCount = tr.seq -- n rows at a time, where n = max number of ingredients for this product
) SELECT
[Date] = trnTranDate,
[Ship/Recv] = trnShipRecv,
[Product] = trnProductID,
[Tran Qty] = trnTranQty,
[UOM] = trnTranUOM,
[Ingredient]= ingIngrientDesc,
[Ingr Pct],
[Ingr Qty],
[Inventory Qty],
[Inventory Pct]
FROM Calculator
WHERE [Ingr Qty] <> 0
ORDER BY seq

-- About 3000 rows/s


DROP TABLE Receipts
DROP TABLE Transactions
DROP TABLE Ingredients




“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
gcresse
gcresse
Mr or Mrs. 500
Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)

Group: General Forum Members
Points: 504 Visits: 436
ChrisM,

This works fantastic with the test data! Thanks for your efforts. Now I will see if I can make it work with my actual tables.

I had actually thought of using the Quirky Update with a pivot table as you had mentioned so that is still a Plan B option.

Thanks, again.
gcresse
gcresse
Mr or Mrs. 500
Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)Mr or Mrs. 500 (504 reputation)

Group: General Forum Members
Points: 504 Visits: 436
Celko,

Do you have Denali or plans to move to it? DB2? Oracle? A stronger SQL product? The reason I ask is that SQL with the [ROW | RANGE] subclause and it makes this sort of thing much easier.


We're on Sql Server 2008 R2 with no immediate plans to upgrade.

Have you seen my tee shirts? “Viral Marketing does not work! Tell everyone you know!” and “Social skills are overrated, you meathead!” I am adversarial by nature and have a reputation for it. My wife is an ordained Soto Zen priest and she hits people with a stick! But on the other hand, I do not charge my consulting rates in SQL forums Smile


Made me laugh. Thanks :-D

Will you be my new best friend?


Sure, why not... ;-)
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42855 Visits: 20015
gcresse (9/6/2011)
ChrisM,

This works fantastic with the test data! Thanks for your efforts. Now I will see if I can make it work with my actual tables.

I had actually thought of using the Quirky Update with a pivot table as you had mentioned so that is still a Plan B option.

Thanks, again.


Thanks for the feedback.

The QU method is well worth a try - it's generally about 5 or 6 times faster to run than a rCTE. The rCTE is quicker and easier to code up and test, but once done and the logic is tested and sound, the same logic can be transposed quite easily to a QU.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search