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


Adding to Sales Quantities


Adding to Sales Quantities

Author
Message
ByronOne
ByronOne
SSC Eights!
SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)

Group: General Forum Members
Points: 851 Visits: 457
Hi

I have a table that forecasts our Sales for the upcoming year. It contains the following columns: Year (DATE), Company (VARCHAR), Product (VARCHAR), ProductType (VARCHAR), LastYearsSales (INT), ForecastSales (INT).

I would like to increase the ForecastSales for particular ProductTypes in the table. So for example for all the LEISURE products I would like to increase the forecasted sales figures by 1000. I don't want to add a 1000 to each LEISURE product but share the 1000 over all of the LEISURE products ie if there were 10 LEISURE products in the table then increase each of their sales by 100 (1000/10).

Thanks in advance.

BO
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)

Group: General Forum Members
Points: 91901 Visits: 38954
Perhaps something like this:



declare @ProductType varchar(???),
@SalesIncrease int;

set @ProductType = 'LEISURE';
set @SalesIncrease = 1000;

with ProductsToUpdate as (
select
Year,
Company,
Product,
ProductType,
LastYearsSales,
ForecastSales
ProductCnt = count(Product) over (partition by ProductType)
from
MyTable
where
ProductType = @ProductType
)
update ProductsToUpdate set
ForecastSales = ForecastSales + (@SalesIncrease/ProductCnt);




You will have to do a lot of testing as you didn't provide us with anything that would allows us to build a test environment to test any code we might provide.

Also, note that the integer division may result in less the requested quantity from being actually added to all products. For example 1000 distributed over 12 products would actually result in a total increase of 996, not 1000.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
ByronOne
ByronOne
SSC Eights!
SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)

Group: General Forum Members
Points: 851 Visits: 457
Thanks Lynn - this is perfect!!!

BO
ByronOne
ByronOne
SSC Eights!
SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)SSC Eights! (851 reputation)

Group: General Forum Members
Points: 851 Visits: 457
Hi Lynn

Is it possible to adapt this code slightly so that rather than updating the sales figures for a specified product type ie LEISURE. It creates a new product type ie NEW_LEISURE with the new sales figures.

Basically I want to update the sales figures but I'd like to keep a record of the old sales figures too.

Hope that makes sense..

BO
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)SSC Guru (91K reputation)

Group: General Forum Members
Points: 91901 Visits: 38954
ByronOne (4/11/2013)
Hi Lynn

Is it possible to adapt this code slightly so that rather than updating the sales figures for a specified product type ie LEISURE. It creates a new product type ie NEW_LEISURE with the new sales figures.

Basically I want to update the sales figures but I'd like to keep a record of the old sales figures too.

Hope that makes sense..

BO


Don't know. Since I don't have access to your database, I am extremely limited in what I can do. Perhaps if you were to read the first article I reference in my signature block below and provide the DDL (CREATE TABLE statement) for the table(s) involved, sample data as a series of INSERT INTO statements for the table(s), expected results based on the sample data someone may be help with this modification.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40112 Visits: 20000
ByronOne (4/11/2013)
Hi Lynn

Is it possible to adapt this code slightly so that rather than updating the sales figures for a specified product type ie LEISURE. It creates a new product type ie NEW_LEISURE with the new sales figures.

Basically I want to update the sales figures but I'd like to keep a record of the old sales figures too.

Hope that makes sense..

BO


You might find it more useful to create a whole new forecast for your new figures. Add a new column say ForecastID to your table. All existing rows take ForecastID = 1, this new iteration takes ForecastID = 2. You can have any number of forecasts in the table.

“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 (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40112 Visits: 20000
Last years' sales belong in a different table, say SalesHistory - with a column for time period, in your current case - year. This makes both tables narrower and allows you to easily compare any forecast to any previous years' actuals. It also facilitates changing the granularity. You can see where this is going - sooner or later the business will want forecasts by month or even by week.

“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