Re: Improve "select count(*)" query - takes more than 30 mins for some large tables

From: Holger Jakobs <holger(at)jakobs(dot)com>
To: pgsql-admin(at)lists(dot)postgresql(dot)org
Subject: Re: Improve "select count(*)" query - takes more than 30 mins for some large tables
Date: 2022-07-11 08:33:41
Message-ID: 7ffca868-0728-6263-eac5-33cf56a46a54@jakobs.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Hi Raj,

Since PostgreSQL uses MVCC there is no current number of rows as an
absolute truth. Every COUNT(*) has to check the visibility of each row
for the current transaction. This makes it slow for large tables.

If you don't need the exact figure but just an estimation, you can get
this from the internal statistics tables. After an ANALYZE they are
close to the "real value".

This show the number of rows for all non-empty tables in all visible
schemas.

SELECT nspname AS schemaname,relname,reltuples::numeric
  FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
  WHERE
    nspname IN (SELECT unnest(current_schemas(false))) AND
    relkind='r' AND reltuples > 0
  ORDER BY reltuples DESC;

Regards,

Holger

Am 11.07.22 um 09:16 schrieb Raj kumar:
> Hi,
>
> How can I improve "select count(*)" for larger tables? I'm doing a db
> migration and need to validate the data count.
> "select count(*) " queries are taking more than 30 minutes for some
> tables which is more than the downtime we have.
> Will work_mem increase help? or how can i speed up this row count?
>
> Thanks,
> Raj

--
Holger Jakobs, Bergisch Gladbach, Tel. +49-178-9759012

In response to

Browse pgsql-admin by date

  From Date Subject
Next Message Raj kumar 2022-07-11 09:15:27 Re: Improve "select count(*)" query - takes more than 30 mins for some large tables
Previous Message Florents Tselai 2022-07-11 07:23:01 Re: Improve "select count(*)" query - takes more than 30 mins for some large tables