Re: SELECT INTO large FKyed table is slow

From: Mladen Gogala <mladen(dot)gogala(at)vmsinfo(dot)com>
To: Mario Splivalo <mario(dot)splivalo(at)megafon(dot)hr>
Cc: "jd(at)commandprompt(dot)com" <jd(at)commandprompt(dot)com>, "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: SELECT INTO large FKyed table is slow
Date: 2010-12-01 16:34:04
Message-ID: 4CF678FC.9050003@vmsinfo.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

<!DOCTYPE html PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN">
<html>
<head>
<meta content="text/html;charset=UTF-8" http-equiv="Content-Type">
</head>
<body bgcolor="#ffffff" text="#000000">
Mario Splivalo wrote:
<blockquote cite="mid:4CF5FF0A(dot)9040605(at)megafon(dot)hr" type="cite"><br>
<pre wrap=""><!---->
Yes, as Mladen Gogala had advised. No noticable change in performance -
it's still slow :)
</pre>
</blockquote>
<br>
Declaring constraints as deferrable  doesn't do anything as such, you
have to actually set the constraints deferred to have an effect. You
have to do it within a transaction block. If done outside of the
transaction block, there is no effect:<br>
<br>
This is what happens when "set constraints" is issued outside the
transaction block:<br>
<br>
<blockquote>&lt; constraint test1_pk primary key(col1)
deferrable);            <br>
NOTICE:  CREATE TABLE / PRIMARY KEY will create implicit index
"test1_pk" for table "test1"<br>
CREATE TABLE<br>
Time: 41.218 ms<br>
scott=# set constraints all deferred;                           <br>
SET CONSTRAINTS<br>
Time: 0.228 ms<br>
scott=# begin;                                      <br>
BEGIN<br>
Time: 0.188 ms<br>
scott=#  insert into test1 values(1);               <br>
INSERT 0 1<br>
Time: 0.929 ms<br>
scott=#  insert into test1 values(1);   <br>
ERROR:  duplicate key value violates unique constraint "test1_pk"<br>
DETAIL:  Key (col1)=(1) already exists.<br>
scott=# end;<br>
ROLLBACK<br>
Time: 0.267 ms<br>
scott=# <br>
<br>
</blockquote>
It works like a charm when issued within the transaction block:<br>
<blockquote>scott=# begin;                          <br>
BEGIN<br>
Time: 0.202 ms<br>
scott=# set constraints all deferred;   <br>
SET CONSTRAINTS<br>
Time: 0.196 ms<br>
scott=#  insert into test1 values(1);   <br>
INSERT 0 1<br>
Time: 0.334 ms<br>
scott=#  insert into test1 values(1);   <br>
INSERT 0 1<br>
Time: 0.327 ms<br>
scott=# end;<br>
ERROR:  duplicate key value violates unique constraint "test1_pk"<br>
DETAIL:  Key (col1)=(1) already exists.<br>
scott=# <br>
</blockquote>
I was able to insert the same value twice, it only failed at the end of
the transaction.<br>
<blockquote cite="mid:4CF5FF0A(dot)9040605(at)megafon(dot)hr" type="cite">
<pre wrap="">
But, just for the sake of clarification - I tought that DEFERRABLE would
matter if I do a lot of INSERTs, inside a FOR loop or something like
that. Since I'm doing INSERT INTO ... SELECT, does it makes any difference?
</pre>
</blockquote>
You cannot tell which part takes a long time, select or insert, without
profiling. I certainly cannot do it over the internet.<br>
<br>
<pre class="moz-signature" cols="72">--

Mladen Gogala
Sr. Oracle DBA
1500 Broadway
New York, NY 10036
(212) 329-5251
<a class="moz-txt-link-freetext" href="http://www.vmsinfo.com">http://www.vmsinfo.com</a>
The Leader in Integrated Media Intelligence Solutions

</pre>
</body>
</html>

Attachment Content-Type Size
unknown_filename text/html 3.0 KB

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Mladen Gogala 2010-12-01 16:46:27 Clarification, please
Previous Message Bruce Momjian 2010-12-01 13:48:01 Re: BBU Cache vs. spindles