Обсуждение: query on query

Поиск
Список
Период
Сортировка

query on query

От
Jayadevan M
Дата:

Hi,

I have a table like this –

postgres=# \d m

       Table "public.m"

Column |  Type   | Modifiers

--------+---------+-----------

id     | integer |

marks  | integer |

 

postgres=# select * from m;

id | marks

----+-------

  1 |    27

  2 |    37

  3 |    17

  4 |    27

  5 |    18

(5 rows)

 

I wanted to get cumulative counts of students in different ranges – >90, > 80  , > 70  etc.

>10  5

>20  3

>30  1

>40 0

> 50 0

 

So each student may get counted many times, someone with 99 will be counted 10 times. Possible to do this with a fat query? The table will have many thousands of records.

 

 

Regards,

Jayadevan

 



DISCLAIMER: "The information in this e-mail and any attachment is intended only for the person to whom it is addressed and may contain confidential and/or privileged material. If you have received this e-mail in error, kindly contact the sender and destroy all copies of the original communication. IBS makes no warranty, express or implied, nor guarantees the accuracy, adequacy or completeness of the information contained in this email or any attachment and is not liable for any errors, defects, omissions, viruses or for resultant loss or damage, if any, direct or indirect."

Re: query on query

От
Luca Ferrari
Дата:
On Fri, Jul 5, 2013 at 5:09 AM, Jayadevan M
<jayadevan.maymala@ibsplc.com> wrote:

>
> So each student may get counted many times, someone with 99 will be counted
> 10 times. Possible to do this with a fat query? The table will have many
> thousands of records.
>


Not sure I got the point, but I guess this is a good candidate for a CTE:

WITH RECURSIVE t(n) AS (
    VALUES (10)
  UNION ALL
    SELECT n+10 FROM t WHERE n < 50
)
select count(*), t.n from m, t where mark > t.n group by t.n;

Luca


Re: query on query

От
Jayadevan M
Дата:
>
>>
>> So each student may get counted many times, someone with 99 will be
>> counted
>> 10 times. Possible to do this with a fat query? The table will have
>> many thousands of records.
>>
>
>
>Not sure I got the point, but I guess this is a good candidate for a CTE:
>
>WITH RECURSIVE t(n) AS (
>    VALUES (10)
>  UNION ALL
>    SELECT n+10 FROM t WHERE n < 50
>)
>select count(*), t.n from m, t where mark > t.n group by t.n;

I meant 'fast', not 'fat. Sorry for the typo.

You got it right. The query gets the data exactly as I wanted it. Thanks a lot.

Regards,
Jayadevan


DISCLAIMER: "The information in this e-mail and any attachment is intended only for the person to whom it is addressed
andmay contain confidential and/or privileged material. If you have received this e-mail in error, kindly contact the
senderand destroy all copies of the original communication. IBS makes no warranty, express or implied, nor guarantees
theaccuracy, adequacy or completeness of the information contained in this email or any attachment and is not liable
forany errors, defects, omissions, viruses or for resultant loss or damage, if any, direct or indirect." 


Re: query on query

От
hubert depesz lubaczewski
Дата:
On Fri, Jul 05, 2013 at 08:35:22AM +0200, Luca Ferrari wrote:
> On Fri, Jul 5, 2013 at 5:09 AM, Jayadevan M
> <jayadevan.maymala@ibsplc.com> wrote:
>
> >
> > So each student may get counted many times, someone with 99 will be counted
> > 10 times. Possible to do this with a fat query? The table will have many
> > thousands of records.
> >
>
>
> Not sure I got the point, but I guess this is a good candidate for a CTE:
>
> WITH RECURSIVE t(n) AS (
>     VALUES (10)
>   UNION ALL
>     SELECT n+10 FROM t WHERE n < 50
> )
> select count(*), t.n from m, t where mark > t.n group by t.n;

This might get expensive with many rows.

On the other hand, you can do it like this:

create table grades (username text, grade int4);
insert into grades select 'x', int(rand() * 50) from generate_series(1,100);

with a as
  (select (grade/10)*10 as mark,
                     count(*)
   from grades
   group by mark)
select mark,
       sum(count) over (
                        order by mark)
from a
order by mark;

Whis should be faster.

Best regards,

depesz