[prev in list] [next in list] [prev in thread] [next in thread] 

List:       postgresql-admin
Subject:    Re: PostgreSQL Tuning and running a query on a big data
From:       Thomas Kellerer <shammat () gmx ! net>
Date:       2020-11-17 21:03:57
Message-ID: ba0179a3-966e-15bf-a621-684a6e89555e () gmx ! net
[Download RAW message or body]

Sachin Kumar schrieb am 17.11.2020 um 18:34:
> 3.     while running the query on 1 million cards it is taking too much time, say \
>                 150 min. is there any way I can reduce it.
> *Query I am using*
> UPDATE hk_card_master_test m
> SET "ACCOUNT_NUMBER" = v."v_account_number", "ISSUANCE_NUMBER" = \
> v."v_issuance_number","cron"=1 FROM (
> SELECT h."id",h."CARD_SEQUENCE_NUMBER" ,h."ACCOUNT_NUMBER" \
> ,h."ISSUANCE_NUMBER",c."ACCOUNT_NUMBER" v_account_number,c."ISSUANCE_NUMBER" \
> v_issuance_number FROM
> hk_card_master_test h
> JOIN
> vdaccount_card_bank c
> ON SUBSTR(c."ACCOUNT_NUMBER", 1, 10) = h."CARD_SEQUENCE_NUMBER"
> ORDER BY h."id" ASC LIMIT 1000
> ) AS v
> WHERE m."CARD_SEQUENCE_NUMBER" = v."CARD_SEQUENCE_NUMBER";

The target table of an UPDATE shouldn't be repeated in the FROM clause in Postgres.

Not sure why you have the LIMIT in the sub-select, but if that is only for
testing purposes, then I think the following should do what you want, but much \
faster:

     UPDATE hk_card_master_test m
       SET "ACCOUNT_NUMBER" = v."v_account_number",
           "ISSUANCE_NUMBER" = v."v_issuance_number",
           "cron"=1
     FROM vdaccount_card_bank v
     WHERE SUBSTR(v."ACCOUNT_NUMBER", 1, 10) = m."CARD_SEQUENCE_NUMBER"

You probably want those indexes:

    create index on vdaccount_card_bank ( (SUBSTR("ACCOUNT_NUMBER", 1, 10) );
    create index on hk_card_master_test ("CARD_SEQUENCE_NUMBER");


Unrelated to your question, but using quoted/uppercase identifiers is generally \
discouraged in Postgres:

https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_upper_case_table_or_column_names


you probably will have a lot less trouble if you get rid of those.

Thomas


[prev in list] [next in list] [prev in thread] [next in thread] 

Configure | About | News | Add a list | Sponsored by KoreLogic