Thanks for the replies, appreciated...
My current solution is:
select trip_code,
station_no,
timer_sec + interval '12 hour' as NZST,
timer_sec as utc,
hstore_to_json(string_agg(values_sec::text, ', ')::hstore) as values_sec
from (select '$TRIP' as trip_code,
$STATION as station_no,
date_trunc('second', timer) as timer_sec,
values_sec
from t_reading_hstore_sec
where timer >= '$ISO_S'::timestamp - interval '12 hour'
and timer <= '$ISO_F'::timestamp - interval '12 hour') as foo
group by timer_sec, trip_code, station_no;
Convert the hstore to text, aggregate the text with string_agg(), convert back to hstore (which seems to remove duplicate keys, OK for my purpose)
and group by timer truncated to whole seconds. I also provide UTC & local timezone times for each set of readings. It is run in a bash script which passes the trip & station values to the query, as well as the start/finish times as ISO format strings.
The output is going to a Sqlite3 (Spatialite) database, which does not have hstore, or all the hstore functionality that Postgres has, but does have a json datatype which is adequate for our purposes, hence the hstore_to_json in the query.
Thanks again,
Brent Wood
Principal Technician, Fisheries NIWA DDI: +64 (4) 3860529 From: David G. Johnston <david.g.johnston@xxxxxxxxx>
Sent: Monday, January 20, 2025 04:28 To: Brent Wood <Brent.Wood@xxxxxxxxxx> Cc: pgsql-general@xxxxxxxxxxxxxxxxxxxx <pgsql-general@xxxxxxxxxxxxxxxxxxxx> Subject: concatenating hstores in a group by? On Friday, January 17, 2025, Brent Wood <Brent.Wood@xxxxxxxxxx> wrote:
There are no hstore aggregate functions. You’ll want to convert them to,json first then use the json_objectagg aggregate function.
David J.
Note: This email is intended solely for the use of the addressee and may contain information that is confidential or subject to legal professional privilege. If you receive this email in error please immediately notify the sender and delete the email. |