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

Stuck with query Expand / Collapse
Author
Message
Posted Wednesday, November 06, 2013 4:27 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Today @ 9:21 AM
Points: 33, Visits: 134
Hi All

Not sure why I'm having such a mental block on this. Below is sample code and data with inline comments and expected results. Can anyone point me in right direction of how to get the results I'm looking for?

Basically, we have revenue for one or more customers and depts for a given job.
Costs may not be relative to same customer (effectively, costs have no customer) and may be same of different departments

Need to get list of all customers we booked revenue for on any job and split total costs by revenue and match up against depts (where there is a match)

More details in comments...

For some reason I can't post when code is in post, so put in attachment


TIA

Mark


  Post Attachments 
Sample.txt (7 views, 3.08 KB)
Post #1512033
Posted Wednesday, November 06, 2013 5:45 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 6:03 PM
Points: 3,590, Visits: 5,098
Here is your code posted so others can see it easily.

-- Using SQL2008 R2
IF OBJECT_ID('tempdb..#Sales') IS NOT NULL
DROP TABLE #Sales

IF OBJECT_ID('tempdb..#Costs') IS NOT NULL
DROP TABLE #Costs

IF OBJECT_ID('tempdb..#Sales_vs_Costs') IS NOT NULL
DROP TABLE #Sales_vs_Costs


CREATE TABLE #Sales
(
CustNo INT
,JobNo VARCHAR(12)
,DeptID VARCHAR(10)
,TotalSales float
,Split float
)


CREATE TABLE #Costs
(
JobNo VARCHAR(12)
,DeptID VARCHAR(10)
,Costs float
)


CREATE TABLE #Sales_vs_Costs
(
CustNo INT
,JobNo VARCHAR(12)
,DeptID VARCHAR(10)
,TotalSales float
,SplitSales FLOAT
,TotalCosts FLOAT
,SplitCosts float
)

-- Have sales for 2 depts for J1.
-- Revenue is split between Cust1 and Cust 2 40/60%
INSERT INTO #Sales
SELECT 1,'J1','D1',1000, 0.4
UNION
SELECT 1,'J1','D2',2000, 0.4
UNION
SELECT 2,'J1','D1',1000, 0.6
UNION
SELECT 2,'J1','D2',2000, 0.6

-- Sales
SELECT
[CustNo]
,[JobNo]
,[DeptID]
,[TotalSales]
,[Split]
,TotalSales * Split AS SplitSales
FROM #Sales



-- Now I have costs, but costs only belong to 1 customer that may not even be a customer that the revenue was recorded for, but we need link costs and sales, according to revenue split
-- So if costs are $100 and split 60/40% Cust 1 get $60 and Cust 2 gets $40
-- Further the departments that revenue is recorded against may not be same as costs. For example record costs for Dept 1 and 2, but sales assinged to Dept's 1 and 3
INSERT INTO #Costs
(
JobNo
,DeptID
,Costs
)
SELECT 'J1','D1',500
UNION
SELECT 'J1','D3',1000

SELECT * FROM #Costs


-- Expected Results
-- All departments that have costs or sales should be listed with respected values
-- I cant for the life of me figure out how to get customer in every row and all depts and respective costs and sales
INSERT INTO [#Sales_vs_Costs]
(
[CustNo]
,[JobNo]
,[DeptID]
,[TotalSales]
,[SplitSales]
,[TotalCosts]
,[SplitCosts]
)

SELECT 1,'J1','D1',1000, 0.4, 500, 200
UNION
SELECT 1,'J1','D2',2000, 0.4,0,0
UNION
SELECT 1,'J1','D3',0, 0.4,1000,400
UNION
SELECT 2,'J1','D1',1000, 0.6,500,300
UNION
SELECT 2,'J1','D2',2000, 0.6,0,0
UNION
SELECT 2,'J1','D3',0, 0.6,1000,600

SELECT * FROM #Sales_vs_Costs AS svc


IF OBJECT_ID('tempdb..#Sales') IS NOT NULL
DROP TABLE #Sales

IF OBJECT_ID('tempdb..#Costs') IS NOT NULL
DROP TABLE #Costs


IF OBJECT_ID('tempdb..#Sales_vs_Costs') IS NOT NULL
DROP TABLE #Sales_vs_Costs


You just need to use the SQL IFCode Shortcut (tag) that appears to the left of the posting window.

I'll take a look now to see if I can make heads or tails.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1512046
Posted Wednesday, November 06, 2013 6:23 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 6:03 PM
Points: 3,590, Visits: 5,098
There may very well be an easier way to do this, but this is what I came up with:

WITH AllDepts AS
(
SELECT DeptID, JobNo
FROM #Sales
UNION
SELECT DeptID, JobNo
FROM #Costs
)
SELECT b.CustNo, a.JobNo, a.DeptID
,TotalSales=ISNULL(c.TotalSales, 0), SplitSales=ISNULL(c.Split, e.Split)
,TotalCosts=ISNULL(d.Costs, 0), SplitCosts=ISNULL(c.Split, e.Split)*ISNULL(d.Costs, 0)
FROM AllDepts a
CROSS APPLY
(
SELECT DISTINCT CustNo
FROM #Sales b
WHERE a.JobNo = b.JobNo -- AND a.DeptID = b.DeptID
) b
LEFT JOIN #Sales c ON b.CustNo = c.CustNo AND a.JobNo = c.JobNo AND a.DeptID = c.DeptID
LEFT JOIN #Costs d ON a.JobNo = d.JobNo AND a.DeptID = d.DeptID
CROSS APPLY
(
SELECT TOP 1 Split
FROM #Sales e
WHERE e.CustNo = b.CustNo AND e.JobNo = a.JobNo
) e
ORDER BY b.CustNo, a.JobNo, a.DeptID;


I have two concerns about it though:
1.
-- See where I have this commented code?
-- AND a.DeptID = b.DeptID

-- My concern is that without this (additional limiter) I'm afraid your record set
-- will explode with more jobs/depts but I only get all the rows you need
-- with it commented out.


2. The way you're deciding to allocate your costs to your customers seems a bit odd. I've figured out how to get the 40/60 split that your expected results implies, but I'm not sure this is going to work well in cases where there's more customers, departments or jobs.

More test data (like for multiple jobs and different combinations of depts and sales/costs might help to further flush out your requirements. Don't forget, when you expand your test data, you need to add corresponding information to your expected results.

But perhaps this will get you on the road to a solution.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1512049
Posted Wednesday, November 06, 2013 6:28 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 6:03 PM
Points: 3,590, Visits: 5,098
Oh, and by the way. This is the kind of allocation problem that bean counters are going to jump on you about if you don't get the rounding just right.

That would be a last step, and there is a way to do it. You might want to look at this article later for that information:
Financial Rounding of Allocations



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1512050
Posted Thursday, November 07, 2013 7:49 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Today @ 9:21 AM
Points: 33, Visits: 134
dwain.c (11/6/2013)

You just need to use the SQL IFCode Shortcut (tag) that appears to the left of the posting window.



Thanks dwain! I did put it in the tags but still got the error
Post #1512277
Posted Thursday, November 07, 2013 7:52 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Today @ 9:21 AM
Points: 33, Visits: 134
dwain.c (11/6/2013)
Oh, and by the way. This is the kind of allocation problem that bean counters are going to jump on you about if you don't get the rounding just right.



Thanks for heads up. Just threw in floats and kept it as simple as possible for the example
Post #1512281
Posted Thursday, November 07, 2013 7:59 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Today @ 9:21 AM
Points: 33, Visits: 134
dwain.c (11/6/2013)
There may very well be an easier way to do this, but this is what I came up with:


Thanks!

I had played around with a derived table and a cross join, but cross apply is probably better. It's something I rarely use
Post #1512286
Posted Thursday, November 07, 2013 5:35 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 6:03 PM
Points: 3,590, Visits: 5,098
mark 4643 (11/7/2013)
dwain.c (11/6/2013)
There may very well be an easier way to do this, but this is what I came up with:


Thanks!

I had played around with a derived table and a cross join, but cross apply is probably better. It's something I rarely use


I also tried a CROSS JOIN but thought the CROSS APPLY may help to limit the row set more efficiently. CA has a tendency to parallelize many queries, improving their elapsed time (often) pretty significantly.

I'd like another shot at this one. I wasn't particularly happy with the solution I gave you. But more test data would be helpful. I'll try to come back to it when I have a bit of time on my hands.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1512500
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse