Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Calculate component percents without a cursor Expand / Collapse
Author
Message
Posted Friday, September 2, 2011 12:07 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Tuesday, February 25, 2014 12:56 PM
Points: 77, Visits: 392
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.
Post #1169436
Posted Monday, September 5, 2011 4:19 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:43 AM
Points: 6,869, Visits: 14,178
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
Post #1169901
Posted Monday, September 5, 2011 10:06 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:43 AM
Points: 6,869, Visits: 14,178
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
Post #1170015
Posted Monday, September 5, 2011 4:27 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 12:29 PM
Points: 1,945, Visits: 3,121
>> 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? <<

I earn my living cleaning up bad SQL, so I see a lot of COBOL => <language du jour> => SQL. And, yes, I was beaten up by COBOL-ers in my youth; I was a FORTRAN II programmer. That is not really so far off; those were the only languages we had in the commercial world. The status fights were like C++ vs C# fights today. Later, I became an Algol programmer on Burroughs 5000 machinery. Totally alien.

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

That is an awful way to do an audit. In fact, it is illegal for some purposes. Triggers do not tell you who viewed the data and HIPAA, Basel II and other standards require it. It is the most expensive way to audit, too. I would use a third party tool that sits like a fence around the entire schema with its own administration and authorizations. AND its own legal staff. Same idea as keeping the log files on a separate disk. But that is another issue.

>> Perhaps it is my fault for over-simplifying the sample data. In reality, the "key" columns in these tables are IDENTITY surrogate keys.<<

IDENTITY is not any kind of key and certainly not a surrogate. This is by definition. Doesn't anyone read Dr. Codd? What you have is a count of the physical insertion attempts in one package on one machine based on random hardware events. No validation, no versification. At best, it is a fake record number from a sequential COBOL mag tape file. Not at all RDBMS.

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

There out to be job tickets or some other real key that tracks each shipment.

A surrogate key is generated by the RDBMS engine, but completely hidden from the user. Think of hashing or indexes or other access methods. You still need a relational key. Would you like the exact quote from Dr. Codd?

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

Where was the accounting department with shipment numbers and other things that can be validated and verified? Where are industry standards?

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

Good!

>> We are not baking cakes, we are making wine. Our grapes do not arrive with handy little bar codes stamped on them. <<

Will you be my new best friend?

But that does imply a UPC code on the bottles, boxes and cartons. There was a wine named “Loon Lake” or some such which had a bird on a lake for the label. But they made the bar code into a stand of bull rushes on the edge of the lake, so it became part of the art work.

>> 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 refering to a surrogate key? <<

The VIN (Vehicle Identification Number) is just a good example of a universal industry standard identifier. It is on your automobile, the DVM reoccurs, the insurance policy, etc. People can verify it instantly --- all Fords have 'F' in one certain position, etc. So I know that if the VIN says this is a Honda Diablo or a Lamborghini Civic, the VIN is wrong. I can validate it by calling the manufacturer, CarFax, my state DVM, etc. and see if the car actually exists. Try to do that with an IDENTITY.

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

Your eyes jump to Uppercase letters, so camelCase gives you a “twitch” when you read code. I cover some of the research on this that was done while I was at AIRMICS; the bottom line after two years of collecting all the research was a set of formatting rules that saved DoD 8 to 12% on the time to maintain code. Springer has a new book on this kind of testing with modern equipment, but I am out of that research now and I am not going to spend $$$ on a book.

That is part of the ISO-11179 standards. The basic format is “[<role>_]<attribute>_<property>” where the <property> is drawn from a vocabulary. The example given in the ISO document is for a “tree” which can have “tree_diameter”, “tree_species”, etc. The <role> is used when the same attribute appears in the same table in different roles such as “husband_emp_id” and “wife_emp_id” in a “Marriages” relationship table.

I cover all this in SQL PROGRAMMING STYLE.

>> What do you recommend? <<

Nothing can be more than 100%, so that sets an upper limit. How many decimal places do you measure to? Parts per million? Per billion?

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

Okay

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

This is where I got lost; I did not know about the wine part of this. So we have a receipt number that the accountants will like. Does this mean that if we receive 1000 gallons of that mix, we have “shipment details” of one tank of 750 gallons of ZN (grape code?) and a tank of 250 gallons of ZM? Or are they blended together in the shipment?

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

So this is a running version of the “water & wine puzzle”! http://en.wikipedia.org/wiki/Wine/water_mixing_problem Let me p[lay with that.

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.

No, 'gal' is the ANSI Standard abbreviation for US Gallon, not to be confused with an Imperial gallon. Ever go thru the “US Pint vs UK pint vs liter” fight in bars with fair pour rules? I figured that you would be metric since we have had 750 ml bottles, and all that stuff, for decades now. And a liter of water/beer is a kilogram, so you can use a scale for home brewing.

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

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 :)


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1170091
Posted Tuesday, September 6, 2011 6:47 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Tuesday, February 25, 2014 12:56 PM
Points: 77, Visits: 392
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.
Post #1170803
Posted Tuesday, September 6, 2011 6:58 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Tuesday, February 25, 2014 12:56 PM
Points: 77, Visits: 392
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...
Post #1170804
Posted Wednesday, September 7, 2011 1:46 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:43 AM
Points: 6,869, Visits: 14,178
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
Post #1170874
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse