473,396 Members | 1,921 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,396 software developers and data experts.

update slow

Hello list,

I have 7.3.4 on RH 8, server hardware is a dual processor Intel Xeon 2.4
Ghz, 2G RAM, 27Gb HD available on postgres partition.

Table cost2est2003 with 99350 recs is described as:
code char(4) -- index
tcos numeric(12,4)
mes char(6) -- index

Table estprod with 355513 recs is described as:
pk_estprod -- index
epr_periodo char(6) -- Index
epr_venta numeric(12,4)
epr_costo numeric(12,4)
pro_code char(4)
This is the update command:
update estprod set epr_costo=(select tcos from cost2est2003 where
code=pro_code and mes=epr_periodo) where epr_periodo >='200301'

The above filters the records to affect only 99157 rows, the update
takes hours and don't get done (I did cancel it), I changed the filter
to "epr_periodo ='200301'" to update only 9756 rows but still has more
than 10 minutes working.

I wonder if there is something I'm doing wrong, any help will be
appreciated. BTW the server is not in production is not doing anything
else. Thanks in advance

--
Josué Maldonado.

---------------------------(end of broadcast)---------------------------
TIP 7: don't forget to increase your free space map settings

Nov 12 '05 #1
3 2882
On Tuesday 11 November 2003 19:46, Josué Maldonado wrote:
This is the update command:
update estprod set epr_costo=(select tcos from cost2est2003 where
code=pro_code and mes=epr_periodo) where epr_periodo >='200301'

The above filters the records to affect only 99157 rows, the update
takes hours and don't get done (I did cancel it), I changed the filter
to "epr_periodo ='200301'" to update only 9756 rows but still has more
than 10 minutes working.


Can you post EXPLAIN ANALYSE <query> on this shorter one - that will show what
PG is doing.

One thing that might be worth looking at is using PG's non-standard
UPDATE t1 SET c1=... FROM t2 ...

--
Richard Huxton
Archonet Ltd

---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?

http://www.postgresql.org/docs/faqs/FAQ.html

Nov 12 '05 #2
Hi Richard,

Here are both ways:

dbmund=# EXPLAIN ANALYSE update estprod set
dbmund-# epr_costo=(select tcos from cost2est2003 where code=pro_code
and mes=epr_periodo)
dbmund-# where epr_periodo='200311';

Seq Scan on estprod (cost=0.00..9177.91 rows=8080 width=163) (actual
time=440.99..627139.23 rows=6867 loops=1)
Filter: (epr_periodo = '200311'::bpchar)
SubPlan
-> Index Scan using c2emes on cost2est2003 (cost=0.00..1532.53
rows=2 width=16) (actual time=66.60..91.19 rows=1 loops=6867)
Index Cond: (mes = $1)
Filter: (code = $0)
Total runtime: 628557.56 msec
(7 rows)
dbmund=# explain analyze update estprod set
dbmund-# epr_costo= tcos
dbmund-# from cost2est2003
dbmund-# where code=pro_code and mes=epr_periodo
dbmund-# and epr_periodo='200311';

Merge Join (cost=10080.76..15930.98 rows=316 width=197) (actual
time=1191.89..4704.49 rows=6851 loops=1)
Merge Cond: ("outer".code = "inner".pro_code)
Join Filter: ("outer".mes = "inner".epr_periodo)
-> Index Scan using c2ecode on cost2est2003 (cost=0.00..4614.85
rows=99350 width=34) (actual time=0.16..2974.96 rows=99350 loops=1)
-> Sort (cost=10080.76..10100.96 rows=8080 width=163) (actual
time=1191.62..1235.32 rows=55216 loops=1)
Sort Key: estprod.pro_code
-> Seq Scan on estprod (cost=0.00..9177.91 rows=8080
width=163) (actual time=396.88..1126.28 rows=6867 loops=1)
Filter: (epr_periodo = '200311'::bpchar)
Total runtime: 5990.34 msec
(9 rows)

Wow, update from is pretty faster than the first update, can't
understand why.

Thanks
Richard Huxton wrote:
On Tuesday 11 November 2003 19:46, Josué Maldonado wrote:
This is the update command:
update estprod set epr_costo=(select tcos from cost2est2003 where
code=pro_code and mes=epr_periodo) where epr_periodo >='200301'

The above filters the records to affect only 99157 rows, the update
takes hours and don't get done (I did cancel it), I changed the filter
to "epr_periodo ='200301'" to update only 9756 rows but still has more
than 10 minutes working.

Can you post EXPLAIN ANALYSE <query> on this shorter one - that will show what
PG is doing.

One thing that might be worth looking at is using PG's non-standard
UPDATE t1 SET c1=... FROM t2 ...

--
Josué Maldonado.

---------------------------(end of broadcast)---------------------------
TIP 8: explain analyze is your friend

Nov 12 '05 #3
On Tuesday 11 November 2003 20:55, Josué Maldonado wrote:
Hi Richard,

Here are both ways:
Excellent - OK, here's a crash course in understanding the output of EXPLAIN
ANALYSE...
dbmund=# EXPLAIN ANALYSE update estprod set
dbmund-# epr_costo=(select tcos from cost2est2003 where code=pro_code
and mes=epr_periodo)
dbmund-# where epr_periodo='200311';

Seq Scan on estprod (cost=0.00..9177.91 rows=8080 width=163) (actual
time=440.99..627139.23 rows=6867 loops=1)
PG predicted 8080 rows to update (each of 163 bytes). It was actually 6867
rows with a total time of 627139.23 milliseconds (over 10 minutes).
Filter: (epr_periodo = '200311'::bpchar)
SubPlan
-> Index Scan using c2emes on cost2est2003 (cost=0.00..1532.53
rows=2 width=16) (actual time=66.60..91.19 rows=1 loops=6867)
Each sub-select took 91.19ms but looping through 6867 calls, that's 626
seconds - almost all of your query time.
Index Cond: (mes = $1)
Filter: (code = $0)
Total runtime: 628557.56 msec
The only thing that might speed it up is to build an index on (mes,code) for
cost2est2003, and even then I wouldn't expect wonders.
dbmund=# explain analyze update estprod set
dbmund-# epr_costo= tcos
dbmund-# from cost2est2003
dbmund-# where code=pro_code and mes=epr_periodo
dbmund-# and epr_periodo='200311';

Merge Join (cost=10080.76..15930.98 rows=316 width=197) (actual
time=1191.89..4704.49 rows=6851 loops=1)
Merge Cond: ("outer".code = "inner".pro_code)
Join Filter: ("outer".mes = "inner".epr_periodo)
-> Index Scan using c2ecode on cost2est2003 (cost=0.00..4614.85
rows=99350 width=34) (actual time=0.16..2974.96 rows=99350 loops=1)
-> Sort (cost=10080.76..10100.96 rows=8080 width=163) (actual
time=1191.62..1235.32 rows=55216 loops=1)
Sort Key: estprod.pro_code
-> Seq Scan on estprod (cost=0.00..9177.91 rows=8080
width=163) (actual time=396.88..1126.28 rows=6867 loops=1)
Filter: (epr_periodo = '200311'::bpchar)
Total runtime: 5990.34 msec
(9 rows)

Wow, update from is pretty faster than the first update, can't
understand why.


In the second example, PG gathers the target rows in estprod sorts them and
then joins using your index on c2ecode. This is clearly a better plan. Note
that since the rows from the previous test could still be in memory, you'd
expect an improvement anyway, but this plan just looks better.

PG obviously can't figure out that it can convert the first example into the
second, but I'm guessing there are good reasons for that. Although your
example is simple enough, there might be cases where it isn't safe to do so.
Presumably this is one reason why the non-standard UPDATE...FROM statement is
there.

Try the second form with your real query, VACUUM ANALYSE both tables and
perhaps try an index on (mes,code) and see what that does for you. If you get
any more performance issues, there is a mailing list specifically for them -
plenty of knowledgable types there.
--
Richard Huxton
Archonet Ltd

---------------------------(end of broadcast)---------------------------
TIP 6: Have you searched our list archives?

http://archives.postgresql.org

Nov 12 '05 #4

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

17
by: Felix | last post by:
Dear Sql Server experts: First off, I am no sql server expert :) A few months ago I put a database into a production environment. Recently, It was brought to my attention that a particular...
1
by: Gent | last post by:
am using FOR UPDATE triggers to audit a table that has 67 fields. My problem is that this slows down the system significantly. I have narrowed down the problem to the size (Lines of code) that need...
6
by: pg | last post by:
Is there any simple way to query the most recent time of "changes" made to a table? I'm accessing my database with ODBC to a remote site thru internet. I want to eliminate some DUPLICATE long...
10
by: Steve Jorgensen | last post by:
Hi all, Over the years, I have had to keep dealing with the same Access restriction - that you can't update a table in a statement that joins it to another non-updateable query or employs a...
2
by: info | last post by:
I can successfully open a recordset based upon an Excel sheet in Access, but I can't work out how to copy all the records to an Access table. Any pointers?
2
by: Chris | last post by:
I'm using a DataTable in my application. I am able to load rows into the DataTable quickly. What's puzzling me, however, is that when I update a set of cells in the DataTable, the update is really...
2
by: Kapti | last post by:
Hi! I save 10 rows per second to a Access DataBase. Data are copied to DataSet pro term, then I call Update fuction of DataAdapter to refresh database. code: DataRow newRow; newRow =...
29
by: Geoff Jones | last post by:
Hi All I hope you'll forgive me for posting this here (I've also posted to ado site but with no response so far) as I'm urgently after a solution. Can anybody help me? I'm updating a table on...
5
by: parwal.sandeep | last post by:
Hello grp! i'm using INNODB tables which are using frequently . if i fire a SELECT query which fetch major part of table it usually take 10-20 seconds to complete. in mean time if any UPDATE...
3
by: traceable1 | last post by:
I installed the SQL Server 2005 SP2 update 2 rollup on my 64-bit server and the performance has tanked! I installed rollup 3 on some of them, but that did not seem to help. I thought it...
0
by: Charles Arthur | last post by:
How do i turn on java script on a villaon, callus and itel keypad mobile phone
1
by: nemocccc | last post by:
hello, everyone, I want to develop a software for my android phone for daily needs, any suggestions?
1
by: Sonnysonu | last post by:
This is the data of csv file 1 2 3 1 2 3 1 2 3 1 2 3 2 3 2 3 3 the lengths should be different i have to store the data by column-wise with in the specific length. suppose the i have to...
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...
0
agi2029
by: agi2029 | last post by:
Let's talk about the concept of autonomous AI software engineers and no-code agents. These AIs are designed to manage the entire lifecycle of a software development project—planning, coding, testing,...
0
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.