Thread: removing duplicates and using sort
FROM appl WHERE lastname ILIKE 'Williamson%' AND firstname ILIKE 'd%'
GROUP BY refid, id, lastname, firstname, appldate ORDER BY refid, appldate DESC;
Change the order by to order by lastname, firstname, refid, appldate
From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Nathan Mailg
Sent: Saturday, September 14, 2013 10:36 PM
To: pgsql-sql@postgresql.org
Subject: [SQL] removing duplicates and using sort
I'm using 8.4.17 and I have the following query working, but it's not quite what I need:
SELECT DISTINCT ON (refid) id, refid, lastname, firstname, appldate
FROM appl WHERE lastname ILIKE 'Williamson%' AND firstname ILIKE 'd%'
GROUP BY refid, id, lastname, firstname, appldate ORDER BY refid, appldate DESC;
I worked on this awhile and is as close as I could get. So this returns rows as you'd expect, except I need to somehow modify this query so it returns the rows ordered by lastname, then firstname.
I'm using distinct so I get rid of duplicates in the table where refid (an integer) is used as the common id that ties like records together. In other words, I'm using it to get only the most recent appldate (a date) for each group of refid's that match the lastname, firstname where clause.
I just need the rows returned from the query above to be sorted by lastname, then firstname.
Hope I explained this well enough. Please let me know if you need more info.
Thanks!
Note that you could always do something like: WITH original_query AS ( SELECT DISTINCT ... ) SELECT * FROM original_query ORDER BY lastname, firstname; OR SELECT * FROM ( SELECT DISTINCT .... ) sub_query ORDER BY lastname, firstname I am thinking you cannot alter the existing ORDER BY otherwise your use of "DISTINCT ON" begins to mal-function. I dislike DISTINCT ON generally but do not wish to ponder how you can avoid it, so I'd suggest just turning your query into a sub-query like I show above. David J. -- View this message in context: http://postgresql.1045698.n5.nabble.com/removing-duplicates-and-using-sort-tp5770931p5771096.html Sent from the PostgreSQL - sql mailing list archive at Nabble.com.
Yes, that's correct, modifying the original ORDER BY gives: ORDER BY lastname, firstname, refid, appldate DESC; ERROR: SELECT DISTINCT ON expressions must match initial ORDER BY expressions Using WITH works great: WITH distinct_query AS ( SELECT DISTINCT ON (refid) id, refid, lastname, firstname, appldate FROM appl WHERE lastnameILIKE 'Williamson%' AND firstname ILIKE 'd%' GROUP BY refid, id, lastname, firstname, appldate ORDERBY refid, appldate DESC ) SELECT * FROM distinct_query ORDER BY lastname, firstname; Thank you!