Re: Top 3 values for each group in PGSQL

From: Achilleas Mantzios <achill(at)matrix(dot)gatewaynet(dot)com>
To: pgsql-sql(at)lists(dot)postgresql(dot)org
Subject: Re: Top 3 values for each group in PGSQL
Date: 2019-03-01 13:17:48
Message-ID: bef5c3a6-7f3c-d8f2-259e-54735dee90f7@matrix.gatewaynet.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On 1/3/19 2:52 μ.μ., Thomas Kellerer wrote:
> Ila B. schrieb am 01.03.2019 um 11:51:
>> Hello,
>>
>> I’m working on a health database and I’m trying to extract the most popular prescription codes from a custom table I structured like this:
>>
>> Year - Code - Count(code)
>>
>> I want to extract the 3 codes with maximum count for each year. I know I should be using rank() but I don’t really understand how this works.
>> I am using pgAdmin4 version 3.5 with PostgreSQL 10.6 on Windows 10 Pro and no permission to update.
> Something along the lines:
>
> select code, year, "count"
> from (
> select code, year, "count",
> dense_rank() over (partition by code, year order by "count" desc) as rnk
> from the_table
> ) t
> where rnk <= 3;
Yup, that's the idea
select qryout.* FROM (select qry.*,dense_rank() OVER (ORDER BY count DESC) FROM (select id_1,year_built,count(*) from vessels WHERE year_built IS NOT NULL AND year_built<>'' group by id_1,year_built
ORDER BY COUNT(*) DESC) as qry ) qryout WHERE dense_rank<=3;
 id_1 | year_built | count | dense_rank
------+------------+-------+------------
   94 | 2009       |    11 |          1
   97 | 2010       |    10 |          2
   94 | 2011       |    10 |          2
   94 | 1975       |     9 |          3
   94 | 1976       |     9 |          3
(5 rows)

or

select qryout.* FROM (select qry.*,dense_rank() OVER (ORDER BY count DESC) FROM (select distinct id_1,year_built,count(*) OVER (partition by id_1,year_built) from vessels WHERE year_built IS NOT NULL
AND year_built<>'') as qry ) qryout WHERE dense_rank<=3;
 id_1 | year_built | count | dense_rank
------+------------+-------+------------
   94 | 2009       |    11 |          1
   97 | 2010       |    10 |          2
   94 | 2011       |    10 |          2
   94 | 1975       |     9 |          3
   94 | 1976       |     9 |          3
(5 rows)

>

--
Achilleas Mantzios
IT DEV Lead
IT DEPT
Dynacom Tankers Mgmt

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Andrew Gierth 2019-03-01 13:25:53 Re: Why does GROUP BY reduce number of rows?
Previous Message Rocky Ji 2019-03-01 12:55:44 Why does GROUP BY reduce number of rows?