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 Wednesday, August 31, 2011 8:22 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
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(
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 Transactions(
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM)
SELECT 1,
'1/1/2011',
123,
'R',
1000,
'GA'

INSERT INTO Transactions(
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM)
SELECT 2,
'1/2/2011',
123,
'S',
-100,
'GA'

INSERT INTO Transactions(
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM)
SELECT 3,
'1/3/2011',
123,
'R',
500,
'GA'

INSERT INTO Transactions(
trnKey,
trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM)
SELECT 4,
'1/4/2011',
123,
'S',
-100,
'GA'

INSERT INTO Receipts(
recKey,
recTrnKey,
recIngKey,
recIngPct)
SELECT 1,
1,
1,
75

INSERT INTO Receipts(
recKey,
recTrnKey,
recIngKey,
recIngPct)
SELECT 2,
1,
2,
25

INSERT INTO Receipts(
recKey,
recTrnKey,
recIngKey,
recIngPct)
SELECT 3,
3,
1,
80

INSERT INTO Receipts(
recKey,
recTrnKey,
recIngKey,
recIngPct)
SELECT 4,
3,
2,
10

INSERT INTO Receipts(
recKey,
recTrnKey,
recIngKey,
recIngPct)
SELECT 5,
3,
3,
10

SELECT trnTranDate,
trnProductID,
trnShipRecv,
trnTranQty,
trnTranUOM,
ingIngrientDesc,
recIngPct,
trnTranQty * recIngPct / 100 AS recIngQty,
'?' AS shipIngPct

FROM Transactions
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



  Post Attachments 
Pcts.xlsx (9 views, 9.84 KB)
Post #1168462
Posted Thursday, September 1, 2011 1:31 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 2:06 PM
Points: 1,901, Visits: 19,000
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 !
__________________________________________________________________
Post #1168503
Posted Thursday, September 1, 2011 3:33 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:38 AM
Points: 7,208, Visits: 13,669
The calculations in your spreadsheet appear to be incorrect, this is what I think it should look like:


Ingr Pct Ingr Qty Inventory 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

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
Exploring Recursive CTEs by Example Dwain Camps
Post #1168550
Posted Thursday, September 1, 2011 7:48 AM
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
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.
Post #1168666
Posted Thursday, September 1, 2011 3:40 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
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?
Post #1168960
Posted Thursday, September 1, 2011 4:04 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 2:06 PM
Points: 1,901, Visits: 19,000
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 !
__________________________________________________________________
Post #1168963
Posted Thursday, September 1, 2011 4:24 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
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 ). 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...
Post #1168969
Posted Thursday, September 1, 2011 11:01 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 2:24 PM
Points: 1,945, Visits: 2,908
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 [no such table in your code] 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.

Thanks for the DDL. Please learn ISO-11179 naming rules and basic data modeling. We have DATE data types and use ISO-8601 dates. We have ANSI/ISO Row constructors. You are using cursors because you are writing 1950's file systems code in SQL. Here is the skeleton analysis.

Never put the table name as a column prefix (that was COBOL record definition not SQL). 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). Why did there no DRI or other constraints? (answer: files do not have them).

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.

The use of camelCase is also out of date, a bitch to read and not ISO. Why did you do a percentage with DECIMAL(18,5)? That just invites huge errors. 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.

CREATE TABLE Inventory_Transactions
(inventory_ticket_nbr INTEGER NOT NULL PRIMARY KEY,
ticket_date DATE DEFAULT CURRENT_TIMESTAMP NOT NULL,
upc CHAR(13) NOT NULL NOT NULL,
ticket_qty DECIMAL(18,5) NOT NULL,
uom CHAR(2) NOT NULL);

CREATE TABLE Ingredients
(upc CHAR(13) NOT NULL PRIMARY KEY,
ingredient_desc VARCHAR(20) NOT NULL);

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

Her is the current syntax for insertions. You inserted rows one at a time, like punch cards in 1950's COBOL and not sets.


INSERT INTO Ingredients(upc, ingredient_desc)
VALUES ('1','Ingredient A'), ('2','Ingredient B'), ('3', 'Ingredient C');

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');

We can build an inventory view on this, once it is normalized

CREATE VIEW Current_Inventory_Levels (upc, onhand_qty, onhand_uom))
AS
SELECT .. FROM .. WHERE ticket_date <= CAST (CURRENT_TIMESTAMP AS DATE);

Let get that fixed later. The recipes are now easy; whyd id you do the math outside the table? Answer: COBOL was not good at math.

INSERT INTO Recipes (recipe_nbr, upc, recipe_pct)
VALUES('42', '1', .75), ('42', '2', .25),
('43', '1', .80), ('43', '2', .10), ('43', '3', .10);

So a #42 cake is 75% ingredient A and 25% ingredient B, etc.

What you will do is called a relational division. The divisor is a recipe, the dividend is the inventory. No cursors, no loop and no more COBOL, please!


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 #1169023
Posted Friday, September 2, 2011 3:13 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, August 21, 2014 3:20 AM
Points: 411, Visits: 1,400
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
Posting Performance Based Questions - Gail Shaw
Hidden RBAR - Jeff Moden
Cross Tabs and Pivots - Jeff Moden
Catch-all queries - Gail Shaw


If you don't have time to do it right, when will you have time to do it over?
Post #1169094
Posted Friday, September 2, 2011 11:48 AM
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 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.
Post #1169421
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse