Re: how to generate a list of distinct scalar values from a column which type is array

From: David Fetter <david(at)fetter(dot)org>
To: Sergio Andreozzi <sergio(dot)andreozzi(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: how to generate a list of distinct scalar values from a column which type is array
Date: 2007-02-22 16:56:48
Message-ID: 20070222165648.GE10321@fetter.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general pgsql-sql

On Thu, Feb 22, 2007 at 12:38:50PM +0100, Sergio Andreozzi wrote:
> Dear all,
>
> given a column which type is for instance varchar(20)[],

This is almost never a good design. If you must have an interface
like that, make it VIEW over an aggregate, which you can make
writeable.

> is it possible via SQL to generate the list of distinct scalar
> values?

Yes, but you should fix your design :)

CREATE TABLE foo (ft TEXT[]);

COPY foo(ft) FROM stdin;
{aaa,bb,c}
{dddd,eeee}
{aaa,eeee}
\.

SELECT DISTINCT ft[i]
FROM (
SELECT ft,
generate_series(
array_lower(ft,1),
array_upper(ft,1)
) AS i
FROM foo
) AS bar;

So, yes, you can do it, and no, you shouldn't.

Cheers,
D
--
David Fetter <david(at)fetter(dot)org> http://fetter.org/
phone: +1 415 235 3778 AIM: dfetter666
Skype: davidfetter

Remember to vote!

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Joris Dobbelsteen 2007-02-22 17:00:14 Re: Guarenteeing ordering constraints
Previous Message Tino Wildenhain 2007-02-22 16:56:43 Re: php professional

Browse pgsql-sql by date

  From Date Subject
Next Message Phillip Smith 2007-02-22 22:31:16 Re: DISTINCT ON not working... RESOLVED
Previous Message Tom Lane 2007-02-22 15:43:33 Re: pg_dump fails (timestamp out of range)