Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to return a certain percentage of rows (NOT TOP PERCENT QUESTION)


How to return a certain percentage of rows (NOT TOP PERCENT QUESTION)

Author
Message
David-155102
David-155102
SSC Veteran
SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)

Group: General Forum Members
Points: 293 Visits: 459
I want to return all values that represent x% of the total values within a table. Here's some test data:

create table #temp (customer varchar(15),number int)

insert into #temp select'A',10
insert into #temp select'B',20
insert into #temp select'C',17
insert into #temp select'D',18
insert into #temp select'E',30
insert into #temp select'F',40
insert into #temp select'G',10
insert into #temp select'H',20
insert into #temp select'I',17
insert into #temp select'J',18
insert into #temp select'K',30
insert into #temp select'L',40

select top 60 percent * from #temp
order by number desc

drop table #temp



When this is executed 60% of the total lines are returned but what I want is for it to return those rows whose 'number' values represent 60% of the total when added. So using my test data, 60% of the total would be represented by customers F, L, K and E because the sum of all the rows is 233 and the sum of F, L, K and E is 140 = 60%

Thanks
David
mazzz
mazzz
Old Hand
Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)Old Hand (373 reputation)

Group: General Forum Members
Points: 373 Visits: 2661
I'm a little confused - how would you differentiate between sum(F, L, K) and sum (A, B, E, F, L) which also adds up to 140?

------------------------------------------------------------------------
Bite-sized fiction (with added teeth)
DCPeterson
DCPeterson
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1049 Visits: 432
This is a weird one...

would something like this do the trick?

declare @Total decimal(18,2)
select @Total = sum(number)
from #temp

create table #temp2
(
customer varchar(15),
number int,
Ranking int
)

insert #temp2
select customer,
Number,
ranking = row_number() over(order by number desc)
from #temp

select customer,
number,
Running,
pct = round((cast(Running as decimal(10,2))/ cast(@Total as decimal(10,2)))*100, 0)
from
(
select customer,
number,
Ranking = ntile(12) over(order by number desc),
Running = (select sum(number) from #temp2 t1
where t1.Ranking <= t.Ranking)
from #temp2 t
)sub
where round((cast(Running as decimal(10,2))/ cast(@Total as decimal(10,2)))*100, 0) <= 60

drop table #temp2



This mess first orders the customers by Number Desc. Then calculates the running total and percentage of the running total against the total total, and returns those rows that add up to close to 60% without going over ("you're the next contestant on the Price is Right"...)

This is based on an inference that you want to return the top 60% of customers by number.

This works fine on a small set, but doubt it would be pretty on a large set of data...lots of table scans, sorts and temp table weirdness...

/*****************

If most people are not willing to see the difficulty, this is mainly because, consciously or unconsciously, they assume that it will be they who will settle these questions for the others, and because they are convinced of their own capacity to do this. -Friedrich August von Hayek



*****************/
Lamprey13
Lamprey13
Old Hand
Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)

Group: General Forum Members
Points: 304 Visits: 1657
I wasn't sure if you were looking for all combinations of Customers that meet that percentage or just starting with the min number or.???

At anyrate, I just used a simple running total solution to get some results. Hopefully, it'll help:
DECLARE @Temp table (customer varchar(15),number int)
insert into @Temp select'A',10
insert into @Temp select'B',20
insert into @Temp select'C',17
insert into @Temp select'D',18
insert into @Temp select'E',30
insert into @Temp select'F',40
insert into @Temp select'G',10
insert into @Temp select'H',20
insert into @Temp select'I',17
insert into @Temp select'J',18
insert into @Temp select'K',30
insert into @Temp select'L',40

DECLARE @Sum INT

SELECT @Sum = SUM(number)
FROM @Temp

DECLARE @Percent FLOAT
SET @Percent = @Sum * .6

SELECT
customer, Number, RunningTotal
FROM
(
SELECT
customer,
number,
(
SELECT SUM(Number)
FROM
(
SELECT *,ROW_NUMBER() OVER (ORDER BY Number, Customer) AS RowNum
FROM @Temp
) AS A
WHERE RowNum <= T.RowNum
) AS RunningTotal
FROM
(SELECT *,ROW_NUMBER() OVER (ORDER BY Number, Customer) AS RowNum FROM @Temp) T
) AS D
WHERE
RunningTotal <= @Percent -- Could add on some sort of varience if needed
ORDER BY
RunningTotal


David-155102
David-155102
SSC Veteran
SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)

Group: General Forum Members
Points: 293 Visits: 459
Thanks all, I'm out of the office so I'll test your solutions tomorrow.

Just to clarify, what I wanted was to first order the rows in the temp table by number (desc) and then count 60% from the top downwards. Once 60% has been reached, or as close to, then stop. I see that you've already guessed that though!
David-155102
David-155102
SSC Veteran
SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)SSC Veteran (293 reputation)

Group: General Forum Members
Points: 293 Visits: 459
Ok, I have had a chance to test out your solutions and am glad to say that after a bit of fiddling it is returning the data I need! We have a mixed environment here where some databases are not SQL 2005 compatible so the row numbering had to be done "the old way". Nevertheless, it is working now so thank you for your help.
azhao 88633
azhao 88633
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 71
Hi David:

Could you post your final solution? I have found out that two suggestions gave two different results and I would like to know the right one you have finally used.

Thanks,
Adrian
Sean Pearce
Sean Pearce
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1170 Visits: 3432
create table #temp (customer varchar(15),number int)

insert into #temp select'A',1
insert into #temp select'B',1
insert into #temp select'C',1
insert into #temp select'D',1

drop table #temp


What is the expected results of selecting 25% of the above?



The SQL Guy @ blogspot

@SeanPearceSQL

About Me
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