Calculate component percents without a cursor

  • I have a challenge that I have not been able to solve (without using a cursor). I have products that are made up of different ingredient components. The percentage of the ingredients are defined when the products are received into inventory. When we ship the products, we have to report the ingredient percents that were in the product when it shipped. The ingredients vary for the same product on each receipt, so the percents need to be re-calculated for each transaction. Attached is spreadsheet of a very simple example.

    The following code creates sample data that demonstrates my challenge. Without using a cursor, is there a way to efficiently (read: quickly) return the values from the Inventory Pct column of the attached spreadsheet? This sample data is very small. In the real world, I'm dealing with thousands of products and each can have hundreds of transactions and each can have hundreds of ingredients, though I only need to deal with 1 product at a time. Any ideas are greatly appreciated. Thanks.

    CREATE TABLE Transactions(

    trnKeyINTEGERNOT NULL,

    trnTranDateDATETIMENOT NULL,

    trnProductIDINTEGERNOT NULL,

    trnShipRecvCHAR(1)NOT NULL,

    trnTranQtyDECIMAL(18,5)NOT NULL,

    trnTranUOMCHAR(2)NOT NULL,

    PRIMARY KEY (trnKey)

    )

    CREATE TABLE Ingredients(

    ingKeyINTEGERNOT NULL,

    ingIngrientDescVARCHAR(20)NOT NULL,

    PRIMARY KEY (ingKey)

    )

    CREATE TABLE Receipts(

    recKeyINTEGERNOT NULL,

    recTrnKeyINTEGERNOT NULL,

    recIngKeyINTEGERNOT NULL,

    recIngPctDECIMAL(18,5)NOT NULL,

    PRIMARY KEY (recKey)

    )

    INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT1,'Ingredient A'

    INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT2,'Ingredient B'

    INSERT INTO Ingredients(ingKey, ingIngrientDesc) SELECT3,'Ingredient C'

    INSERT INTO Transactions(

    trnKey,

    trnTranDate,

    trnProductID,

    trnShipRecv,

    trnTranQty,

    trnTranUOM)

    SELECT1,

    '1/1/2011',

    123,

    'R',

    1000,

    'GA'

    INSERT INTO Transactions(

    trnKey,

    trnTranDate,

    trnProductID,

    trnShipRecv,

    trnTranQty,

    trnTranUOM)

    SELECT2,

    '1/2/2011',

    123,

    'S',

    -100,

    'GA'

    INSERT INTO Transactions(

    trnKey,

    trnTranDate,

    trnProductID,

    trnShipRecv,

    trnTranQty,

    trnTranUOM)

    SELECT3,

    '1/3/2011',

    123,

    'R',

    500,

    'GA'

    INSERT INTO Transactions(

    trnKey,

    trnTranDate,

    trnProductID,

    trnShipRecv,

    trnTranQty,

    trnTranUOM)

    SELECT4,

    '1/4/2011',

    123,

    'S',

    -100,

    'GA'

    INSERT INTO Receipts(

    recKey,

    recTrnKey,

    recIngKey,

    recIngPct)

    SELECT1,

    1,

    1,

    75

    INSERT INTO Receipts(

    recKey,

    recTrnKey,

    recIngKey,

    recIngPct)

    SELECT2,

    1,

    2,

    25

    INSERT INTO Receipts(

    recKey,

    recTrnKey,

    recIngKey,

    recIngPct)

    SELECT3,

    3,

    1,

    80

    INSERT INTO Receipts(

    recKey,

    recTrnKey,

    recIngKey,

    recIngPct)

    SELECT4,

    3,

    2,

    10

    INSERT INTO Receipts(

    recKey,

    recTrnKey,

    recIngKey,

    recIngPct)

    SELECT5,

    3,

    3,

    10

    SELECTtrnTranDate,

    trnProductID,

    trnShipRecv,

    trnTranQty,

    trnTranUOM,

    ingIngrientDesc,

    recIngPct,

    trnTranQty * recIngPct / 100AS recIngQty,

    '?'AS shipIngPct

    FROMTransactions

    LEFT OUTER JOIN

    Receipts ON (recTrnKey = trnKey)

    LEFT OUTER JOIN

    Ingredients ON (ingKey = recIngKey)

    ORDER BY trnTranDate

    DROP TABLE Receipts

    DROP TABLE Transactions

    DROP TABLE Ingredients

  • Hi

    based on the sample code you gave, for the shipment on 2011-01-04 of qty 100 of product 123.....how do we know which receipt this was taken from?

    ________________________________________________________________
    you can lead a user to data....but you cannot make them think
    and remember....every day is a school day

  • The calculations in your spreadsheet appear to be incorrect, this is what I think it should look like:

    [font="Courier New"]

    Ingr Pct Ingr QtyInventory Qty Inventory Pct

    75.00 750 750 75.00

    25.00 250 250 25.00

    75.00 -75 675 75.00

    25.00 -25 225 25.00

    80.00 400 1075 76.79

    10.00 50 275 19.64

    10.00 50 50 3.57

    76.79 -76.78571429 998.2142857 76.79

    19.64 -19.64285714 255.3571429 19.64

    3.57 -3.571428571 46.42857143 3.57

    [/font]

    It's possible to model most of your required results by adding rows to the receipts table, like this:

    INSERT INTO Receipts(recKey, recTrnKey, recIngKey, recIngPct)

    SELECT 1, 1, 1, 75 UNION ALL

    SELECT 2, 1, 2, 25 UNION ALL

    SELECT 3, 2, 1, 75 UNION ALL

    SELECT 4, 2, 2, 25 UNION ALL

    SELECT 5, 3, 1, 80 UNION ALL

    SELECT 6, 3, 2, 10 UNION ALL

    SELECT 7, 3, 3, 10 UNION ALL

    SELECT 8, 4, 1, 80 UNION ALL

    SELECT 9, 4, 2, 10 UNION ALL

    SELECT 10, 4, 3, 10

    I'm guessing that since these are shipments, you don't want them here - presumably you want the solution to "fabricate" them instead?

    “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

  • based on the sample code you gave, for the shipment on 2011-01-04 of qty 100 of product 123.....how do we know which receipt this was taken from?

    The product is liquid and stored/mixed together in a tank. The receiving qty is mixed together with the current inventory, effectively changing the overall percents with each receipt.

  • 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?

  • gcresse (9/1/2011)


    The spreadsheet calculations are correct. 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?

    The quirky update will handle more than one running total...see

    http://www.sqlservercentral.com/articles/T-SQL/68467/ Fig 19 in the article

    I would suggest that you read the article at least twice (or even twenty times 😀 ) and then make an attempt in a safe (non prod) environment...I am sure that if you get stuck and post back the code you have tried , then I would expect someone, if not Jeff himself, wil chime in.

    Based on my own experience ....if you do have problems and need to post back, then please provide a decent set of test data that is easy for us to use (see link in my sig) and also, do not try to over simplify your table and data....this quite often leads to you not getting the results you really need.

    The quirky update has a lot of rules that MUST be used.....so read the article again 😀

    ________________________________________________________________
    you can lead a user to data....but you cannot make them think
    and remember....every day is a school day

  • The quirky update will handle more than one running total...see

    http://www.sqlservercentral.com/articles/T-SQL/68467/ Fig 19 in the article

    Thanks, J. That is the very article that I'm reading (for the second time... only a dozen more to go :-D). When I say multiple variables need to be updated, I don't mean in the way that the article is updating both a running total and a running count. I don't know if you looked at my sample data or the spreadsheet, but basically it's the same variable but with any number of potential values. I receive product with 75% Ingredient A and 25% Ingredient B then later I receive more of the same product, but this time with 80% Ingredient A, 10% Ingredient B, and 10% Ingredient C. I need to re-calculate the overall percents (combine the ingredient percents from the first receiving with the ingredient percents from the second receiving). If I knew there would only ever be 3 ingredients, I could DIM @IngrArunningTotal, @IngrBrunningTotal, @IngrCrunningTotal, but there can be any number of ingredients on any number of receivings. I thought perhaps I could use a temporary table to store the running totals instead of the variables, but "RULE #5. DO NOT USE JOINS" from Jeff's article indicates that I probably can't do that... Back to reading...

  • 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.

    The only thing that could be of worry if this is a continuous process, are rounding errors. I can imagine that some components are added in very large percentages, whereas others would be inserted in very minor quantities only. Actions like taking shipments from the tank will make rounding errors have a bigger impact. If I were in control I would suggest to periodically empty the entire tank to avoid these rounding errors grow out of control. But if this is a production facility you most likely already do something like this, and thus your software rounding errors will be reset with every cleaning of the tank too.



    Posting Data Etiquette - Jeff Moden[/url]
    Posting Performance Based Questions - Gail Shaw[/url]
    Hidden RBAR - Jeff Moden[/url]
    Cross Tabs and Pivots - Jeff Moden[/url]
    Catch-all queries - Gail Shaw[/url]


    If you don't have time to do it right, when will you have time to do it over?

  • Thanks for your kind reply, Celko. Your insight into the fact that this system was originally written in COBOL and converted to VB/SQL by the COBOL developer is amazing. Were you once beaten up by a gang of COBOL geeks?

    Never put the table name as a column prefix (that was COBOL record definition not SQL).

    This particular naming convention is required in our system due to a third-party auditing program that uses triggers to write to an audit table whenever a column value is inserted/updated/deleted. If we duplicate column names between tables, that program doesn't record the audit row correctly.

    There is no such crap as a magical genetic “key” (that was a record number in mag tape files or pointer chains in network DBMS, not SQL).

    Perhaps it is my fault for over-simplifying the sample data. In reality, the "key" columns in these tables are IDENTITY surrogate keys. I did not create them that way in the sample data because I wanted to control the values to simplify. If "key" is not the correct term to describe a surrogate key, then what is? Are surrogate keys now out of style? Because before we introduced them, users had to make up their own identifiers and they kept hand-written logs or Excel spreadsheets... some of them probably chiseled the identifiers in stone tablets as a left-over from the old COBOL days.

    Why did there no DRI or other constraints? (answer: files do not have them).

    Again, my fault for over-simplifying. In reality, the tables are loaded with foreign key constraints that enforce data reference integrity.

    SQL Programmers use for particular keys; we use a VIN, not a silly invented “autokey”, etc. Let's use the UPC code to identify the Ingredients instead of a silly pseudo-pointer.

    Again, my fault for not providing the complete details of our products in an attempt to simplify. We are not baking cakes, we are making wine. Our grapes do not arrive with handy little bar codes stamped on them. I'm pretty sure you're not suggesting I assign a vehicle identification number to my grapes, but my quick Google search on your acronyms didn't give me much of a clue. Could it be that you are referreing to a surrogate key?

    The use of camelCase is also out of date, a bitch to read and not ISO.

    So if I insert underscores in my column names, I will be able to get the results I need? Who knew that such a simple fix would do the trick. I feel so stupid now.

    Why did you do a percentage with DECIMAL(18,5)?

    What do you recommend?

    Likewise, “ship_recv” looks like a mag tape file bit flag; an SQL programmer would have a received date that is NULL when the shipment is still in process. But wait! This is a redundancy status for input and output to inventory! The sign of the quantity tells us 'R' or 'S' without loss of data integrity, like you HAVE NOW.

    Again, S and R were used to over-simplify a process that not only receives and ships, but uses inputs and outputs to blend product and adjust inventory balances (which can be positive or negative numbers, so a negative qty is not necesarily a shipment). I could have left off the S and R but I need a way to identify actual shipments and receipts as opposed to movements and adjustments.

    A recipe has many ingredients so that gives us a two column real key instead of a fake mag tape record number. This is a relationship, so we need DRI in this table. But why does the ticket number have any thing to do with baking the cake?

    CREATE TABLE Recipes

    (recipe_nbr INTEGER NOT NULL,

    upc CHAR(13) NOT NULL

    REFERENCES Ingredients(upc),

    PRIMARY KEY (recipe_nbr, upc),

    recipe_pct DECIMAL(8,5) NOT NULL

    CHECK(recipe_pct BETWEEN 00.00001 AND 100.00000));

    You lost me a bit here. I didn't present a Recipe table, but rather a Receipt table that stores the details of the receipts into the plant (i.e. 75% Zinfandel Grapes from Napa Valley, 25% Zinfandel Grapes from Monterey, etc) The receipt is linked to the inventory transaction via one of those evil "key" columns -- specifically TrnKey.

    Now when we get to the Inventory, it looks like you are trying to do a COBOL record structure again, not SQL. In SQL all column are scalar and this looks like you are cramming upc codes 1, 2 and 3 into a single column!!

    Besides spitting on Dr. Codd's grave, we have no idea to which of the three ingredients the quantity applies. Also, what is a “GA”; I do not know that unit.

    INSERT INTO Inventory_Transactions

    (inventory_ticket_nbr, ticket_date, upc, ticket_qty, uom)

    VALUES (1, '2011-01-01', '123', 1000, 'GA'),

    (2, '2011-01-02', '123', -100, 'GA'),

    (3, '2011-01-03', '123', 500, 'GA'),

    (4, '2011-01-04', '123', -100, 'GA');

    Somehow you have gotten the idea that product #123 is actually referring to ingredients A, B, and C. Think of it this way. Product #123 is 2010 Napa Valley Merlot Wine. On day 1, we received 1000 GA (GA is the UOM for Gallons) and it was sourced from grapes from Farmer Joe in Napa Valley (85%) and grapes from Farmer Sam in Monterey (15%). On day 2, we bottled 100 gallons of product #123 and we must prove the percents in the bottle. On day 3 received 500 GA of product #123 but its grapes were sourced from Farmer John in Napa Valley (95%) and Farmer Dick in Bakersfield (5%). It is all mixed together in the same tank. On day 4 we bottle another 100 GA, but we need to prove the latest percents -- how much from Napa Valley and how much from Bakersfield.

    Perhaps the transition to SQL for dinosaur COBOL developers would be easier if their questions were not attacked with arrogance and petty insults.

  • 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.

  • 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

  • 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,

    trnProductIDINTEGER 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

  • 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.

  • 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 🙂

    Made me laugh. Thanks 😀

    Will you be my new best friend?

    Sure, why not... 😉

  • 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

Viewing 15 posts - 1 through 14 (of 14 total)

You must be logged in to reply to this topic. Login to reply