Re: Cumulative count (running total) window fn - Mailing list pgsql-general

From Magnus Hagander
Subject Re: Cumulative count (running total) window fn
Date
Msg-id z2w9837222c1004290201ta8359d32g9711d94b712be282@mail.gmail.com
Whole thread Raw
In response to Cumulative count (running total) window fn  (Oliver Kohll - Mailing Lists <oliver.lists@gtwm.co.uk>)
Responses Re: Cumulative count (running total) window fn  (Oliver Kohll - Mailing Lists <oliver.lists@gtwm.co.uk>)
List pgsql-general
On Thu, Apr 29, 2010 at 10:52, Oliver Kohll - Mailing Lists
<oliver.lists@gtwm.co.uk> wrote:
> Hello,
>
> Many thanks to andreas.kretschmer for this helpful reply about how to set up a window function to perform a running
total:
> http://archives.postgresql.org/pgsql-general/2010-03/msg01122.php
>
> It works perfectly with the simple test data but I've just got back to work, tried implementing it on my live data
andthe results are slightly different. My query is almost exactly the same - I've simplified by grouping by year only
ratherthan year and month: 
>
> select extract(year from signup_date),
>  count(email_address),
>  sum(count(email_address)) over (rows unbounded preceding)
> from email_list group by 1 order by 1;
>
>  date_part | count | sum
> -----------+-------+------
>      2007 |   501 | 1374
>      2008 |   491 |  491
>      2009 |   382 |  873
>      2010 |    66 | 1440
> (4 rows)
>
> What I'm looking for is
>  date_part | count | sum
> -----------+-------+------
>      2007 |   501 | 501
>      2008 |   491 |  992
>      2009 |   382 |  1374
>      2010 |    66 | 1440
>
> It seems to be adding up the counts but not in the right order.
>
> I've also tried an explicit ORDER BY inside the partition with no difference:
>
> select extract(year from signup_date),
>  count(email_address),
>  sum(count(email_address)) over (partition by 1 order by 1 asc rows unbounded preceding)
> from email_list group by 1 order by 1;
>
> Does anyone have any other ideas?

Aren't you looking for something along the line of:

SELECT year, sum(c) over (order by year)
FROM (
  SELECT extract(year from signup_date) AS year, count(email_address) AS c
  FROM email_list
  GROUP BY extract(year from signup_date)
)

(adjust for typos, I didn't test it)

--
 Magnus Hagander
 Me: http://www.hagander.net/
 Work: http://www.redpill-linpro.com/

pgsql-general by date:

Previous
From: Oliver Kohll - Mailing Lists
Date:
Subject: Cumulative count (running total) window fn
Next
From: Cédric Villemain
Date:
Subject: Re: Storing many big files in database- should I do it?