Thread: Query runs forever after upgrading to 9.3
Query SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive) OR toode in (SELECT toode FROM tempalgsemu) stops working after upgrading to 9.3 RTM in Windows from earlier version. Task Manager shows that postgres.exe process has constantly 13% CPU usage (this is 8 core computer) and private working set memory is 16 MB PgAdmin shows that this query is running . toode field type is char(20) and it is toode table primary key. tempkaive and tempalgsemu are temporary tables created eralier this transaction. They do not have indexes. toode is real table which has 509873 records . Probably tempkaive temp table size is bigger that toode table and templalgemu temp table size is smaller than in toode. How to fix this or find the reason ? How to rewrite the query so that it works ? analyze command was executed but problem persists. I tested it running Postgres 9.3 RTM in 32 bin Windows 7 and 64 bit Windows 2008 R2 servers. In both cases same problem occurs. Only single user is using database and only this query is running. Locks window shows: 7840 toy 53749 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) 7840 toy 53652 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) 7840 toy 54605 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) 7840 toy 54608 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) 7840 toy 49799 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) 7840 admin 7/13375 7/13375 ExclusiveLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) 7840 toy 53750 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu) Andrus.
Re: Andrus 2013-09-23 <E04C65FDEE80430DB6499621E2EC36BC@dell2> > SELECT * FROM toode > WHERE toode in (SELECT toode FROM tempkaive) > OR toode in (SELECT toode FROM tempalgsemu) Generally, WHERE IN (SELECT) should be rewritten as WHERE EXISTS (SELECT): SELECT * FROM toode o WHERE EXISTS (SELECT toode FROM tempkaive i WHERE o.toode = i.toode) OR EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode) Also, ANALYZEing the tables after the upgrade might help if this has not yet been done. Christoph -- cb@df7cb.de | http://www.df7cb.de/
Could you please post EXPLAIN for that query?
How 'fat' are the temporary tables - just a couple of columns or really wide? On Mon, Sep 23, 2013 at 7:08 PM, Andrus <kobruleht2@hot.ee> wrote:
Query
SELECT * FROM toode
WHERE toode in (SELECT toode FROM tempkaive)
OR toode in (SELECT toode FROM tempalgsemu)
stops working after upgrading to 9.3 RTM in Windows from earlier version.
Task Manager shows that postgres.exe process has constantly 13% CPU usage (this is 8 core computer) and private working set memory is 16 MB
PgAdmin shows that this query is running .
toode field type is char(20) and it is toode table primary key.
tempkaive and tempalgsemu are temporary tables created eralier this transaction. They do not have indexes.
toode is real table which has 509873 records .
Probably tempkaive temp table size is bigger that toode table and templalgemu temp table size is smaller than in toode.
How to fix this or find the reason ?
How to rewrite the query so that it works ?
analyze command was executed but problem persists.
I tested it running Postgres 9.3 RTM in 32 bin Windows 7 and 64 bit Windows 2008 R2 servers.
In both cases same problem occurs.
Only single user is using database and only this query is running.
Locks window shows:
7840 toy 53749 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 53652 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 54605 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 54608 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 49799 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 admin 7/13375 7/13375 ExclusiveLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 53750 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
Andrus.
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Hi, Thank you. >Generally, WHERE IN (SELECT) should be rewritten as WHERE EXISTS >(SELECT): >SELECT * FROM toode o >WHERE EXISTS (SELECT toode FROM tempkaive i WHERE o.toode = i.toode) > OR EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode) I re-wrote it. It now hangs in this line SELECT * FROM toode o WHERE exists (SELECT toode FROM tempkaive i where o.toode = i.toode ) OR EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode) I wait 18 minutes but query is still running. Maybe it will take extremely long time. How to make it work ? toode table structure is below. It contains 509873 records . tempkaive and tempalgsemu are big temporary tables created earlier this transaction. They do not have indexes and have lot of records. Andrus. CREATE TABLE firma1.toode ( grupp character(1), toode character(20) NOT NULL, ribakood character(20), ribakood2 character(20), ribakood3 character(20), nimetus character(50), yhik character(6), myygikood character(4), tykke numeric(9,2), liik character(10), kontonr character(10), engnimetus character(50), rusnimetus character(50), finnimetus character(50), lvlnimetus character(50), markused text, myygihind numeric(15,5), jaehind numeric(15,2), katteprots numeric(6,2), paritoluri character(2), ostuhind numeric(15,5), valmyygih numeric(15,5), valraha character(3), ovalraha character(3), aktsiis numeric(10,5), kogpak numeric(9,4) NOT NULL DEFAULT 0, soodkogus numeric(8,1), vaikkogus numeric(12,4), hinne numeric(8,2), yhikuteise numeric(9,4), norm numeric(8,4), soetaeg date, soetarve character(25), algmaksumu numeric(12,2), kasutaja character(12), kulum character(10), kulukonto character(10), oper character(3), objekt1 character(10), objekt2 character(10), objekt3 character(10), objekt4 character(10), objekt5 character(10), objekt6 character(10), objekt7 character(10), objekt8 character(10), objekt9 character(10), parimenne date, asukoht character(25), minkogus numeric(12,4), masin character(5), ryhm character(10), klass character(5), kaubasumma text, tasusumma text, pangateen ebool, analoog character(20), taara character(20), taara2 character(20), taarakaal numeric(9,5), taara2kaal numeric(9,5), hankija character(12), hinnak character(5), eelminekuu ebool, distribute ebool, plaanhind numeric(15,5), "timestamp" character(14) NOT NULL DEFAULT to_char(now(), 'YYYYMMDDHH24MISS'::text), atimestamp character(14) NOT NULL DEFAULT to_char(now(), 'YYYYMMDDHH24MISS'::text), username character(10), changedby character(10), kgasuvi numeric(2,0), ktasuvi numeric(2,0), kgatalv numeric(2,0), ktatalv numeric(2,0), kylmik numeric(2,0), tkmkoef numeric(3,1), paak numeric(4,0), kassakeeld ebool, kaalukaup ebool, saadakaalu ebool, sailivusae numeric(2,0), kaubakood character(10), netomass numeric(12,4), seisund character(1), tootjakood character(40), klassif3 numeric(7,0), prots1 numeric(6,2), prots2 numeric(6,2), prots3 numeric(6,2), ale1 numeric(8,2), ale2 numeric(8,2), ale3 numeric(8,2), tootja character(10), soomes numeric(12,4), originaal character(20), eekjaehind numeric(15,2), amordipiir numeric(12,2), pant character(20), hulgihind numeric(12,2), transportw ebool, tykke2 numeric(9,2), tootjaviit character(40), CONSTRAINT toode_pkey PRIMARY KEY (toode), CONSTRAINT toode_changedby_fkey FOREIGN KEY (changedby) REFERENCES kasutaja (kasutaja) MATCH SIMPLE ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_kasutaja_fkey FOREIGN KEY (kasutaja) REFERENCES firma1.klient (kood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_kaubakood_fkey FOREIGN KEY (kaubakood) REFERENCES nomenkla (kood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_kontonr_fkey FOREIGN KEY (kontonr) REFERENCES firma1.konto (kontonr) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_kulukonto_fkey FOREIGN KEY (kulukonto) REFERENCES firma1.konto (kontonr) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_kulum_fkey FOREIGN KEY (kulum) REFERENCES firma1.konto (kontonr) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_liik_fkey FOREIGN KEY (liik) REFERENCES firma1.artliik (liik) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY DEFERRED, CONSTRAINT toode_myygikood_fkey FOREIGN KEY (myygikood) REFERENCES firma1.myygikoo (myygikood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt1_fkey FOREIGN KEY (objekt1) REFERENCES firma1.yksus1 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt2_fkey FOREIGN KEY (objekt2) REFERENCES firma1.yksus2 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt3_fkey FOREIGN KEY (objekt3) REFERENCES firma1.yksus3 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt4_fkey FOREIGN KEY (objekt4) REFERENCES firma1.yksus4 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt5_fkey FOREIGN KEY (objekt5) REFERENCES firma1.yksus5 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt7_fkey FOREIGN KEY (objekt7) REFERENCES firma1.yksus7 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt8_fkey FOREIGN KEY (objekt8) REFERENCES firma1.yksus8 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_objekt9_fkey FOREIGN KEY (objekt9) REFERENCES firma1.yksus9 (yksus) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_oper_fkey FOREIGN KEY (oper) REFERENCES alamdok (oper) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_ovalraha_fkey FOREIGN KEY (ovalraha) REFERENCES raha (raha) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_paritoluri_fkey FOREIGN KEY (paritoluri) REFERENCES riik (kood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_ryhm_fkey FOREIGN KEY (ryhm) REFERENCES firma1.artryhm (kood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_seisund_fkey FOREIGN KEY (seisund) REFERENCES artstaat (kood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_taara2_fkey FOREIGN KEY (taara2) REFERENCES firma1.toode (toode) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_taara_fkey FOREIGN KEY (taara) REFERENCES firma1.toode (toode) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_username_fkey FOREIGN KEY (username) REFERENCES kasutaja (kasutaja) MATCH SIMPLE ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_valraha_fkey FOREIGN KEY (valraha) REFERENCES raha (raha) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_yhik_fkey FOREIGN KEY (yhik) REFERENCES firma1.mootyhik (kood) MATCH SIMPLE ON UPDATE CASCADE ON DELETE NO ACTION DEFERRABLE INITIALLY IMMEDIATE, CONSTRAINT toode_grupp_check CHECK (grupp = ANY (ARRAY['L'::bpchar, 'P'::bpchar, 'V'::bpchar, 'S'::bpchar])) ) WITH ( OIDS=FALSE ); CREATE INDEX toode_toode_pattern_idx ON firma1.toode USING btree (toode COLLATE pg_catalog."default" bpchar_pattern_ops); CREATE UNIQUE INDEX toode_toode_unique_pattern_idx ON firma1.toode USING btree (upper(toode::text) COLLATE pg_catalog."default" text_pattern_ops); >Also, ANALYZEing the tables after the upgrade might help if this has >not yet been done. analyze was ran in this database. Andrus.
Hi,
thank you.
>Could you please post EXPLAIN for that query?
As recommend I changed query to use exists :
SELECT * FROM toode o WHERE exists (SELECT toode FROM tempkaive i where o.toode = i.toode ) OR
EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode)
It still hangs in same way. This query explain is:
Seq Scan on toode o (cost=0.00..172913763.23 rows=382319 width=1681)
Filter: ((SubPlan 1) OR (alternatives: SubPlan 2 or hashed SubPlan 3))
SubPlan 1
-> Seq Scan on tempkaive i (cost=0.00..4566.52 rows=14 width=0)
Filter: (o.toode = toode)
SubPlan 2
-> Seq Scan on tempalgsemu i_1 (cost=0.00..348.98 rows=27 width=0)
Filter: (o.toode = toode)
SubPlan 3
-> Seq Scan on tempalgsemu i_2 (cost=0.00..335.58 rows=5358 width=84)
> How 'fat' are the temporary tables - just a couple of columns or really wide?
tempalgsemu has 14 columns
tempkaive has 31 columns
structures are below. Too structure was posted in separate letter.
Andrus.
tempalgsemu :
Field Field Name Type Width Dec Index Collate Nulls Next Step
1 ID Integer 4 Yes
2 LAONR Numeric 4 Yes
3 KUUPAEV Date 8 Yes
4 KELLAAEG Character 5 Yes
5 OSAK Character 10 Yes
6 TOODE Character 20 Yes
7 PARTII Character 15 Yes
8 KOGUS Numeric 14 4 Yes
9 HIND Numeric 17 5 Yes
10 KULUM Numeric 17 5 Yes
11 TEGKOGUS Numeric 14 4 Yes
12 STKUUPAEV Date 8 Yes
13 KLIENT Character 12 Yes
14 MASIN Character 5 Yes
** Total ** 156
tempkaive
Field Field Name Type Width Dec Index Collate Nulls Next Step
1 DOKTYYP Character 1 Yes
2 DOKUMNR Integer 4 Yes
3 KUUPAEV Date 8 Yes
4 KELLAAEG Character 5 Yes
5 RAHA Character 3 Yes
6 EXCHRATE Numeric 16 8 Yes
7 KLIENT Character 12 Yes
8 ID Integer 4 Yes
9 TOODE Character 20 Yes
10 PARTII Character 15 Yes
11 KULUPARTII Character 15 Yes
12 KOGPAK Numeric 11 4 Yes
13 KOGUS Numeric 14 4 Yes
14 HIND Numeric 17 5 Yes
15 MYYGIKOOD Character 4 Yes
16 YHIK Character 6 Yes
17 NIMETUS Character 50 Yes
18 HINNAK Character 5 Yes
19 TKOGUS Numeric 20 6 Yes
20 UKOGUS Numeric 20 6 Yes
21 KUSTPARTII Character 15 Yes
22 KAUBASUMMA Numeric 17 5 Yes
23 KULUOBJEKT Character 10 Yes
24 FIFOEXPENS Logical 1 Yes
25 KULUM Numeric 17 5 Yes
26 SKAUBASUMM Numeric 17 5 Yes
27 ST Numeric 3 Yes
28 VM Numeric 3 Yes
29 VKAUBASUMM Numeric 20 6 Yes
30 YKSUS Character 10 Yes
31 SIHTYKSUS Character 10 Yes
** Total ** 378
On Mon, Sep 23, 2013 at 7:08 PM, Andrus <kobruleht2@hot.ee> wrote:
Query
SELECT * FROM toode
WHERE toode in (SELECT toode FROM tempkaive)
OR toode in (SELECT toode FROM tempalgsemu)
stops working after upgrading to 9.3 RTM in Windows from earlier version.
Task Manager shows that postgres.exe process has constantly 13% CPU usage (this is 8 core computer) and private working set memory is 16 MB
PgAdmin shows that this query is running .
toode field type is char(20) and it is toode table primary key.
tempkaive and tempalgsemu are temporary tables created eralier this transaction. They do not have indexes.
toode is real table which has 509873 records .
Probably tempkaive temp table size is bigger that toode table and templalgemu temp table size is smaller than in toode.
How to fix this or find the reason ?
How to rewrite the query so that it works ?
analyze command was executed but problem persists.
I tested it running Postgres 9.3 RTM in 32 bin Windows 7 and 64 bit Windows 2008 R2 servers.
In both cases same problem occurs.
Only single user is using database and only this query is running.
Locks window shows:
7840 toy 53749 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 53652 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 54605 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 54608 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 49799 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 admin 7/13375 7/13375 ExclusiveLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 53750 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
Andrus.
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
On Mon, Sep 23, 2013 at 8:06 AM, Andrus <kobruleht2@hot.ee> wrote:
>Could you please post EXPLAIN for that query?
Could you also post the results of the following query?
SELECT name, current_setting(name), source
FROM pg_settings
WHERE source NOT IN ('default', 'override');
SELECT name, current_setting(name), source
FROM pg_settings
WHERE source NOT IN ('default', 'override');
Also, what is the total memory in the server?
I fixed the issue by creating indexes for temporary tables before running query:
create index on tempalgsemu(toode);
create index on temphetkes(toode);
SELECT * FROM toode o WHERE exists (SELECT toode FROM tempkaive i where o.toode = i.toode ) OR
EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode);
Is this best fix ?
Andrus.
From: Andrus
Sent: Monday, September 23, 2013 6:06 PM
To: Jayadevan M
Subject: Re: [GENERAL] Query runs forever after upgrading to 9.3
Hi,
thank you.
>Could you please post EXPLAIN for that query?
As recommend I changed query to use exists :
SELECT * FROM toode o WHERE exists (SELECT toode FROM tempkaive i where o.toode = i.toode ) OR
EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode)
It still hangs in same way. This query explain is:
Seq Scan on toode o (cost=0.00..172913763.23 rows=382319 width=1681)
Filter: ((SubPlan 1) OR (alternatives: SubPlan 2 or hashed SubPlan 3))
SubPlan 1
-> Seq Scan on tempkaive i (cost=0.00..4566.52 rows=14 width=0)
Filter: (o.toode = toode)
SubPlan 2
-> Seq Scan on tempalgsemu i_1 (cost=0.00..348.98 rows=27 width=0)
Filter: (o.toode = toode)
SubPlan 3
-> Seq Scan on tempalgsemu i_2 (cost=0.00..335.58 rows=5358 width=84)
> How 'fat' are the temporary tables - just a couple of columns or really wide?
tempalgsemu has 14 columns
tempkaive has 31 columns
structures are below. Too structure was posted in separate letter.
Andrus.
tempalgsemu :
Field Field Name Type Width Dec Index Collate Nulls Next Step
1 ID Integer 4 Yes
2 LAONR Numeric 4 Yes
3 KUUPAEV Date 8 Yes
4 KELLAAEG Character 5 Yes
5 OSAK Character 10 Yes
6 TOODE Character 20 Yes
7 PARTII Character 15 Yes
8 KOGUS Numeric 14 4 Yes
9 HIND Numeric 17 5 Yes
10 KULUM Numeric 17 5 Yes
11 TEGKOGUS Numeric 14 4 Yes
12 STKUUPAEV Date 8 Yes
13 KLIENT Character 12 Yes
14 MASIN Character 5 Yes
** Total ** 156
tempkaive
Field Field Name Type Width Dec Index Collate Nulls Next Step
1 DOKTYYP Character 1 Yes
2 DOKUMNR Integer 4 Yes
3 KUUPAEV Date 8 Yes
4 KELLAAEG Character 5 Yes
5 RAHA Character 3 Yes
6 EXCHRATE Numeric 16 8 Yes
7 KLIENT Character 12 Yes
8 ID Integer 4 Yes
9 TOODE Character 20 Yes
10 PARTII Character 15 Yes
11 KULUPARTII Character 15 Yes
12 KOGPAK Numeric 11 4 Yes
13 KOGUS Numeric 14 4 Yes
14 HIND Numeric 17 5 Yes
15 MYYGIKOOD Character 4 Yes
16 YHIK Character 6 Yes
17 NIMETUS Character 50 Yes
18 HINNAK Character 5 Yes
19 TKOGUS Numeric 20 6 Yes
20 UKOGUS Numeric 20 6 Yes
21 KUSTPARTII Character 15 Yes
22 KAUBASUMMA Numeric 17 5 Yes
23 KULUOBJEKT Character 10 Yes
24 FIFOEXPENS Logical 1 Yes
25 KULUM Numeric 17 5 Yes
26 SKAUBASUMM Numeric 17 5 Yes
27 ST Numeric 3 Yes
28 VM Numeric 3 Yes
29 VKAUBASUMM Numeric 20 6 Yes
30 YKSUS Character 10 Yes
31 SIHTYKSUS Character 10 Yes
** Total ** 378
On Mon, Sep 23, 2013 at 7:08 PM, Andrus <kobruleht2@hot.ee> wrote:
Query
SELECT * FROM toode
WHERE toode in (SELECT toode FROM tempkaive)
OR toode in (SELECT toode FROM tempalgsemu)
stops working after upgrading to 9.3 RTM in Windows from earlier version.
Task Manager shows that postgres.exe process has constantly 13% CPU usage (this is 8 core computer) and private working set memory is 16 MB
PgAdmin shows that this query is running .
toode field type is char(20) and it is toode table primary key.
tempkaive and tempalgsemu are temporary tables created eralier this transaction. They do not have indexes.
toode is real table which has 509873 records .
Probably tempkaive temp table size is bigger that toode table and templalgemu temp table size is smaller than in toode.
How to fix this or find the reason ?
How to rewrite the query so that it works ?
analyze command was executed but problem persists.
I tested it running Postgres 9.3 RTM in 32 bin Windows 7 and 64 bit Windows 2008 R2 servers.
In both cases same problem occurs.
Only single user is using database and only this query is running.
Locks window shows:
7840 toy 53749 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 53652 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 54605 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 54608 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 49799 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 admin 7/13375 7/13375 ExclusiveLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
7840 toy 53750 admin 7/13375 AccessShareLock Yes 2013-09-23 15:57:08+03 SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive)OR toode in (SELECT toode FROM tempalgsemu)
Andrus.
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Hi!
>Could you also post the results of the following query?
>SELECT name, current_setting(name), source
>FROM pg_settings
>WHERE source NOT IN ('default', 'override');
>SELECT name, current_setting(name), source
>FROM pg_settings
>WHERE source NOT IN ('default', 'override');
In real server where problem is:
1 DateStyle ISO, DMY session
2 default_text_search_config pg_catalog.simple configuration file
3 extra_float_digits 2 session
4 lc_messages Estonian_Estonia.1257 configuration file
5 lc_monetary Estonian_Estonia.1257 configuration file
6 lc_numeric Estonian_Estonia.1257 configuration file
7 lc_time Estonian_Estonia.1257 configuration file
8 listen_addresses * configuration file
9 log_destination stderr configuration file
10 log_line_prefix %t %u %d configuration file
11 log_lock_waits on configuration file
12 log_min_duration_statement 10s configuration file
13 log_min_error_statement warning configuration file
14 log_temp_files 2000kB configuration file
15 log_timezone Europe/Helsinki configuration file
16 logging_collector on configuration file
17 max_connections 100 configuration file
18 max_stack_depth 2MB environment variable
19 port 5432 configuration file
20 search_path firma1, public session
21 shared_buffers 2400MB configuration file
22 TimeZone Europe/Helsinki configuration file
In development computer from where explain was posted and problem with copy of database also occurs:
"application_name";"pgAdmin III - Query Tool";"client"
"bytea_output";"escape";"session"
"client_encoding";"UNICODE";"session"
"client_min_messages";"notice";"session"
"DateStyle";"ISO, DMY";"session"
"default_text_search_config";"pg_catalog.simple";"configuration file"
"lc_messages";"Estonian_Estonia.1257";"configuration file"
"lc_monetary";"Estonian_Estonia.1257";"configuration file"
"lc_numeric";"Estonian_Estonia.1257";"configuration file"
"lc_time";"Estonian_Estonia.1257";"configuration file"
"listen_addresses";"*";"configuration file"
"log_destination";"stderr";"configuration file"
"log_line_prefix";"%t ";"configuration file"
"log_timezone";"Europe/Helsinki";"configuration file"
"logging_collector";"on";"configuration file"
"max_connections";"100";"configuration file"
"max_stack_depth";"2MB";"environment variable"
"port";"5432";"configuration file"
"shared_buffers";"128MB";"configuration file"
"TimeZone";"Europe/Helsinki";"configuration file"
> Also, what is the total memory in the server?
In devel computer where tests are performed, 4 GB
Real server has 16 GB RAM
Real server is for Postgres for this database and ASP.NET MVC3 application which uses this same database from postgres.
Can settings in real server changed to increase perfomance ?
Andrus.
On Mon, Sep 23, 2013 at 8:33 AM, Andrus <kobruleht2@hot.ee> wrote:
Hi!>Could you also post the results of the following query?
>SELECT name, current_setting(name), source
>FROM pg_settings
>WHERE source NOT IN ('default', 'override');In real server where problem is:21 shared_buffers 2400MB configuration file
What are effective_cache_size and work_mem set to? The defaults? They are good candidates to be increased. effective_cache_size could be set to (for example) 10GB, depending on how much memory gets consumed by the other application(s) running on that server.
The EXPLAIN ANALYZE plan of your query will show if work_mem needs to be increased, as there will be a line saying something like "External merge: disk sort" (or something like that, can't recall the exact message off the top of my head).
In development computer from where explain was posted and problem with copy of database also occurs:"shared_buffers";"128MB";"configuration file"
You likely want to bump that up closer to 1GB.
> Also, what is the total memory in the server?
In devel computer where tests are performed, 4 GBReal server has 16 GB RAMReal server is for Postgres for this database and ASP.NET MVC3 application which uses this same database from postgres.
Hi,
>>21 shared_buffers 2400MB configuration file
>What are effective_cache_size and work_mem set to? The defaults?
Yes.
>They are good candidates to be increased. effective_cache_size could be set to (for example) 10GB, depending on >how much memory gets consumed by the other application(s) running on that server.
There are 10 human users and one web service user. Windows Task Manager cached value shows 10 GB
There are 10 human users and one web service user. Windows Task Manager cached value shows 10 GB
in evening when nobody is working in server.
I changed those to
effective_cache_size= 10GB
work_mem = 400MB
Hope that this is OK.
After adding indexes log contains
LOG: duration: 11045.000 ms statement: create index on tempkaive(toode);create index on tempalgsemu(toode);SELECT * FROM toode o WHERE exists (SELECT toode FROM tempkaive i where o.toode=i.toode) OR EXISTS (SELECT toode FROM tempalgsemu i WHERE o.toode = i.toode)
In development computer from where explain was posted and problem with copy of database also occurs:"shared_buffers";"128MB";"configuration file"
> You likely want to bump that up closer to 1GB.
I changed it. Thank you very much.
Andrus.
On Mon, Sep 23, 2013 at 9:12 AM, Andrus <kobruleht2@hot.ee> wrote:
work_mem = 400MBHope that this is OK.
For cluster-wide setting you will probably want to drop that significantly -- start lower, as in somewhere around 10MB and work up from there as necessary. For the queries you are finding slow (the reason for these emails) you can set work_mem specifically for the session.
Eg.
set work_mem to '400MB';
<run your query>
reset work_mem;
Hi,
>For cluster-wide setting you will probably want to drop that significantly -- start lower, as in somewhere around 10MB >and work up from there as necessary. For the queries you are finding slow (the reason for these emails) you can set >work_mem specifically for the session.
>Eg.
>set work_mem to '400MB';
><run your query>
>reset work_mem;
I changed it to 10MB.
The problamatic commands runs now less than 10 seconds.
wrote that max reasonable value in Windows for shared_buffers is 512MB
Is my setting shared_buffers= 2400MB reasonable in Windows ?
Andrus.
On Mon, Sep 23, 2013 at 9:50 AM, Andrus <kobruleht2@hot.ee> wrote:
wrote that max reasonable value in Windows for shared_buffers is 512MBIs my setting shared_buffers= 2400MB reasonable in Windows ?
Someone else will hopefully answer that question, I have never run Postgresql on Windows.
"Andrus" <kobruleht2@hot.ee> writes: > Query > SELECT * FROM toode > WHERE toode in (SELECT toode FROM tempkaive) > OR toode in (SELECT toode FROM tempalgsemu) > stops working after upgrading to 9.3 RTM in Windows from earlier version. Just out of curiosity, what "earlier version" was that that was able to run this query quickly? Based on what you've said in this thread, I don't see a reason for 9.3 to be slower than earlier releases for this. The default plan certainly sucks, but that would've been true in earlier releases as well. Personally I'd try to get rid of the OR, perhaps with SELECT * FROM toode WHERE toode in (SELECT toode FROM tempkaive UNION ALL SELECT toode FROM tempalgsemu) You want to end up with a plan that has no "SubPlans" in it, and in a quick check this looked promising. regards, tom lane
Hi, >Just out of curiosity, what "earlier version" was that that was able to >run this query quickly? It was installed in customer site at May 2012 in Windows 2003 server and latest RTM version of Postgres x32 in this time was used. In this year server was upgraded to Windows 2008 x64 server and Postgres 9.3 x64 was used, database was restored from backup copy. After that this query started to run forever so I assumed that this was Postgres version issue. It is probably possible to try to reproduce the issue by restoring it to earlier version. >Personally I'd try to get rid of the OR, perhaps with >SELECT * FROM toode >WHERE toode in (SELECT toode FROM tempkaive UNION ALL > SELECT toode FROM tempalgsemu) >You want to end up with a plan that has no "SubPlans" in it, and in >a quick check this looked promising. I fixed the issue by using create index tempkaivetoode on tempkaive(toode); create index tempalgemutoode on tempalgsemu(toode); and using exists. Will your suggestion run faster ? Is it reasonable to switch to use your suggestion ? Andrus.
"Andrus" <kobruleht2@hot.ee> writes: >> Just out of curiosity, what "earlier version" was that that was able to >> run this query quickly? > It was installed in customer site at May 2012 in Windows 2003 server and > latest RTM version of Postgres > x32 in this time was used. That would probably have been 9.1.something, which makes it even less likely that there was a significant planner difference affecting this. I wonder if maybe the 9.1 installation had a higher work_mem, or there was some other configuration setting you forgot to bring forward. (A higher work_mem might have allowed it to use hashed rather than simple subplans, which could possibly explain the speed difference.) > Will your suggestion run faster ? Is it reasonable to switch to use your > suggestion ? If you're happy with performance now, there's probably no reason to mess with it. Changing the query might allow you to skip building those indexes though, so if that's a pain point then it might be worth spending more time on. regards, tom lane