Re: Top -N Query performance issue and high CPU usage

From: "Peter J(dot) Holzer" <hjp-pgsql(at)hjp(dot)at>
To: pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Top -N Query performance issue and high CPU usage
Date: 2026-02-03 21:02:19
Message-ID: jasqhe5gccxmdmtog2qp64qylt64w6ownnqeppjh76vprks44j@cgdvwok4hdwz
Views: Whole Thread | Raw Message | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 2026-02-04 00:20:20 +0530, yudhi s wrote:
>
>
> On Tue, 3 Feb, 2026, 9:37 pm Adrian Klaver, <adrian(dot)klaver(at)aklaver(dot)com> wrote:
>
> On 2/3/26 07:59, Ron Johnson wrote:
>
> >
> >
> > There is no VARCHAR or CHAR; there is only TEXT.  Thus, this is 100%
> > expected and normal.
>
> What Ron is saying is that there are varchar and char types, but they
> boil down to text per:
>
> https://www.postgresql.org/docs/current/datatype-character.html
>
> "text is PostgreSQL's native string data type, in that most built-in
> functions operating on strings are declared to take or return text not
> character varying. For many purposes, character varying acts as though
> it were a domain over text."
>
> As to performance see:
>
> "
> Tip
>
> There is no performance difference among these three types, apart from
> increased storage space when using the blank-padded type, and a few
> extra CPU cycles to check the length when storing into a
> length-constrained column. While character(n) has performance advantages
> in some other database systems, there is no such advantage in
> PostgreSQL; in fact character(n) is usually the slowest of the three
> because of its additional storage costs. In most situations text or
> character varying should be used instead.
> "
>
>
> Thank you. I was looking into those casting(::text) in the explain plan output
> in similar way (as it was happening for int8 to numeric join scenario) and was
> thinking, may be it's spending some cpu cycles on doing these ::text casting
> behind the scenes for that column and if there is someway(data type change) to
> stop those. But from your explanation, it looks like those representation in
> the query plan is normal and have no performance overhead as such. Thanks
> again. 
>
> In regards to the below, "nested loop" having response time of 100ms. I
> understand, here the casting function us now removed after changing the data
> type of columns to match in both side of the join.
>
> So, is this expected to do a nested loop on 500k rows to take 100ms?
>
> ->  Nested Loop  (cost=262.77..1342550.91 rows=579149 width=20) (actual time=
> 6.406..107.946 rows=1049 loops=1)
>               Join Filter: (df.ent_id = m.ent_id)
>               Rows Removed by Join Filter: 514648
>               Buffers: shared hit=1972
>

Take a closer look at what that nested loop does:

-> Nested Loop (cost=266.53..1548099.38 rows=411215 width=20) (actual time=6.009..147.695 rows=1049 loops=1)
Join Filter: ((df.ent_id)::numeric = m.ent_id)
Rows Removed by Join Filter: 513436
Buffers: shared hit=1939
-> Index Scan Backward using txn_tbl_due_dt_idx on txn_tbl df (cost=0.43..115471.09 rows=1417983 width=20) (actual time=0.047..20.155 rows=43626 loops=1)
Filter: ((txn_tbl_type_nm)::text = ANY ('{.......}'::text[]))
Rows Removed by Filter: 17
Buffers: shared hit=1816
-> Materialize (cost=266.10..328.09 rows=58 width=16) (actual time=0.000..0.001 rows=12 loops=43626)
[lots of stuff]

It scans backwards through txn_tbl_due_dt_idx which returns 43626 rows
and takes 20 milliseconds.

For each of these rows it performs the "Materialize" node, which in turn
does lots of stuff, but whatever it is, it's fast and probably not worth
optimizing. The problem is that it's done 43626 times, which takes
another 120ms.

So the most promising way to proceed it to try to reduce those 43626
rows. Since the query is already scanning txn_tbl_due_dt_idx from newest
to oldest, is there a cutoff date where it is safe to ignore everything
older? If you can get it to scan only 2000 rows that would be 20 times
faster ...

(I'm a bit confused by your naming. I'm guessing that the "Index Scan
Backward using txn_tbl_due_dt_idx" is there because of the "order by
df.tran_date desc", but the name of the index and the column don't
match.)

hjp

--
_ | Peter J. Holzer | Story must make more sense than reality.
|_|_) | |
| | | hjp(at)hjp(dot)at | -- Charles Stross, "Creative writing
__/ | http://www.hjp.at/ | challenge!"

In response to

Browse pgsql-general by date

  From Date Subject
Previous Message Ron Johnson 2026-02-03 20:51:44 Re: Top -N Query performance issue and high CPU usage