Re: concatenating hstores in a group by?

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: Brent Wood <pcreso(at)yahoo(dot)com>, Pgsql-general General <pgsql-general(at)postgresql(dot)org>
Subject: Re: concatenating hstores in a group by?
Date: 2025-01-22 00:29:13
Message-ID: 0acacffd-8139-48f8-8b19-6d8e5459f47a@aklaver.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 1/21/25 10:02, Brent Wood wrote:
> Yes, a Timescale hypertable with 500,000,000 rows of about 15 key/value
> pairs per record.
>
> I'm not sure why there is both a gin & gist index on the hstore, or the
> merits of each.

Questions:

1) What is the timezone setting for the database?

2) What is the system time zone where the BASH script is run?

3) Are you sure you don't need the duplicate keys?
The keys maybe duplicated, but are the values duplicated also?

Also could this be simplified to something like?:

create table hstore_tbl (id integer, tsz_fld timestamptz, hstore_fld
hstore);

insert into hstore_tbl values (1, now(), 'a=>1, b=>2'), (2, now() +
interval '0.5 sec', 'a=>3, b=>4'), (3, now() + interval '1 sec', 'a=>1,
b=>5'), (4, now()
+ interval '1.5 sec', 'a=>6, b=>7');

select id, date_trunc('second', tsz_fld) AS t_sec, h.key, h.value from
hstore_tbl, each(hstore_fld) as h ;
id | t_sec | key | value
----+------------------------+-----+-------
1 | 2025-01-21 14:00:27-08 | a | 1
1 | 2025-01-21 14:00:27-08 | b | 2
2 | 2025-01-21 14:00:28-08 | a | 3
2 | 2025-01-21 14:00:28-08 | b | 4
3 | 2025-01-21 14:00:28-08 | a | 1
3 | 2025-01-21 14:00:28-08 | b | 5
4 | 2025-01-21 14:00:29-08 | a | 6
4 | 2025-01-21 14:00:29-08 | b | 7

It would unnest the data.

>
>
> Thanks....
>
>  \d t_reading_hstore_sec
>                                          Table
> "public.t_reading_hstore_sec"
>    Column   |            Type             | Collation | Nullable
> |                      Default
> ------------+-----------------------------+-----------+----------+---------------------------------------------------
>  key        | bigint                      |           | not null |
> nextval('t_reading_hstore_sec_key_seq'::regclass)
>  timer      | timestamp without time zone |           | not null |
>  values_sec | hstore                      |           |          |
> Indexes:
>     "t_reading_hstore_sec_pkey" PRIMARY KEY, btree (key, timer)
>     "t_reading_hstore_sec_timer_idx" btree (timer)
>     "t_reading_hstore_sec_timer_key" UNIQUE CONSTRAINT, btree (timer)
>     "t_reading_hstore_sec_values_idx_gin" gin (values_sec)
>     "t_reading_hstore_sec_values_idx_gist" gist (values_sec)
>
>
>
>
> On Wednesday, January 22, 2025 at 06:34:38 AM GMT+13, Adrian Klaver
> <adrian(dot)klaver(at)aklaver(dot)com> wrote:
>
>
> On 1/19/25 12:09, Brent Wood wrote:
> > 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)
>
> To be clear values_sec in t_reading_hstore_sec is the hstore field?
>
> If so what is it's structure?
>
>
> > 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
>
> >
>
> --
> Adrian Klaver
> adrian(dot)klaver(at)aklaver(dot)com <mailto:adrian(dot)klaver(at)aklaver(dot)com>
>
>
>
>

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Runxi Yu 2025-01-22 07:00:28 Automatic deletion of orphaned rows
Previous Message Adrian Klaver 2025-01-21 21:40:57 Re: Records count mismatch with logical replication