Re: How to select avg(select max(something) from ...) - Mailing list pgsql-general

From Adrian Klaver
Subject Re: How to select avg(select max(something) from ...)
Date
Msg-id 0878c968-a3d6-4803-a5b8-3ac1eb876309@aklaver.com
Whole thread Raw
In response to How to select avg(select max(something) from ...)  (dfgpostgres <dfgpostgres3@gmail.com>)
Responses Re: How to select avg(select max(something) from ...)
List pgsql-general
On 2/18/25 12:56, dfgpostgres wrote:
> Hi:
> psql 15.3
> 
> I have a table with sets of observations, each set sharing an id.
> I want to get the average of the max of each set.
> 
> id  |  val
> -----------
> 1     5.0
> 1     4.3
> 1     3.8
> 2     4.8
> 2     6.0
> 2     2.9
> 3     4.1
> 3     4.4
> 3     8.0
> 
> So I want the avg of the max of the set where id=1 (5.0), where id=2 
> (6.0), where id=3 (8.0) ~= 6.33...
> 
> I tried this...
> 
>                select
>                   avg(x.maxsz)
>                 from
>                   dvm.dvm_events d,
>                   (select cast(max(size_g) as int) as maxsz
>                     from dvm.wa_du_profile_data
>                     where dvm_id=d.dvm_id) x
>                 where
>                    d.project='foo' and
>                   <more conditions on d>
> 
> It doesn't like that reference to "d.dvm_id) in that subquery.


create table wa_du_profile_data (id integer, val float);

insert into wa_du_profile_data values (1, 5.0),
(1, 4.3),
(1, 3.8),
(2, 4.8),
(2, 6.0),
(2, 2.9),
(3, 4.1),
(3, 4.4),
(3, 8.0);


with max_val as (select max(val) from wa_du_profile_data group by id) 
select avg(max) from max_val;

6.333333333333333

-- 
Adrian Klaver
adrian.klaver@aklaver.com




pgsql-general by date:

Previous
From: David Rowley
Date:
Subject: Re: How to select avg(select max(something) from ...)
Next
From: Greg Sabino Mullane
Date:
Subject: Re: How to select avg(select max(something) from ...)