SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 Distributor count
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

pvaru
Starting Member

India
5 Posts

Posted - 03/02/2013 :  00:01:25  Show Profile  Reply with Quote
distcode YTD (YTD Desc order)
D101 4000
D102 2000
D103 500

90% sales
ie., sum(YTD)*90% : 6500*90%=5850

I want to find out for 5850, count(distcode) contribution (ie.d how many distributor summing YTD comes to 5850 from YTD desc order ,we have to consider)

If i add 2 disttributor YTD then it comes near to 5850

result is count(Distcode)=2

is it possible write sql statement

bandi
Flowing Fount of Yak Knowledge

India
2218 Posts

Posted - 03/05/2013 :  00:56:25  Show Profile  Reply with Quote
DECLARE @tab TABLE(distcode VARCHAR(5), YTD INT)
INSERT INTO @tab VALUES('D101', 4000 ), ('D102', 2000), ('D103', 500)

SELECT COUNT(distcode)+1 DistCount
FROM (SELECT a.distcode, a.YTD, (SELECT SUM(b.YTD) FROM @tab b WHERE b.distcode <= a.distcode) RunningTotal, 0.9*SUM(YTD) OVER() Sales
FROM @tab a
)t
WHERE RunningTotal <= Sales

--
Chandu
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52317 Posts

Posted - 03/05/2013 :  01:03:19  Show Profile  Reply with Quote
quote:
Originally posted by bandi

DECLARE @tab TABLE(distcode VARCHAR(5), YTD INT)
INSERT INTO @tab VALUES('D101', 4000 ), ('D102', 2000), ('D103', 500)

SELECT COUNT(distcode)+1 DistCount
FROM (SELECT a.distcode, a.YTD, (SELECT SUM(b.YTD) FROM @tab b WHERE b.distcode <= a.distcode) RunningTotal, 0.9*SUM(YTD) OVER() Sales
FROM @tab a
)t
WHERE RunningTotal <= Sales

--
Chandu



will not work always

see this sample data

distcode YTD (YTD Desc order)
D101 4000 
D102 1850
D103 300
D104 350


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

bandi
Flowing Fount of Yak Knowledge

India
2218 Posts

Posted - 03/05/2013 :  01:22:08  Show Profile  Reply with Quote

DECLARE @tab TABLE(distcode VARCHAR(5), YTD INT)
INSERT INTO @tab 
--VALUES('D101', 4000 ), ('D102', 2000), ('D103', 500)
SELECT 'D103', 4000  UNION ALL
SELECT 'D102', 1850 UNION ALL
SELECT 'D101', 300 UNION ALL
SELECT 'D104', 350

SELECT a.distcode, a.YTD, (SELECT SUM(b.YTD) FROM @tab b WHERE b.YTD >= a.YTD) RunningTotal, 0.9*SUM(YTD) OVER() Sales
FROM  @tab a

;With CTE 
AS
(
	SELECT a.distcode, a.YTD, (SELECT SUM(b.YTD) FROM @tab b WHERE b.YTD >= a.YTD) RunningTotal, 0.9*SUM(YTD) OVER() Sales
		FROM  @tab a
)
SELECT COUNT(distcode)+1 DistCount
FROM CTE t
WHERE RunningTotal < Sales


--
Chandu
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52317 Posts

Posted - 03/05/2013 :  01:56:07  Show Profile  Reply with Quote
not again correct as its not considering the order of distcode


DECLARE @tab TABLE(distcode VARCHAR(5), YTD INT)
INSERT INTO @tab 
--VALUES('D101', 4000 ), ('D102', 2000), ('D103', 500)
SELECT 'D103', 4000  UNION ALL
SELECT 'D102', 1000 UNION ALL
SELECT 'D101', 900 UNION ALL
SELECT 'D106', 550 UNION ALL
SELECT 'D107', 200 UNION ALL
SELECT 'D105', 250 UNION ALL
SELECT 'D104',150


--Bandi solution
SELECT a.distcode, a.YTD, (SELECT SUM(b.YTD) FROM @tab b WHERE b.YTD >= a.YTD) RunningTotal, 0.9*SUM(YTD) OVER() Sales
FROM  @tab a

;With CTE 
AS
(
	SELECT a.distcode, a.YTD, (SELECT SUM(b.YTD) FROM @tab b WHERE b.YTD >= a.YTD) RunningTotal, 0.9*SUM(YTD) OVER() Sales
		FROM  @tab a
)
SELECT COUNT(distcode)+1 DistCount
FROM CTE t
WHERE RunningTotal < Sales


--Visakh Solution

;With CTE 
AS
(
SELECT a.distcode, a.YTD,  0.9*SUM(YTD) OVER()  AS [90PC],
ROW_NUMBER() OVER (ORDER BY distcode) AS RN
		FROM  @tab a 
)

SELECT RN AS DistCount
FROM CTE c1
OUTER APPLY (SELECT SUM(YTD) AS  RunningTotal FROM CTE  WHERE RN < c1.RN) c2
WHERE COALESCE(RunningTotal,0)<= [90PC]
AND COALESCE(RunningTotal,0) + YTD > [90PC]

output
-----------------------------------------
distcode	YTD	RunningTotal	Sales
D103	4000	4000	6345.0
D102	1000	5000	6345.0
D101	900	5900	6345.0
D106	550	6450	6345.0
D107	200	6900	6345.0
D105	250	6700	6345.0
D104	150	7050	6345.0

Bandi output
-------------------------------
4

Visakh Output
-------------------------------
6




------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.09 seconds. Powered By: Snitz Forums 2000