File: performance_tips.xml

package info (click to toggle)
postgis 3.5.3%2Bdfsg-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 69,528 kB
  • sloc: ansic: 162,229; sql: 93,970; xml: 53,139; cpp: 12,646; perl: 5,658; sh: 5,369; makefile: 3,435; python: 1,205; yacc: 447; lex: 151; pascal: 58
file content (146 lines) | stat: -rw-r--r-- 7,567 bytes parent folder | download | duplicates (4)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
<!-- Converted by db4-upgrade version 1.1 -->
<chapter xmlns:xlink="http://www.w3.org/1999/xlink" xmlns="http://docbook.org/ns/docbook" version="5.0" xml:id="performance_tips">
  <title>Performance Tips</title>

  <section xml:id="small_tables_large_objects">
    <title>Small tables of large geometries</title>

    <section>
      <title>Problem description</title>

      <para>Current PostgreSQL versions (including 9.6) suffer from a query
      optimizer weakness regarding TOAST tables. TOAST tables are a kind of
      "extension room" used to store large (in the sense of data size) values
      that do not fit into normal data pages (like long texts, images or
      complex geometries with lots of vertices), see
      <link xlink:href="http://www.postgresql.org/docs/current/static/storage-toast.html">the PostgreSQL Documentation for TOAST</link> for more
      information).</para>

      <para>The problem appears if you happen to have a table with rather
      large geometries, but not too many rows of them (like a table containing
      the boundaries of all European countries in high resolution). Then the
      table itself is small, but it uses lots of TOAST space. In our example
      case, the table itself had about 80 rows and used only 3 data pages, but
      the TOAST table used 8225 pages.</para>

      <para>Now issue a query where you use the geometry operator &amp;&amp;
      to search for a bounding box that matches only very few of those rows.
      Now the query optimizer sees that the table has only 3 pages and 80
      rows. It estimates that a sequential scan on such a small table is much
      faster than using an index. And so it decides to ignore the GIST index.
      Usually, this estimation is correct. But in our case, the &amp;&amp;
      operator has to fetch every geometry from disk to compare the bounding
      boxes, thus reading all TOAST pages, too.</para>

      <para>To see whether your suffer from this issue, use the "EXPLAIN
      ANALYZE" postgresql command. For more information and the technical
      details, you can read the thread on the PostgreSQL performance mailing
      list:
      <link xlink:href="http://archives.postgresql.org/pgsql-performance/2005-02/msg00030.php">http://archives.postgresql.org/pgsql-performance/2005-02/msg00030.php</link></para>

      <para>and newer thread on PostGIS <link xlink:href="https://lists.osgeo.org/pipermail/postgis-devel/2017-June/026209.html">https://lists.osgeo.org/pipermail/postgis-devel/2017-June/026209.html</link></para>
    </section>

    <section>
      <title>Workarounds</title>

      <para>The PostgreSQL people are trying to solve this issue by making the
      query estimation TOAST-aware. For now, here are two workarounds:</para>

      <para>The first workaround is to force the query planner to use the
      index. Send "SET enable_seqscan TO off;" to the server before issuing
      the query. This basically forces the query planner to avoid sequential
      scans whenever possible. So it uses the GIST index as usual. But this
      flag has to be set on every connection, and it causes the query planner
      to make misestimations in other cases, so you should "SET enable_seqscan
      TO on;" after the query.</para>

      <para>The second workaround is to make the sequential scan as fast as
      the query planner thinks. This can be achieved by creating an additional
      column that "caches" the bbox, and matching against this. In our
      example, the commands are like:</para>

      <programlisting>SELECT AddGeometryColumn('myschema','mytable','bbox','4326','GEOMETRY','2');
UPDATE mytable SET bbox = ST_Envelope(ST_Force2D(geom));</programlisting>

      <para>Now change your query to use the &amp;&amp; operator against bbox
      instead of geom_column, like:</para>

      <programlisting><![CDATA[
SELECT geom_column
FROM mytable
WHERE bbox && ST_SetSRID('BOX3D(0 0,1 1)'::box3d,4326);
]]></programlisting>

      <para>Of course, if you change or add rows to mytable, you have to keep
      the bbox "in sync". The most transparent way to do this would be
      triggers, but you also can modify your application to keep the bbox
      column current or run the UPDATE query above after every
      modification.</para>
    </section>
  </section>

  <section xml:id="database_clustering">
    <title>CLUSTERing on geometry indices</title>

    <para>For tables that are mostly read-only, and where a single index is
    used for the majority of queries, PostgreSQL offers the CLUSTER command.
    This command physically reorders all the data rows in the same order as
    the index criteria, yielding two performance advantages: First, for index
    range scans, the number of seeks on the data table is drastically reduced.
    Second, if your working set concentrates to some small intervals on the
    indices, you have a more efficient caching because the data rows are
    spread along fewer data pages. (Feel invited to read the CLUSTER command
    documentation from the PostgreSQL manual at this point.)</para>

    <para>However, currently PostgreSQL does not allow clustering on PostGIS
    GIST indices because GIST indices simply ignores NULL values, you get an
    error message like:</para>

    <programlisting>lwgeom=# CLUSTER my_geom_index ON my_table;
ERROR: cannot cluster when index access method does not handle null values
HINT: You may be able to work around this by marking column "geom" NOT NULL.</programlisting>

    <para>As the HINT message tells you, one can work around this deficiency
    by adding a "not null" constraint to the table:</para>

    <programlisting>lwgeom=# ALTER TABLE my_table ALTER COLUMN geom SET not null;
ALTER TABLE</programlisting>

    <para>Of course, this will not work if you in fact need NULL values in
    your geometry column. Additionally, you must use the above method to add
    the constraint, using a CHECK constraint like "ALTER TABLE blubb ADD CHECK
    (geometry is not null);" will not work.</para>
  </section>

  <section xml:id="avoiding_dimension_conversion">
    <title>Avoiding dimension conversion</title>

    <para>Sometimes, you happen to have 3D or 4D data in your table, but
    always access it using OpenGIS compliant ST_AsText() or ST_AsBinary()
    functions that only output 2D geometries. They do this by internally
    calling the ST_Force2D() function, which introduces a significant
    overhead for large geometries. To avoid this overhead, it may be feasible
    to pre-drop those additional dimensions once and forever:</para>

    <programlisting>UPDATE mytable SET geom = ST_Force2D(geom);
VACUUM FULL ANALYZE mytable;</programlisting>

    <para>Note that if you added your geometry column using
    AddGeometryColumn() there'll be a constraint on geometry dimension. To
    bypass it you will need to drop the constraint. Remember to update the
    entry in the geometry_columns table and recreate the constraint
    afterwards.</para>

    <para>In case of large tables, it may be wise to divide this UPDATE into
    smaller portions by constraining the UPDATE to a part of the table via a
    WHERE clause and your primary key or another feasible criteria, and
    running a simple "VACUUM;" between your UPDATEs. This drastically reduces
    the need for temporary disk space. Additionally, if you have mixed
    dimension geometries, restricting the UPDATE by "WHERE
    dimension(geom)&gt;2" skips re-writing of geometries that already are
    in 2D.</para>

  </section>

</chapter>