Re: Consecutive row count query - Mailing list pgsql-sql

From Andrew Hammond
Subject Re: Consecutive row count query
Date
Msg-id 423A144B.2010304@ca.afilias.info
Whole thread Raw
In response to Consecutive row count query  (Leon Stringer <leon.stringer@ntlworld.com>)
List pgsql-sql
You could hack it using a custom aggregate. NB: you'll want to reset the  categorizer_seq every now and then. And this
isn'tsafe for concurrent 
 
queries. You could make it safe for concurrent queries by using a 
complex type for STYPE, but I didn't bother. I also haven't debugged 
this, but I think it expresses the concept.


CREATE SEQUENCE categorizer_seq;

CREATE OR REPLACE FUNCTION categorizer_func (string, string) RETURNS 
bigint VOLATILE CALLED ON NULL INPUT AS '
SELECT CASE WHEN $1 = $2    THEN (SELECT last_value FROM categorizer_seq)    ELSE nextval(''categorizer_seq'')    END
AScategory
 
' LANGUAGE SQL;

CREATE AGGREGATE categorizer (    BASETYPE = text,    SFUNC = categorizer_func,    STYPE = text,    INITCOND = ''
);

SELECT col1, count(*)
FROM (    SELECT col1, cagetorizer(col1) AS category    FROM mytable    ORDER BY col_order
) tmp
GROUP BY (col1, category);

Leon Stringer wrote:
> Hi,
> 
> I wondered if anyone could answer the following question:
> 
> If I have a table such as the one below:
> 
> col1   col_order
> -----------
> Apple  1
> Apple  2
> Orange 3
> Banana 4
> Apple  5
> 
> Is there a way I can get the following results:
> 
> Apple  2
> Orange 1
> Banana 1
> Apple  1
> 
> i.e. Each row is printed ordered by col_order but consecutive
> appearances of the same col1 result in only a single line in the result
> with the number of consecutive appearances.
> 
> Obviously I could store the table as:
> 
> col1   col_order col_count
> --------------------------
> Apple  1         2
> Orange 2         1
> Banana 3         1
> Apple  4         1
> 
> But since (in my intended table) most rows will have col_count = 1, this
> seems like unnecessary normalization (and semantically "wrong").
> 
> Thanks in advance for any help,
> 
> Leon Stringer
> 
> 
> 
> ---------------------------(end of broadcast)---------------------------
> TIP 3: if posting/reading through Usenet, please send an appropriate
>       subscribe-nomail command to majordomo@postgresql.org so that your
>       message can get through to the mailing list cleanly


pgsql-sql by date:

Previous
From: Theo Galanakis
Date:
Subject: Process priority.
Next
From: Tom Lane
Date:
Subject: Re: Process priority.