Thread: Select Distinct Order By Array_Position

Select Distinct Order By Array_Position

From
"Mark Williams"
Date:

Hi,

 

I am getting an error “SELECT DISTINCT, ORDER BY expressions must appear in select list”. I am ordering by documents.id and it appears in my select list. So I am guessing the problem lies with the array. Is there any way of achieving this? Query is below.

 

SELECT DISTINCT documents.id, page_no FROM texts LEFT JOIN documents on documents.id=texts.doc_id WHERE doc_id IN (26194, 2345, 189) AND  (text LIKE '%RIVER%') ORDER BY array_position(ARRAY[26194, 2345, 189]::INTEGER[], documents.id)

 

Thanks,

 

Mark

__

 

Re: Select Distinct Order By Array_Position

From
Rob Sargent
Date:


On Nov 26, 2018, at 12:12 PM, Mark Williams <markwillimas@gmail.com> wrote:

Hi,
 
I am getting an error “SELECT DISTINCT, ORDER BY expressions must appear in select list”. I am ordering by documents.id and it appears in my select list. So I am guessing the problem lies with the array. Is there any way of achieving this? Query is below.
 
SELECT DISTINCT documents.id, page_no FROM texts LEFT JOIN documents on documents.id=texts.doc_id WHERE doc_id IN (26194, 2345, 189) AND  (text LIKE '%RIVER%') ORDER BY array_position(ARRAY[26194, 2345, 189]::INTEGER[], documents.id)
 
Thanks,
 
Mark
__

Try put the array_position clause in the select and add documents.id to the order by?

Re: Select Distinct Order By Array_Position

From
"David G. Johnston"
Date:
On Mon, Nov 26, 2018 at 12:12 PM Mark Williams <markwillimas@gmail.com> wrote:
> I am ordering by documents.id and it appears in my select list.
[...]
> SELECT DISTINCT documents.id, page_no FROM texts LEFT JOIN documents on documents.id=texts.doc_id WHERE doc_id IN
(26194,2345, 189) AND  (text LIKE '%RIVER%') ORDER BY array_position(ARRAY[26194, 2345, 189]::INTEGER[], documents.id)
 

No, you are not ordering by documents.id, you are ordering by an
expression into which you are passing the documents.id value as one of
its components.

When you use ORDER BY and DISTINCT together you basically are short-handing:

SELECT sq.*
FROM (SELECT DISTINCT ...) AS sq
ORDER BY sq.?

If you want to order by something you have to include it exactly in
the select-list of the inner/distinct query.

In this example, though, you could just "ORDER BY documents.id DESC"...

David J.


RE: Select Distinct Order By Array_Position

From
"Mark Williams"
Date:

Wasn’t aware it was possible to put array_position statement in the actual select or is this a select within a select?

 

Also, I am selecting from an ordered (randomly) subset of data and I need to return the result set in the same order so do have to output the array as part of the order by?

 

__

 

From: Rob Sargent <robjsargent@gmail.com>
Sent: 26 November 2018 19:20
To: Mark Williams <markwillimas@gmail.com>
Cc: pgsql-sql@lists.postgresql.org
Subject: Re: Select Distinct Order By Array_Position

 

 



On Nov 26, 2018, at 12:12 PM, Mark Williams <markwillimas@gmail.com> wrote:

 

Hi,

 

I am getting an error “SELECT DISTINCT, ORDER BY expressions must appear in select list”. I am ordering by documents.id and it appears in my select list. So I am guessing the problem lies with the array. Is there any way of achieving this? Query is below.

 

SELECT DISTINCT documents.id, page_no FROM texts LEFT JOIN documents on documents.id=texts.doc_id WHERE doc_id IN (26194, 2345, 189) AND  (text LIKE '%RIVER%') ORDER BY array_position(ARRAY[26194, 2345, 189]::INTEGER[], documents.id)

 

Thanks,

 

Mark

__

 

Try put the array_position clause in the select and add documents.id to the order by?

 

RE: Select Distinct Order By Array_Position

From
"Mark Williams"
Date:
David, thanks. It was a bad example on my part. Could just as well have been: (26194, 189, 2345).

__

-----Original Message-----
From: David G. Johnston <david.g.johnston@gmail.com>
Sent: 26 November 2018 19:46
To: Mark Williams <markwillimas@gmail.com>
Cc: pgsql-sql <pgsql-sql@lists.postgresql.org>
Subject: Re: Select Distinct Order By Array_Position

On Mon, Nov 26, 2018 at 12:12 PM Mark Williams <markwillimas@gmail.com> wrote:
> I am ordering by documents.id and it appears in my select list.
[...]
> SELECT DISTINCT documents.id, page_no FROM texts LEFT JOIN documents
> on documents.id=texts.doc_id WHERE doc_id IN (26194, 2345, 189) AND
> (text LIKE '%RIVER%') ORDER BY array_position(ARRAY[26194, 2345,
> 189]::INTEGER[], documents.id)

No, you are not ordering by documents.id, you are ordering by an expression into which you are passing the documents.id
valueas one of its components. 

When you use ORDER BY and DISTINCT together you basically are short-handing:

SELECT sq.*
FROM (SELECT DISTINCT ...) AS sq
ORDER BY sq.?

If you want to order by something you have to include it exactly in the select-list of the inner/distinct query.

In this example, though, you could just "ORDER BY documents.id DESC"...

David J.



Re: Select Distinct Order By Array_Position

From
"David G. Johnston"
Date:
On Mon, Nov 26, 2018 at 12:58 PM Mark Williams <markwillimas@gmail.com> wrote:
>
> Wasn’t aware it was possible to put array_position statement in the actual select or is this a select within a
select?

Easy enough to try either way

> Also, I am selecting from an ordered (randomly) subset of data and I need to return the result set in the same order
sodo have to output the array as part of the order by? 

Not sure what the question is...

Anyway, maybe this will be helpful:

SELECT vals.*
FROM (VALUES (1::integer),(2),(3),(4),(5)) vals (v),
LATERAL unnest(ARRAY[3,1,5]::integer[]) with ordinality AS spec (s, o)
WHERE v = s
ORDER BY o

David J.


RE: Select Distinct Order By Array_Position

From
"Mark Williams"
Date:
Many thanks. I'll mess around with what you've sent and see if I can get it working.

__

-----Original Message-----
From: David G. Johnston <david.g.johnston@gmail.com>
Sent: 26 November 2018 20:07
To: Mark Williams <markwillimas@gmail.com>
Cc: Rob Sargent <robjsargent@gmail.com>; pgsql-sql <pgsql-sql@lists.postgresql.org>
Subject: Re: Select Distinct Order By Array_Position

On Mon, Nov 26, 2018 at 12:58 PM Mark Williams <markwillimas@gmail.com> wrote:
>
> Wasn’t aware it was possible to put array_position statement in the actual select or is this a select within a
select?

Easy enough to try either way

> Also, I am selecting from an ordered (randomly) subset of data and I need to return the result set in the same order
sodo have to output the array as part of the order by? 

Not sure what the question is...

Anyway, maybe this will be helpful:

SELECT vals.*
FROM (VALUES (1::integer),(2),(3),(4),(5)) vals (v), LATERAL unnest(ARRAY[3,1,5]::integer[]) with ordinality AS spec
(s,o) WHERE v = s ORDER BY o 

David J.