Thread: is there a distinct function for comma lists ?

is there a distinct function for comma lists ?

From
Andreas
Date:
  Hi,
is there a distinct function for comma separated lists ?

I sometimes need to update tables where I got a set of IDs, like:

update mytable   set someattribute = 42
where mytable.id in
(  1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )

So there are double entries in the list but in this case its just 
overhead but no problem.

But for calculated values this would not allways be desirable.

update mytable   set someattribute = someattribute + 1
where mytable.id in
(  1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )

How could I get a distinct list? Those lists can have 2000-3000 IDs 
sometimes.

One solution was as follows but perhaps there is something more elegant?

update mytable   set someattribute = someattribute + 1
where mytable.id in ( select distinct id from mytable where id in (  1, 2, 3, 5, 7, 11, 3, 
6, 13, 13, 3, 11 ... ) )


And as bonus ... is there a way to find IDs that are in the list but not 
in the table without creating a temporary table and use a join?


Re: is there a distinct function for comma lists ?

From
Andreas Gaab
Date:
Hi,

For the problem 1 perhaps something like

select distinct unnest(ARRAY[ 1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ])

Regards,
Andreas

-----Ursprüngliche Nachricht-----
Von: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] Im Auftrag von Andreas
Gesendet: Dienstag, 7. September 2010 13:52
An: pgsql-sql@postgresql.org
Betreff: [SQL] is there a distinct function for comma lists ?
 Hi,
is there a distinct function for comma separated lists ?

I sometimes need to update tables where I got a set of IDs, like:

update mytable   set someattribute = 42
where mytable.id in
(  1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )

So there are double entries in the list but in this case its just 
overhead but no problem.

But for calculated values this would not allways be desirable.

update mytable   set someattribute = someattribute + 1
where mytable.id in
(  1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )

How could I get a distinct list? Those lists can have 2000-3000 IDs 
sometimes.

One solution was as follows but perhaps there is something more elegant?

update mytable   set someattribute = someattribute + 1
where mytable.id in ( select distinct id from mytable where id in (  1, 2, 3, 5, 7, 11, 3, 
6, 13, 13, 3, 11 ... ) )


And as bonus ... is there a way to find IDs that are in the list but not 
in the table without creating a temporary table and use a join?

-- 
Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-sql

Re: is there a distinct function for comma lists ?

From
Lew
Date:
On 09/07/2010 07:52 AM, Andreas wrote:
> Hi,
> is there a distinct function for comma separated lists ?
>
> I sometimes need to update tables where I got a set of IDs, like:
>
> update mytable
> set someattribute = 42
> where mytable.id in
> ( 1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )
>
> So there are double entries in the list but in this case its just
> overhead but no problem.
>
> But for calculated values this would not allways be desirable.
>
> update mytable
> set someattribute = someattribute + 1
> where mytable.id in
> ( 1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )
>
> How could I get a distinct list? Those lists can have 2000-3000 IDs
> sometimes.
>
> One solution was as follows but perhaps there is something more elegant?
>
> update mytable
> set someattribute = someattribute + 1
> where mytable.id in
> ( select distinct id from mytable where id in ( 1, 2, 3, 5, 7, 11, 3, 6,
> 13, 13, 3, 11 ... ) )

I am not clear on what you're asking here.  From what you say, there's nothing 
to do.  The two forms of the SQL you show have the same result.

The fact that 11 or 13 or whatever appear in the IN list more than once 
doesn't affect the result of the query; 13 is in the IN list no matter how 
many times (> 0) that 13 appears in the IN list.  So a row from mytable with 
id=13 is selected regardless.  It's not like the row will be selected more 
than once.
From the manual:
'The result of IN is "true" if any equal subquery row is found.'
<http://www.postgresql.org/docs/8.4/interactive/functions-subquery.html>

It's still true of more than one equal subquery row is found.  It's not true 
multiple times, it's just true.

If mytable.id is not unique, then every row with that value will be selected, 
but adding DISTINCT to the IN list won't change that either.

-- 
Lew


Re: is there a distinct function for comma lists ?

From
msi77
Date:
Hi,

> And as bonus ... is there a way to find IDs that are in the list but not 
> in the table without creating a temporary table and use a join?

Does below satisfy you?

select * from (values (1), (2), (3), (5), (7), (11), (3), 
(6), (13), (13), (3), (11)) as X(a)
where a not in(select id from mytable)

Serge
http://www.sql-ex.com/


> Hi,
> For the problem 1 perhaps something like
> select distinct unnest(ARRAY[ 1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ])
> Regards,
> Andreas
> -----Ursprüngliche Nachricht-----
> Von: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] Im Auftrag von Andreas
> Gesendet: Dienstag, 7. September 2010 13:52
> An: pgsql-sql@postgresql.org
> Betreff: [SQL] is there a distinct function for comma lists ?
> Hi,
> is there a distinct function for comma separated lists ?
> I sometimes need to update tables where I got a set of IDs, like:
> update mytable
> set someattribute = 42
> where mytable.id in
> ( 1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )
> So there are double entries in the list but in this case its just 
> overhead but no problem.
> But for calculated values this would not allways be desirable.
> update mytable
> set someattribute = someattribute + 1
> where mytable.id in
> ( 1, 2, 3, 5, 7, 11, 3, 6, 13, 13, 3, 11 ... )
> How could I get a distinct list? Those lists can have 2000-3000 IDs 
> sometimes.
> One solution was as follows but perhaps there is something more elegant?
> update mytable
> set someattribute = someattribute + 1
> where mytable.id in
> ( select distinct id from mytable where id in ( 1, 2, 3, 5, 7, 11, 3, 
> 6, 13, 13, 3, 11 ... ) )
> And as bonus ... is there a way to find IDs that are in the list but not 
> in the table without creating a temporary table and use a join?
> 

Здесь спама нет http://mail.yandex.ru/nospam/sign