Thread: Slow timestamp query after upgrading from Pg13 to Pg16
Hello
After upgrading a Db from Pg13 (Centos) to Pg16(Ubuntu) some queries on a simple, large table (200M rows) are very slowid integer not null
status char(4) not null
status_tstamp timestamp
<... other columns ...>
If I create indexes on
- status, status_tstamp
- status_tstamp when status_timestamp is not null
Queries for a set date range for a given status are good and perform similarly to Pg13
Queries for a set date range are VERY slow compared to Pg13. A few other queries on tables with indexes like
CREATE INDEX table_col ON table (col) WHERE col IS NOT NULL;
also appear to be slow.
Any ideas, observations or comments would be appreciated
Simon
-- Simon Windsor Eml: simon.windsor@cornfield.me.uk Mob: 0755 197 9733 “There is nothing in the world that some man cannot make a little worse and sell a little cheaper, and he who considers price only is that man's lawful prey.”
On Mon, 2025-04-07 at 15:48 +0100, Simon Windsor wrote: > After upgrading a Db from Pg13 (Centos) to Pg16(Ubuntu) some queries > on a simple, large table (200M rows) are very slow If you used "pg_upgrade", did you ANALYZE the database? If that is not the problem, we can't guess what your problem might be unless you provide EXPLAIN (ANALYZE, BUFFERS, SETTINGS) output for auch a slow query. Ideally, add the same information for the fast v13 case. Yours, Laurenz Albe
Hi We used pg_dump|pg_restore to migrate the data. The full explain plan is at https://explain.depesz.com/s/742M. The SQL explain (analyze, buffers) select count(*) from consignments where (req_status_tstamp >= '2025-03-28 00:00'::timestamp and req_status_tstamp <= '2025-03-28 01:00'::timestamp); takes 2-3s with the old Pg13 DB, and over a minute with Pg16 After spending many hours looking at DB settings and Statistic settings I am at a loss/ Simon On 07/04/2025 15:51, Laurenz Albe wrote: > On Mon, 2025-04-07 at 15:48 +0100, Simon Windsor wrote: >> After upgrading a Db from Pg13 (Centos) to Pg16(Ubuntu) some queries >> on a simple, large table (200M rows) are very slow > If you used "pg_upgrade", did you ANALYZE the database? > > If that is not the problem, we can't guess what your problem might be > unless you provide EXPLAIN (ANALYZE, BUFFERS, SETTINGS) output for auch a > slow query. Ideally, add the same information for the fast v13 case. > > Yours, > Laurenz Albe -- Simon Windsor Eml: simon.windsor@cornfield.me.uk Mob: 0755 197 9733 “There is nothing in the world that some man cannot make a little worse and sell a little cheaper, and he who considers priceonly is that man's lawful prey.”
On 4/7/25 12:25, Simon Windsor wrote: > Hi > > We used pg_dump|pg_restore to migrate the data. Did you do an ANALYZE on the Postgres 16 instance after the pg_restore? > > The full explain plan is at https://explain.depesz.com/s/742M. The SQL > > explain (analyze, buffers) select count(*) from consignments where > (req_status_tstamp >= '2025-03-28 00:00'::timestamp and > req_status_tstamp <= '2025-03-28 01:00'::timestamp); > > takes 2-3s with the old Pg13 DB, and over a minute with Pg16 Do you have an EXPLAIN ANALYZE for the Postgres 13 case? > > After spending many hours looking at DB settings and Statistic settings > I am at a loss/ > > Simon > -- Adrian Klaver adrian.klaver@aklaver.com
On Mon, 2025-04-07 at 20:25 +0100, Simon Windsor wrote: > We used pg_dump|pg_restore to migrate the data. > > The full explain plan is at https://explain.depesz.com/s/742M. The SQL > > explain (analyze, buffers) select count(*) from consignments where > (req_status_tstamp >= '2025-03-28 00:00'::timestamp and > req_status_tstamp <= '2025-03-28 01:00'::timestamp); > > takes 2-3s with the old Pg13 DB, and over a minute with Pg16 > > After spending many hours looking at DB settings and Statistic settings > I am at a loss/ Thanks. - Can you show the index definitions on that table? - If you "SET enable_seqscan = off;" in an interactive session, PostgreSQL should choose an index scan if possible. Can you show the EXPLAIN (ANALYZE, BUFFERS) output for that execution? Yours, Laurenz Albe