Re: ORDER BY too slow in Foreign Table using postgres_fdw

From: Samed YILDIRIM <samed(at)reddoc(dot)net>
To: Luan Huynh <nnhluan(at)gmail(dot)com>, "pgsql-performance-owner(at)postgresql(dot)org" <pgsql-performance-owner(at)postgresql(dot)org>, "pgsql-sql-owner(at)postgresql(dot)org" <pgsql-sql-owner(at)postgresql(dot)org>, "pgsql-admin(at)postgresql(dot)org" <pgsql-admin(at)postgresql(dot)org>
Subject: Re: ORDER BY too slow in Foreign Table using postgres_fdw
Date: 2017-07-18 12:38:48
Message-ID: 78991500381528@web3j.yandex.ru
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

<div>Hi Luan,</div><div> </div><div>Sort operation is performed on local postgres server, not on remote. Because of that, local postgresql server gets all rows matched by filter and then sort them. If your code always sort the results, you can just create a view on remote postgres with order by clause and then create a foreign table pointing to the view. By using a view like that, sorting is performed on remote server.</div><div> </div><div><strong>On remote Postgres</strong></div><div>create view user_info_vw as select id,info from user_info order by id;</div><div> </div><div><strong>On local Postgres</strong></div><div>create foreign table user_info (id bigint, info jsonb) server luan_server options (schema_name 'public', table_name 'user_info_vw');</div><div> </div><div> </div><div><u><em>Before view</em></u></div><div><div>postgres=# explain analyze SELECT id, info</div><div>FROM user_info</div><div>WHERE info -&gt;&gt; 'key1'= '1' order by id limit 10;</div><div>                                                           QUERY PLAN                                                            </div><div>---------------------------------------------------------------------------------------------------------------------------------</div><div> Limit  (cost=153.28..153.29 rows=6 width=40) (actual time=7512.755..7512.759 rows=10 loops=1)</div><div>   -&gt;  Sort  (cost=153.28..153.29 rows=6 width=40) (actual time=7512.754..7512.757 rows=10 loops=1)</div><div>         Sort Key: id</div><div>         Sort Method: top-N heapsort  Memory: 26kB</div><div>         -&gt;  Foreign Scan on user_info  (cost=100.00..153.20 rows=6 width=40) (actual time=0.962..7351.989 rows=1187840 loops=1)</div><div>               Filter: ((info -&gt;&gt; 'key1'::text) = '1'::text)</div><div>               Rows Removed by Filter: 786432</div><div> Planning time: 0.089 ms</div><div><strong> Execution time: 7513.322 ms</strong></div><div>(9 rows)</div><div> </div><div> </div></div><div><u><em>After view</em></u></div><div><div>explain analyze SELECT id, info</div><div>FROM user_info</div><div>WHERE info -&gt;&gt; 'key1'= '1' LIMIT 10;</div><div>                                                    QUERY PLAN                                                     </div><div>-------------------------------------------------------------------------------------------------------------------</div><div> Limit  (cost=100.00..153.20 rows=6 width=40) (actual time=0.678..0.684 rows=10 loops=1)</div><div>   -&gt;  Foreign Scan on user_info  (cost=100.00..153.20 rows=6 width=40) (actual time=0.677..0.681 rows=10 loops=1)</div><div>         Filter: ((info -&gt;&gt; 'key1'::text) = '1'::text)</div><div>         Rows Removed by Filter: 4</div><div> Planning time: 0.060 ms</div><div><strong> Execution time: 1.167 ms</strong></div><div>(6 rows)</div></div><div> </div><div><div>postgres=# SELECT id, info</div><div>postgres-# FROM user_info</div><div>postgres-# WHERE info -&gt;&gt; 'key1'= '1' LIMIT 10;</div><div> id |            info            </div><div>----+----------------------------</div><div>  1 | {"key1": 1, "key2": 0.678}</div><div>  2 | {"key1": 1, "key2": 0.678}</div><div>  3 | {"key1": 1, "key2": 1.0}</div><div>  4 | {"key1": 1, "key2": 0.986}</div><div>  7 | {"key1": 1, "key2": 0.678}</div><div>  8 | {"key1": 1, "key2": 1.0}</div><div>  9 | {"key1": 1, "key2": 0.986}</div><div> 12 | {"key1": 1, "key2": 0.678}</div><div> 13 | {"key1": 1, "key2": 1.0}</div><div> 14 | {"key1": 1, "key2": 0.986}</div><div>(10 rows)</div></div><div> </div><div>Best regards.</div><div><br /></div><div><br /></div><div>İyi çalışmalar.</div><div>Samed YILDIRIM</div><div><br /></div><div><br /></div><div><br /></div><div>18.07.2017, 10:06, "Luan Huynh" &lt;nnhluan(at)gmail(dot)com&gt;:</div><blockquote type="cite"><div dir="ltr"><div>Hi all, </div><div><br /></div><div>On PostgreSQL <b>v.9.6, </b>when using <b>postgres_fdw</b>, I got an issue with "<b><i>ORDER BY</i></b>" (<a href="https://dba.stackexchange.com/questions/179744/order-by-too-slow-in-foreign-table-using-postgres-fdw">here's my question on stackexchange</a> ).</div><div><br /></div><div><b>Query on Foreign Table</b></div><blockquote style="margin:0 0 0 40px;border:none;padding:0px;"><div><font face="tahoma, sans-serif">SELECT id, info </font></div><div><div><font face="tahoma, sans-serif">FROM user_info</font></div></div><div><div><font face="tahoma, sans-serif">WHERE info -&gt;&gt; 'key1'= '1' </font></div></div><div><div><font face="tahoma, sans-serif">ORDER BY id </font></div></div><div><div><font face="tahoma, sans-serif">LIMIT 10; </font></div></div><div><div><font face="tahoma, sans-serif"><br /></font></div></div><div><div><font face="tahoma, sans-serif">Limit  (cost=<span>10750829</span>.63..<span>10750829</span>.65 rows=10 width=40) (actual time=550059.320..550059.326 rows=10 loops=1)</font></div></div><div><div><font face="tahoma, sans-serif">   -&gt;  Sort  (cost=<span>10750829</span>.63..<span>10751772</span>.77 rows=377257 width=40) (actual time=550059.318..550059.321 rows=10 loops=1)</font></div></div><div><div><font face="tahoma, sans-serif">         Sort Key: id</font></div></div><div><div><font face="tahoma, sans-serif">         Sort Method: top-N heapsort  Memory: 26kB</font></div></div><div><div><font face="tahoma, sans-serif">         -&gt;  Foreign Scan on user_info (cost=100.00..<span>10742677</span>.24 rows=377257 width=40) (actual time=1.413..536718.366 rows=<span>68281020</span> loops=1)</font></div></div><div><div><font face="tahoma, sans-serif">               Filter: ((info -&gt;&gt; 'key1'::text) = '1'::text)</font></div></div><div><div><font face="tahoma, sans-serif">               Rows Removed by Filter: <span>7170443</span></font></div></div><div><div><font face="tahoma, sans-serif"> Planning time: 4.097 ms</font></div></div><div><div><font face="tahoma, sans-serif"> <i>Execution time: 550059.597 ms</i></font></div></div></blockquote><div><br /></div><div><b>Query on remote server</b></div><blockquote style="margin:0 0 0 40px;border:none;padding:0px;"><div><div><font face="tahoma, sans-serif">EXPLAIN ANALYSE</font></div></div><div><div><font face="tahoma, sans-serif">SELECT id, info </font></div></div><div><div><font face="tahoma, sans-serif">FROM user_info_raw</font></div></div><div><div><font face="tahoma, sans-serif">WHERE info -&gt;&gt; 'key1'= '1'</font></div></div><div><div><font face="tahoma, sans-serif">ORDER BY id </font></div></div><div><div><font face="tahoma, sans-serif">LIMIT 10;</font></div></div><div><div><font face="tahoma, sans-serif"><br /></font></div></div><div><div><font face="tahoma, sans-serif"> Limit  (cost=0.57..1296.95 rows=10 width=59) (actual time=0.043..0.073 rows=10 loops=1)</font></div></div><div><div><font face="tahoma, sans-serif">   -&gt;  Index Scan using idx_user_info_raw_info on user_info_raw  (cost=0.57..<span>68882850</span>.88 rows=531346 width=59) (actual time=0.042..0.070 rows=10 loops=1)</font></div></div><div><div><font face="tahoma, sans-serif">         Filter: ((info -&gt;&gt; 'key1'::text) = '1'::text)</font></div></div><div><div><font face="tahoma, sans-serif"> Planning time: 0.192 ms</font></div></div><div><div><font face="tahoma, sans-serif"><i> Execution time: 0.102 ms </i></font></div></div></blockquote><div><br /></div><div><br /></div><div>Please help me to figure out the solution for that issue .<br /></div><div><br /></div><div>Thank you<br /></div><div> </div><div><br /></div></div>
</blockquote>

Attachment Content-Type Size
unknown_filename text/html 7.7 KB

In response to

Responses

Browse pgsql-admin by date

  From Date Subject
Next Message Prashanth Reddy 2017-07-18 14:58:12 Re: Steps to place standby database in read write
Previous Message Luan Huynh 2017-07-18 07:04:15 ORDER BY too slow in Foreign Table using postgres_fdw