Обсуждение: how to generate a list of distinct scalar values from a column which type is array
how to generate a list of distinct scalar values from a column which type is array
От
"Sergio Andreozzi"
Дата:
Dear all, <br /><br />given a column which type is for instance varchar(20)[], is there any SQL command that let me generatethe list of distinct scalar values? <br /><br /><br />e.g.: <br /> col1<br />row 1: (aaa, bb, c) <br/>row 2: (dddd, eeee) <br />row 3: (aaa, eeee) <br /><br />the query should return: <br /><br />aaa <br />bb <br />c <br/>dddd <br />eeee <br /><br />if not, I guess the approach is to use stored procedure. Any code snippet/suggestion?<br/><br />Thanks, Sergio <br /><br />
Re: how to generate a list of distinct scalar values from a column which type is array
От
"A. Kretschmer"
Дата:
am Wed, dem 21.02.2007, um 19:21:09 +0100 mailte Sergio Andreozzi folgendes: > Dear all, > > given a column which type is for instance varchar(20)[], is there any SQL > command that let me generate the list of distinct scalar values? > > > e.g.: > col1 > row 1: (aaa, bb, c) > row 2: (dddd, eeee) > row 3: (aaa, eeee) > > the query should return: > > aaa > bb > c > dddd > eeee > > if not, I guess the approach is to use stored procedure. Any code snippet/ > suggestion? You can, for each row, split the array into the elements with a loop over array_lower, array_upper, returns this element. Yes, this is a setof-function. Than you can do a simple select distinct * from your_function. I hope this may help you. Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net
Re: how to generate a list of distinct scalar values from a column which type is array
От
"A. Kretschmer"
Дата:
am Wed, dem 21.02.2007, um 19:21:09 +0100 mailte Sergio Andreozzi folgendes:
> Dear all,
>
> given a column which type is for instance varchar(20)[], is there any SQL
> command that let me generate the list of distinct scalar values?
>
>
> e.g.:
> col1
> row 1: (aaa, bb, c)
> row 2: (dddd, eeee)
> row 3: (aaa, eeee)
>
> the query should return:
>
> aaa
> bb
> c
> dddd
> eeee
Okay, next solution:
test=*# select * from a; c
-------------{aaa,bb,c}{dddd,eeee}{aaa,eeee}
(3 rows)
test=*# select distinct c[s] from a, generate_series(1,3)s where c[s] is not null; c
------aaabbcddddeeee
(5 rows)
You need to know the greatest upper dimension of the array, in this case
3, for the generate_series - function.
Andreas
--
Andreas Kretschmer
Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net
Re: how to generate a list of distinct scalar values from a column which type is array
От
"A. Kretschmer"
Дата:
am Thu, dem 22.02.2007, um 14:25:36 +0100 mailte A. Kretschmer folgendes:
> test=*# select * from a;
> c
> -------------
> {aaa,bb,c}
> {dddd,eeee}
> {aaa,eeee}
> (3 rows)
>
>
> test=*# select distinct c[s] from a, generate_series(1,3)s where c[s] is not null;
> c
> ------
> aaa
> bb
> c
> dddd
> eeee
> (5 rows)
>
>
> You need to know the greatest upper dimension of the array, in this case
> 3, for the generate_series - function.
select distinct c[s] from a, generate_series(1,(select max(array_upper(c,1)) from a))s where c[s] is not null;
;-)
Andreas
--
Andreas Kretschmer
Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net