Re: How to improve the performance of my SQL query? - Mailing list pgsql-general

From Laurenz Albe
Subject Re: How to improve the performance of my SQL query?
Date
Msg-id 369ee851ef59bc84190f1631219b5a0c8f7907e9.camel@cybertec.at
Whole thread Raw
In response to How to improve the performance of my SQL query?  (gzh <gzhcoder@126.com>)
Responses Re: How to improve the performance of my SQL query?
List pgsql-general
On Thu, 2023-07-20 at 15:09 +0800, gzh wrote:
> I'm running into some performance issues with my SQL query.
> The following SQL query is taking a long time to execute.
>
> explain analyze
> select COUNT(ET_CD)
> from TBL_SHA
> WHERE TBL_SHA.MS_CD = '009'
> and TBL_SHA.ETRYS in
>    (select TBL_INF.RY_CD
>     from TBL_INF
>     WHERE TBL_INF.MS_CD = '009'
>    AND TBL_INF.RY_CD = '000001'
>    )
> ----- Execution Plan -----
> Limit  (cost=2738709.57..2738709.58 rows=1 width=8) (actual time=124168.769..124168.771 rows=1 loops=1)
>   ->  Aggregate  (cost=2738709.57..2738709.58 rows=1 width=8) (actual time=124168.767..124168.769 rows=1 loops=1)
>         ->  Nested Loop  (cost=0.29..2730702.63 rows=3202774 width=9) (actual time=97264.166..123920.769 rows=3200000
loops=1)
>               ->  Index Only Scan using TBL_INF_pkc on TBL_INF  (cost=0.29..8.31 rows=1 width=9) (actual
time=0.025..0.030rows=1 loops=1) 
>                     Index Cond: ((MS_CD = '009'::bpchar) AND (RY_CD = '000001'::bpchar))
>                     Heap Fetches: 1
>               ->  Seq Scan on TBL_SHA  (cost=0.00..2698666.58 rows=3202774 width=18) (actual
time=97264.138..123554.792rows=3200000 loops=1) 
>                     Filter: ((MS_CD = '009'::bpchar) AND (ETRYS = '000001'::bpchar))
>                     Rows Removed by Filter: 32000325
> Planning Time: 0.162 ms
> Execution Time: 124168.838 ms
> --------------------------------------------------------------------------------
>
> The index is defined as follows.
>
> CREATE INDEX index_search_01 ON mdb.TBL_SHA USING btree (MS_CD, ETRYS);

Actual rows = 3200000, rows removed by filter is ten times as much.
It should use an index.

> When I take the following sql statement, the index works fine and the query is fast.
>
> select COUNT(ET_CD)
> from TBL_SHA
> WHERE MS_CD = '009'
> AND ETRYS = '000001'
>
> The amount of data in the table is as follows.
> TBL_SHA    38700325
> TBL_INF    35546

This looks very much like it is a problem with the data types.
I see that you are using "character", which you shouldn't do.

What I cannot see is if the columns are defined as "character" or whether you bind
the parameters as "character".  Can you show us the table definition of "TBL_SHA"
and "TBL_INF"?

Yours,
Laurenz Albe



pgsql-general by date:

Previous
From: gzh
Date:
Subject: Re:Re: How to improve the performance of my SQL query?
Next
From: Anthony Apollis
Date:
Subject: Fwd: TSQL To Postgres - Unpivot/Union All