gooderp18绿色标准版
Nie możesz wybrać więcej, niż 25 tematów Tematy muszą się zaczynać od litery lub cyfry, mogą zawierać myślniki ('-') i mogą mieć do 35 znaków.

935 lines
56KB

  1. <?xml version="1.0" encoding="UTF-8" standalone="no"?>
  2. <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>5.11. Table Partitioning</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="ddl-inherit.html" title="5.10. Inheritance" /><link rel="next" href="ddl-foreign-data.html" title="5.12. Foreign Data" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">5.11. Table Partitioning</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ddl-inherit.html" title="5.10. Inheritance">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="ddl.html" title="Chapter 5. Data Definition">Up</a></td><th width="60%" align="center">Chapter 5. Data Definition</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="ddl-foreign-data.html" title="5.12. Foreign Data">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="DDL-PARTITIONING"><div class="titlepage"><div><div><h2 class="title" style="clear: both">5.11. Table Partitioning</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="ddl-partitioning.html#DDL-PARTITIONING-OVERVIEW">5.11.1. Overview</a></span></dt><dt><span class="sect2"><a href="ddl-partitioning.html#DDL-PARTITIONING-DECLARATIVE">5.11.2. Declarative Partitioning</a></span></dt><dt><span class="sect2"><a href="ddl-partitioning.html#DDL-PARTITIONING-IMPLEMENTATION-INHERITANCE">5.11.3. Implementation Using Inheritance</a></span></dt><dt><span class="sect2"><a href="ddl-partitioning.html#DDL-PARTITION-PRUNING">5.11.4. Partition Pruning</a></span></dt><dt><span class="sect2"><a href="ddl-partitioning.html#DDL-PARTITIONING-CONSTRAINT-EXCLUSION">5.11.5. Partitioning and Constraint Exclusion</a></span></dt><dt><span class="sect2"><a href="ddl-partitioning.html#DDL-PARTITIONING-DECLARATIVE-BEST-PRACTICES">5.11.6. Declarative Partitioning Best Practices</a></span></dt></dl></div><a id="id-1.5.4.13.2" class="indexterm"></a><a id="id-1.5.4.13.3" class="indexterm"></a><a id="id-1.5.4.13.4" class="indexterm"></a><p>
  3. <span class="productname">PostgreSQL</span> supports basic table
  4. partitioning. This section describes why and how to implement
  5. partitioning as part of your database design.
  6. </p><div class="sect2" id="DDL-PARTITIONING-OVERVIEW"><div class="titlepage"><div><div><h3 class="title">5.11.1. Overview</h3></div></div></div><p>
  7. Partitioning refers to splitting what is logically one large table into
  8. smaller physical pieces. Partitioning can provide several benefits:
  9. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  10. Query performance can be improved dramatically in certain situations,
  11. particularly when most of the heavily accessed rows of the table are in a
  12. single partition or a small number of partitions. The partitioning
  13. substitutes for leading columns of indexes, reducing index size and
  14. making it more likely that the heavily-used parts of the indexes
  15. fit in memory.
  16. </p></li><li class="listitem"><p>
  17. When queries or updates access a large percentage of a single
  18. partition, performance can be improved by taking advantage
  19. of sequential scan of that partition instead of using an
  20. index and random access reads scattered across the whole table.
  21. </p></li><li class="listitem"><p>
  22. Bulk loads and deletes can be accomplished by adding or removing
  23. partitions, if that requirement is planned into the partitioning design.
  24. Doing <code class="command">ALTER TABLE DETACH PARTITION</code> or dropping an individual
  25. partition using <code class="command">DROP TABLE</code> is far faster than a bulk
  26. operation. These commands also entirely avoid the
  27. <code class="command">VACUUM</code> overhead caused by a bulk <code class="command">DELETE</code>.
  28. </p></li><li class="listitem"><p>
  29. Seldom-used data can be migrated to cheaper and slower storage media.
  30. </p></li></ul></div><p>
  31. The benefits will normally be worthwhile only when a table would
  32. otherwise be very large. The exact point at which a table will
  33. benefit from partitioning depends on the application, although a
  34. rule of thumb is that the size of the table should exceed the physical
  35. memory of the database server.
  36. </p><p>
  37. <span class="productname">PostgreSQL</span> offers built-in support for the
  38. following forms of partitioning:
  39. </p><div class="variablelist"><dl class="variablelist"><dt><span class="term">Range Partitioning</span></dt><dd><p>
  40. The table is partitioned into <span class="quote">“<span class="quote">ranges</span>”</span> defined
  41. by a key column or set of columns, with no overlap between
  42. the ranges of values assigned to different partitions. For
  43. example, one might partition by date ranges, or by ranges of
  44. identifiers for particular business objects.
  45. </p></dd><dt><span class="term">List Partitioning</span></dt><dd><p>
  46. The table is partitioned by explicitly listing which key values
  47. appear in each partition.
  48. </p></dd><dt><span class="term">Hash Partitioning</span></dt><dd><p>
  49. The table is partitioned by specifying a modulus and a remainder for
  50. each partition. Each partition will hold the rows for which the hash
  51. value of the partition key divided by the specified modulus will
  52. produce the specified remainder.
  53. </p></dd></dl></div><p>
  54. If your application needs to use other forms of partitioning not listed
  55. above, alternative methods such as inheritance and
  56. <code class="literal">UNION ALL</code> views can be used instead. Such methods
  57. offer flexibility but do not have some of the performance benefits
  58. of built-in declarative partitioning.
  59. </p></div><div class="sect2" id="DDL-PARTITIONING-DECLARATIVE"><div class="titlepage"><div><div><h3 class="title">5.11.2. Declarative Partitioning</h3></div></div></div><p>
  60. <span class="productname">PostgreSQL</span> offers a way to specify how to
  61. divide a table into pieces called partitions. The table that is divided
  62. is referred to as a <em class="firstterm">partitioned table</em>. The
  63. specification consists of the <em class="firstterm">partitioning method</em>
  64. and a list of columns or expressions to be used as the
  65. <em class="firstterm">partition key</em>.
  66. </p><p>
  67. All rows inserted into a partitioned table will be routed to one of the
  68. <em class="firstterm">partitions</em> based on the value of the partition
  69. key. Each partition has a subset of the data defined by its
  70. <em class="firstterm">partition bounds</em>. The currently supported
  71. partitioning methods are range, list, and hash.
  72. </p><p>
  73. Partitions may themselves be defined as partitioned tables, using what is
  74. called <em class="firstterm">sub-partitioning</em>. Partitions may have their
  75. own indexes, constraints and default values, distinct from those of other
  76. partitions. See <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a> for more details on
  77. creating partitioned tables and partitions.
  78. </p><p>
  79. It is not possible to turn a regular table into a partitioned table or
  80. vice versa. However, it is possible to add a regular or partitioned table
  81. containing data as a partition of a partitioned table, or remove a
  82. partition from a partitioned table turning it into a standalone table;
  83. see <a class="xref" href="sql-altertable.html" title="ALTER TABLE"><span class="refentrytitle">ALTER TABLE</span></a> to learn more about the
  84. <code class="command">ATTACH PARTITION</code> and <code class="command">DETACH PARTITION</code>
  85. sub-commands.
  86. </p><p>
  87. Individual partitions are linked to the partitioned table with inheritance
  88. behind-the-scenes; however, it is not possible to use some of the
  89. generic features of inheritance (discussed below) with declaratively
  90. partitioned tables or their partitions. For example, a partition
  91. cannot have any parents other than the partitioned table it is a
  92. partition of, nor can a regular table inherit from a partitioned table
  93. making the latter its parent. That means partitioned tables and their
  94. partitions do not participate in inheritance with regular tables.
  95. Since a partition hierarchy consisting of the partitioned table and its
  96. partitions is still an inheritance hierarchy, all the normal rules of
  97. inheritance apply as described in <a class="xref" href="ddl-inherit.html" title="5.10. Inheritance">Section 5.10</a> with
  98. some exceptions, most notably:
  99. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  100. Both <code class="literal">CHECK</code> and <code class="literal">NOT NULL</code>
  101. constraints of a partitioned table are always inherited by all its
  102. partitions. <code class="literal">CHECK</code> constraints that are marked
  103. <code class="literal">NO INHERIT</code> are not allowed to be created on
  104. partitioned tables.
  105. </p></li><li class="listitem"><p>
  106. Using <code class="literal">ONLY</code> to add or drop a constraint on only the
  107. partitioned table is supported as long as there are no partitions. Once
  108. partitions exist, using <code class="literal">ONLY</code> will result in an error
  109. as adding or dropping constraints on only the partitioned table, when
  110. partitions exist, is not supported. Instead, constraints on the
  111. partitions themselves can be added and (if they are not present in the
  112. parent table) dropped.
  113. </p></li><li class="listitem"><p>
  114. As a partitioned table does not have any data directly, attempts to use
  115. <code class="command">TRUNCATE</code> <code class="literal">ONLY</code> on a partitioned
  116. table will always return an error.
  117. </p></li><li class="listitem"><p>
  118. Partitions cannot have columns that are not present in the parent. It
  119. is not possible to specify columns when creating partitions with
  120. <code class="command">CREATE TABLE</code>, nor is it possible to add columns to
  121. partitions after-the-fact using <code class="command">ALTER TABLE</code>. Tables may be
  122. added as a partition with <code class="command">ALTER TABLE ... ATTACH PARTITION</code>
  123. only if their columns exactly match the parent.
  124. </p></li><li class="listitem"><p>
  125. You cannot drop the <code class="literal">NOT NULL</code> constraint on a
  126. partition's column if the constraint is present in the parent table.
  127. </p></li></ul></div><p>
  128. </p><p>
  129. Partitions can also be foreign tables, although they have some limitations
  130. that normal tables do not; see <a class="xref" href="sql-createforeigntable.html" title="CREATE FOREIGN TABLE"><span class="refentrytitle">CREATE FOREIGN TABLE</span></a> for
  131. more information.
  132. </p><p>
  133. Updating the partition key of a row might cause it to be moved into a
  134. different partition where this row satisfies the partition bounds.
  135. </p><div class="sect3" id="DDL-PARTITIONING-DECLARATIVE-EXAMPLE"><div class="titlepage"><div><div><h4 class="title">5.11.2.1. Example</h4></div></div></div><p>
  136. Suppose we are constructing a database for a large ice cream company.
  137. The company measures peak temperatures every day as well as ice cream
  138. sales in each region. Conceptually, we want a table like:
  139. </p><pre class="programlisting">
  140. CREATE TABLE measurement (
  141. city_id int not null,
  142. logdate date not null,
  143. peaktemp int,
  144. unitsales int
  145. );
  146. </pre><p>
  147. We know that most queries will access just the last week's, month's or
  148. quarter's data, since the main use of this table will be to prepare
  149. online reports for management. To reduce the amount of old data that
  150. needs to be stored, we decide to only keep the most recent 3 years
  151. worth of data. At the beginning of each month we will remove the oldest
  152. month's data. In this situation we can use partitioning to help us meet
  153. all of our different requirements for the measurements table.
  154. </p><p>
  155. To use declarative partitioning in this case, use the following steps:
  156. </p><div class="orderedlist"><ol class="orderedlist compact" type="1"><li class="listitem"><p>
  157. Create <code class="structname">measurement</code> table as a partitioned
  158. table by specifying the <code class="literal">PARTITION BY</code> clause, which
  159. includes the partitioning method (<code class="literal">RANGE</code> in this
  160. case) and the list of column(s) to use as the partition key.
  161. </p><pre class="programlisting">
  162. CREATE TABLE measurement (
  163. city_id int not null,
  164. logdate date not null,
  165. peaktemp int,
  166. unitsales int
  167. ) PARTITION BY RANGE (logdate);
  168. </pre><p>
  169. </p><p>
  170. You may decide to use multiple columns in the partition key for range
  171. partitioning, if desired. Of course, this will often result in a larger
  172. number of partitions, each of which is individually smaller. On the
  173. other hand, using fewer columns may lead to a coarser-grained
  174. partitioning criteria with smaller number of partitions. A query
  175. accessing the partitioned table will have to scan fewer partitions if
  176. the conditions involve some or all of these columns.
  177. For example, consider a table range partitioned using columns
  178. <code class="structfield">lastname</code> and <code class="structfield">firstname</code> (in that order)
  179. as the partition key.
  180. </p></li><li class="listitem"><p>
  181. Create partitions. Each partition's definition must specify the bounds
  182. that correspond to the partitioning method and partition key of the
  183. parent. Note that specifying bounds such that the new partition's
  184. values will overlap with those in one or more existing partitions will
  185. cause an error. Inserting data into the parent table that does not map
  186. to one of the existing partitions will cause an error; an appropriate
  187. partition must be added manually.
  188. </p><p>
  189. Partitions thus created are in every way normal
  190. <span class="productname">PostgreSQL</span>
  191. tables (or, possibly, foreign tables). It is possible to specify a
  192. tablespace and storage parameters for each partition separately.
  193. </p><p>
  194. It is not necessary to create table constraints describing partition
  195. boundary condition for partitions. Instead, partition constraints are
  196. generated implicitly from the partition bound specification whenever
  197. there is need to refer to them.
  198. </p><pre class="programlisting">
  199. CREATE TABLE measurement_y2006m02 PARTITION OF measurement
  200. FOR VALUES FROM ('2006-02-01') TO ('2006-03-01');
  201. CREATE TABLE measurement_y2006m03 PARTITION OF measurement
  202. FOR VALUES FROM ('2006-03-01') TO ('2006-04-01');
  203. ...
  204. CREATE TABLE measurement_y2007m11 PARTITION OF measurement
  205. FOR VALUES FROM ('2007-11-01') TO ('2007-12-01');
  206. CREATE TABLE measurement_y2007m12 PARTITION OF measurement
  207. FOR VALUES FROM ('2007-12-01') TO ('2008-01-01')
  208. TABLESPACE fasttablespace;
  209. CREATE TABLE measurement_y2008m01 PARTITION OF measurement
  210. FOR VALUES FROM ('2008-01-01') TO ('2008-02-01')
  211. WITH (parallel_workers = 4)
  212. TABLESPACE fasttablespace;
  213. </pre><p>
  214. </p><p>
  215. To implement sub-partitioning, specify the
  216. <code class="literal">PARTITION BY</code> clause in the commands used to create
  217. individual partitions, for example:
  218. </p><pre class="programlisting">
  219. CREATE TABLE measurement_y2006m02 PARTITION OF measurement
  220. FOR VALUES FROM ('2006-02-01') TO ('2006-03-01')
  221. PARTITION BY RANGE (peaktemp);
  222. </pre><p>
  223. After creating partitions of <code class="structname">measurement_y2006m02</code>,
  224. any data inserted into <code class="structname">measurement</code> that is mapped to
  225. <code class="structname">measurement_y2006m02</code> (or data that is directly inserted
  226. into <code class="structname">measurement_y2006m02</code>, provided it satisfies its
  227. partition constraint) will be further redirected to one of its
  228. partitions based on the <code class="structfield">peaktemp</code> column. The partition
  229. key specified may overlap with the parent's partition key, although
  230. care should be taken when specifying the bounds of a sub-partition
  231. such that the set of data it accepts constitutes a subset of what
  232. the partition's own bounds allows; the system does not try to check
  233. whether that's really the case.
  234. </p></li><li class="listitem"><p>
  235. Create an index on the key column(s), as well as any other indexes you
  236. might want, on the partitioned table. (The key index is not strictly
  237. necessary, but in most scenarios it is helpful.)
  238. This automatically creates
  239. one index on each partition, and any partitions you create or attach
  240. later will also contain the index.
  241. </p><pre class="programlisting">
  242. CREATE INDEX ON measurement (logdate);
  243. </pre><p>
  244. </p></li><li class="listitem"><p>
  245. Ensure that the <a class="xref" href="runtime-config-query.html#GUC-ENABLE-PARTITION-PRUNING">enable_partition_pruning</a>
  246. configuration parameter is not disabled in <code class="filename">postgresql.conf</code>.
  247. If it is, queries will not be optimized as desired.
  248. </p></li></ol></div><p>
  249. </p><p>
  250. In the above example we would be creating a new partition each month, so
  251. it might be wise to write a script that generates the required DDL
  252. automatically.
  253. </p></div><div class="sect3" id="DDL-PARTITIONING-DECLARATIVE-MAINTENANCE"><div class="titlepage"><div><div><h4 class="title">5.11.2.2. Partition Maintenance</h4></div></div></div><p>
  254. Normally the set of partitions established when initially defining the
  255. table are not intended to remain static. It is common to want to
  256. remove old partitions of data and periodically add new partitions for
  257. new data. One of the most important advantages of partitioning is
  258. precisely that it allows this otherwise painful task to be executed
  259. nearly instantaneously by manipulating the partition structure, rather
  260. than physically moving large amounts of data around.
  261. </p><p>
  262. The simplest option for removing old data is to drop the partition that
  263. is no longer necessary:
  264. </p><pre class="programlisting">
  265. DROP TABLE measurement_y2006m02;
  266. </pre><p>
  267. This can very quickly delete millions of records because it doesn't have
  268. to individually delete every record. Note however that the above command
  269. requires taking an <code class="literal">ACCESS EXCLUSIVE</code> lock on the parent
  270. table.
  271. </p><p>
  272. Another option that is often preferable is to remove the partition from
  273. the partitioned table but retain access to it as a table in its own
  274. right:
  275. </p><pre class="programlisting">
  276. ALTER TABLE measurement DETACH PARTITION measurement_y2006m02;
  277. </pre><p>
  278. This allows further operations to be performed on the data before
  279. it is dropped. For example, this is often a useful time to back up
  280. the data using <code class="command">COPY</code>, <span class="application">pg_dump</span>, or
  281. similar tools. It might also be a useful time to aggregate data
  282. into smaller formats, perform other data manipulations, or run
  283. reports.
  284. </p><p>
  285. Similarly we can add a new partition to handle new data. We can create an
  286. empty partition in the partitioned table just as the original partitions
  287. were created above:
  288. </p><pre class="programlisting">
  289. CREATE TABLE measurement_y2008m02 PARTITION OF measurement
  290. FOR VALUES FROM ('2008-02-01') TO ('2008-03-01')
  291. TABLESPACE fasttablespace;
  292. </pre><p>
  293. As an alternative, it is sometimes more convenient to create the
  294. new table outside the partition structure, and make it a proper
  295. partition later. This allows the data to be loaded, checked, and
  296. transformed prior to it appearing in the partitioned table:
  297. </p><pre class="programlisting">
  298. CREATE TABLE measurement_y2008m02
  299. (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS)
  300. TABLESPACE fasttablespace;
  301. ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
  302. CHECK ( logdate &gt;= DATE '2008-02-01' AND logdate &lt; DATE '2008-03-01' );
  303. \copy measurement_y2008m02 from 'measurement_y2008m02'
  304. -- possibly some other data preparation work
  305. ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02
  306. FOR VALUES FROM ('2008-02-01') TO ('2008-03-01' );
  307. </pre><p>
  308. </p><p>
  309. Before running the <code class="command">ATTACH PARTITION</code> command, it is
  310. recommended to create a <code class="literal">CHECK</code> constraint on the table to
  311. be attached matching the desired partition constraint. That way,
  312. the system will be able to skip the scan to validate the implicit
  313. partition constraint. Without the <code class="literal">CHECK</code> constraint,
  314. the table will be scanned to validate the partition constraint while
  315. holding an <code class="literal">ACCESS EXCLUSIVE</code> lock on that partition
  316. and a <code class="literal">SHARE UPDATE EXCLUSIVE</code> lock on the parent table.
  317. It may be desired to drop the redundant <code class="literal">CHECK</code> constraint
  318. after <code class="command">ATTACH PARTITION</code> is finished.
  319. </p><p>
  320. As explained above, it is possible to create indexes on partitioned tables
  321. and they are applied automatically to the entire hierarchy. This is very
  322. convenient, as not only the existing partitions will become indexed, but
  323. also any partitions that are created in the future will. One limitation is
  324. that it's not possible to use the <code class="literal">CONCURRENTLY</code>
  325. qualifier when creating such a partitioned index. To overcome long lock
  326. times, it is possible to use <code class="command">CREATE INDEX ON ONLY</code>
  327. the partitioned table; such an index is marked invalid, and the partitions
  328. do not get the index applied automatically. The indexes on partitions can
  329. be created separately using <code class="literal">CONCURRENTLY</code>, and later
  330. <em class="firstterm">attached</em> to the index on the parent using
  331. <code class="command">ALTER INDEX .. ATTACH PARTITION</code>. Once indexes for all
  332. partitions are attached to the parent index, the parent index is marked
  333. valid automatically. Example:
  334. </p><pre class="programlisting">
  335. CREATE INDEX measurement_usls_idx ON ONLY measurement (unitsales);
  336. CREATE INDEX measurement_usls_200602_idx
  337. ON measurement_y2006m02 (unitsales);
  338. ALTER INDEX measurement_usls_idx
  339. ATTACH PARTITION measurement_usls_200602_idx;
  340. ...
  341. </pre><p>
  342. This technique can be used with <code class="literal">UNIQUE</code> and
  343. <code class="literal">PRIMARY KEY</code> constraints too; the indexes are created
  344. implicitly when the constraint is created. Example:
  345. </p><pre class="programlisting">
  346. ALTER TABLE ONLY measurement ADD UNIQUE (city_id, logdate);
  347. ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
  348. ALTER INDEX measurement_city_id_logdate_key
  349. ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
  350. ...
  351. </pre><p>
  352. </p></div><div class="sect3" id="DDL-PARTITIONING-DECLARATIVE-LIMITATIONS"><div class="titlepage"><div><div><h4 class="title">5.11.2.3. Limitations</h4></div></div></div><p>
  353. The following limitations apply to partitioned tables:
  354. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  355. There is no way to create an
  356. exclusion constraint spanning all partitions; it is only possible
  357. to constrain each leaf partition individually.
  358. </p></li><li class="listitem"><p>
  359. Unique constraints on partitioned tables must include all the
  360. partition key columns. This limitation exists because
  361. <span class="productname">PostgreSQL</span> can only enforce
  362. uniqueness in each partition individually.
  363. </p></li><li class="listitem"><p>
  364. <code class="literal">BEFORE ROW</code> triggers, if necessary, must be defined
  365. on individual partitions, not the partitioned table.
  366. </p></li><li class="listitem"><p>
  367. Mixing temporary and permanent relations in the same partition tree is
  368. not allowed. Hence, if the partitioned table is permanent, so must be
  369. its partitions and likewise if the partitioned table is temporary. When
  370. using temporary relations, all members of the partition tree have to be
  371. from the same session.
  372. </p></li></ul></div><p>
  373. </p></div></div><div class="sect2" id="DDL-PARTITIONING-IMPLEMENTATION-INHERITANCE"><div class="titlepage"><div><div><h3 class="title">5.11.3. Implementation Using Inheritance</h3></div></div></div><p>
  374. While the built-in declarative partitioning is suitable for most
  375. common use cases, there are some circumstances where a more flexible
  376. approach may be useful. Partitioning can be implemented using table
  377. inheritance, which allows for several features not supported
  378. by declarative partitioning, such as:
  379. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  380. For declarative partitioning, partitions must have exactly the same set
  381. of columns as the partitioned table, whereas with table inheritance,
  382. child tables may have extra columns not present in the parent.
  383. </p></li><li class="listitem"><p>
  384. Table inheritance allows for multiple inheritance.
  385. </p></li><li class="listitem"><p>
  386. Declarative partitioning only supports range, list and hash
  387. partitioning, whereas table inheritance allows data to be divided in a
  388. manner of the user's choosing. (Note, however, that if constraint
  389. exclusion is unable to prune child tables effectively, query performance
  390. might be poor.)
  391. </p></li><li class="listitem"><p>
  392. Some operations require a stronger lock when using declarative
  393. partitioning than when using table inheritance. For example,
  394. removing a partition from a partitioned table requires taking
  395. an <code class="literal">ACCESS EXCLUSIVE</code> lock on the parent table,
  396. whereas a <code class="literal">SHARE UPDATE EXCLUSIVE</code> lock is enough
  397. in the case of regular inheritance.
  398. </p></li></ul></div><p>
  399. </p><div class="sect3" id="DDL-PARTITIONING-INHERITANCE-EXAMPLE"><div class="titlepage"><div><div><h4 class="title">5.11.3.1. Example</h4></div></div></div><p>
  400. We use the non-partitioned <code class="structname">measurement</code>
  401. table above. To implement partitioning using inheritance, use
  402. the following steps:
  403. </p><div class="orderedlist"><ol class="orderedlist compact" type="1"><li class="listitem"><p>
  404. Create the <span class="quote">“<span class="quote">master</span>”</span> table, from which all of the
  405. <span class="quote">“<span class="quote">child</span>”</span> tables will inherit. This table will contain no data. Do not
  406. define any check constraints on this table, unless you intend them
  407. to be applied equally to all child tables. There is no point in
  408. defining any indexes or unique constraints on it, either. For our
  409. example, the master table is the <code class="structname">measurement</code>
  410. table as originally defined.
  411. </p></li><li class="listitem"><p>
  412. Create several <span class="quote">“<span class="quote">child</span>”</span> tables that each inherit from
  413. the master table. Normally, these tables will not add any columns
  414. to the set inherited from the master. Just as with declarative
  415. partitioning, these tables are in every way normal
  416. <span class="productname">PostgreSQL</span> tables (or foreign tables).
  417. </p><p>
  418. </p><pre class="programlisting">
  419. CREATE TABLE measurement_y2006m02 () INHERITS (measurement);
  420. CREATE TABLE measurement_y2006m03 () INHERITS (measurement);
  421. ...
  422. CREATE TABLE measurement_y2007m11 () INHERITS (measurement);
  423. CREATE TABLE measurement_y2007m12 () INHERITS (measurement);
  424. CREATE TABLE measurement_y2008m01 () INHERITS (measurement);
  425. </pre><p>
  426. </p></li><li class="listitem"><p>
  427. Add non-overlapping table constraints to the child tables to
  428. define the allowed key values in each.
  429. </p><p>
  430. Typical examples would be:
  431. </p><pre class="programlisting">
  432. CHECK ( x = 1 )
  433. CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' ))
  434. CHECK ( outletID &gt;= 100 AND outletID &lt; 200 )
  435. </pre><p>
  436. Ensure that the constraints guarantee that there is no overlap
  437. between the key values permitted in different child tables. A common
  438. mistake is to set up range constraints like:
  439. </p><pre class="programlisting">
  440. CHECK ( outletID BETWEEN 100 AND 200 )
  441. CHECK ( outletID BETWEEN 200 AND 300 )
  442. </pre><p>
  443. This is wrong since it is not clear which child table the key
  444. value 200 belongs in.
  445. </p><p>
  446. It would be better to instead create child tables as follows:
  447. </p><pre class="programlisting">
  448. CREATE TABLE measurement_y2006m02 (
  449. CHECK ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
  450. ) INHERITS (measurement);
  451. CREATE TABLE measurement_y2006m03 (
  452. CHECK ( logdate &gt;= DATE '2006-03-01' AND logdate &lt; DATE '2006-04-01' )
  453. ) INHERITS (measurement);
  454. ...
  455. CREATE TABLE measurement_y2007m11 (
  456. CHECK ( logdate &gt;= DATE '2007-11-01' AND logdate &lt; DATE '2007-12-01' )
  457. ) INHERITS (measurement);
  458. CREATE TABLE measurement_y2007m12 (
  459. CHECK ( logdate &gt;= DATE '2007-12-01' AND logdate &lt; DATE '2008-01-01' )
  460. ) INHERITS (measurement);
  461. CREATE TABLE measurement_y2008m01 (
  462. CHECK ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
  463. ) INHERITS (measurement);
  464. </pre><p>
  465. </p></li><li class="listitem"><p>
  466. For each child table, create an index on the key column(s),
  467. as well as any other indexes you might want.
  468. </p><pre class="programlisting">
  469. CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate);
  470. CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate);
  471. CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate);
  472. CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate);
  473. CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate);
  474. </pre><p>
  475. </p></li><li class="listitem"><p>
  476. We want our application to be able to say <code class="literal">INSERT INTO
  477. measurement ...</code> and have the data be redirected into the
  478. appropriate child table. We can arrange that by attaching
  479. a suitable trigger function to the master table.
  480. If data will be added only to the latest child, we can
  481. use a very simple trigger function:
  482. </p><pre class="programlisting">
  483. CREATE OR REPLACE FUNCTION measurement_insert_trigger()
  484. RETURNS TRIGGER AS $$
  485. BEGIN
  486. INSERT INTO measurement_y2008m01 VALUES (NEW.*);
  487. RETURN NULL;
  488. END;
  489. $$
  490. LANGUAGE plpgsql;
  491. </pre><p>
  492. </p><p>
  493. After creating the function, we create a trigger which
  494. calls the trigger function:
  495. </p><pre class="programlisting">
  496. CREATE TRIGGER insert_measurement_trigger
  497. BEFORE INSERT ON measurement
  498. FOR EACH ROW EXECUTE FUNCTION measurement_insert_trigger();
  499. </pre><p>
  500. We must redefine the trigger function each month so that it always
  501. points to the current child table. The trigger definition does
  502. not need to be updated, however.
  503. </p><p>
  504. We might want to insert data and have the server automatically
  505. locate the child table into which the row should be added. We
  506. could do this with a more complex trigger function, for example:
  507. </p><pre class="programlisting">
  508. CREATE OR REPLACE FUNCTION measurement_insert_trigger()
  509. RETURNS TRIGGER AS $$
  510. BEGIN
  511. IF ( NEW.logdate &gt;= DATE '2006-02-01' AND
  512. NEW.logdate &lt; DATE '2006-03-01' ) THEN
  513. INSERT INTO measurement_y2006m02 VALUES (NEW.*);
  514. ELSIF ( NEW.logdate &gt;= DATE '2006-03-01' AND
  515. NEW.logdate &lt; DATE '2006-04-01' ) THEN
  516. INSERT INTO measurement_y2006m03 VALUES (NEW.*);
  517. ...
  518. ELSIF ( NEW.logdate &gt;= DATE '2008-01-01' AND
  519. NEW.logdate &lt; DATE '2008-02-01' ) THEN
  520. INSERT INTO measurement_y2008m01 VALUES (NEW.*);
  521. ELSE
  522. RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!';
  523. END IF;
  524. RETURN NULL;
  525. END;
  526. $$
  527. LANGUAGE plpgsql;
  528. </pre><p>
  529. The trigger definition is the same as before.
  530. Note that each <code class="literal">IF</code> test must exactly match the
  531. <code class="literal">CHECK</code> constraint for its child table.
  532. </p><p>
  533. While this function is more complex than the single-month case,
  534. it doesn't need to be updated as often, since branches can be
  535. added in advance of being needed.
  536. </p><div class="note"><h3 class="title">Note</h3><p>
  537. In practice, it might be best to check the newest child first,
  538. if most inserts go into that child. For simplicity, we have
  539. shown the trigger's tests in the same order as in other parts
  540. of this example.
  541. </p></div><p>
  542. A different approach to redirecting inserts into the appropriate
  543. child table is to set up rules, instead of a trigger, on the
  544. master table. For example:
  545. </p><pre class="programlisting">
  546. CREATE RULE measurement_insert_y2006m02 AS
  547. ON INSERT TO measurement WHERE
  548. ( logdate &gt;= DATE '2006-02-01' AND logdate &lt; DATE '2006-03-01' )
  549. DO INSTEAD
  550. INSERT INTO measurement_y2006m02 VALUES (NEW.*);
  551. ...
  552. CREATE RULE measurement_insert_y2008m01 AS
  553. ON INSERT TO measurement WHERE
  554. ( logdate &gt;= DATE '2008-01-01' AND logdate &lt; DATE '2008-02-01' )
  555. DO INSTEAD
  556. INSERT INTO measurement_y2008m01 VALUES (NEW.*);
  557. </pre><p>
  558. A rule has significantly more overhead than a trigger, but the
  559. overhead is paid once per query rather than once per row, so this
  560. method might be advantageous for bulk-insert situations. In most
  561. cases, however, the trigger method will offer better performance.
  562. </p><p>
  563. Be aware that <code class="command">COPY</code> ignores rules. If you want to
  564. use <code class="command">COPY</code> to insert data, you'll need to copy into the
  565. correct child table rather than directly into the master. <code class="command">COPY</code>
  566. does fire triggers, so you can use it normally if you use the trigger
  567. approach.
  568. </p><p>
  569. Another disadvantage of the rule approach is that there is no simple
  570. way to force an error if the set of rules doesn't cover the insertion
  571. date; the data will silently go into the master table instead.
  572. </p></li><li class="listitem"><p>
  573. Ensure that the <a class="xref" href="runtime-config-query.html#GUC-CONSTRAINT-EXCLUSION">constraint_exclusion</a>
  574. configuration parameter is not disabled in
  575. <code class="filename">postgresql.conf</code>; otherwise
  576. child tables may be accessed unnecessarily.
  577. </p></li></ol></div><p>
  578. </p><p>
  579. As we can see, a complex table hierarchy could require a
  580. substantial amount of DDL. In the above example we would be creating
  581. a new child table each month, so it might be wise to write a script that
  582. generates the required DDL automatically.
  583. </p></div><div class="sect3" id="DDL-PARTITIONING-INHERITANCE-MAINTENANCE"><div class="titlepage"><div><div><h4 class="title">5.11.3.2. Maintenance for Inheritance Partitioning</h4></div></div></div><p>
  584. To remove old data quickly, simply drop the child table that is no longer
  585. necessary:
  586. </p><pre class="programlisting">
  587. DROP TABLE measurement_y2006m02;
  588. </pre><p>
  589. </p><p>
  590. To remove the child table from the inheritance hierarchy table but retain access to
  591. it as a table in its own right:
  592. </p><pre class="programlisting">
  593. ALTER TABLE measurement_y2006m02 NO INHERIT measurement;
  594. </pre><p>
  595. </p><p>
  596. To add a new child table to handle new data, create an empty child table
  597. just as the original children were created above:
  598. </p><pre class="programlisting">
  599. CREATE TABLE measurement_y2008m02 (
  600. CHECK ( logdate &gt;= DATE '2008-02-01' AND logdate &lt; DATE '2008-03-01' )
  601. ) INHERITS (measurement);
  602. </pre><p>
  603. Alternatively, one may want to create and populate the new child table
  604. before adding it to the table hierarchy. This could allow data to be
  605. loaded, checked, and transformed before being made visible to queries on
  606. the parent table.
  607. </p><pre class="programlisting">
  608. CREATE TABLE measurement_y2008m02
  609. (LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS);
  610. ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
  611. CHECK ( logdate &gt;= DATE '2008-02-01' AND logdate &lt; DATE '2008-03-01' );
  612. \copy measurement_y2008m02 from 'measurement_y2008m02'
  613. -- possibly some other data preparation work
  614. ALTER TABLE measurement_y2008m02 INHERIT measurement;
  615. </pre><p>
  616. </p></div><div class="sect3" id="DDL-PARTITIONING-INHERITANCE-CAVEATS"><div class="titlepage"><div><div><h4 class="title">5.11.3.3. Caveats</h4></div></div></div><p>
  617. The following caveats apply to partitioning implemented using
  618. inheritance:
  619. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  620. There is no automatic way to verify that all of the
  621. <code class="literal">CHECK</code> constraints are mutually
  622. exclusive. It is safer to create code that generates
  623. child tables and creates and/or modifies associated objects than
  624. to write each by hand.
  625. </p></li><li class="listitem"><p>
  626. Indexes and foreign key constraints apply to single tables and not
  627. to their inheritance children, hence they have some
  628. <a class="link" href="ddl-inherit.html#DDL-INHERIT-CAVEATS" title="5.10.1. Caveats">caveats</a> to be aware of.
  629. </p></li><li class="listitem"><p>
  630. The schemes shown here assume that the values of a row's key column(s)
  631. never change, or at least do not change enough to require it to move to another partition.
  632. An <code class="command">UPDATE</code> that attempts
  633. to do that will fail because of the <code class="literal">CHECK</code> constraints.
  634. If you need to handle such cases, you can put suitable update triggers
  635. on the child tables, but it makes management of the structure
  636. much more complicated.
  637. </p></li><li class="listitem"><p>
  638. If you are using manual <code class="command">VACUUM</code> or
  639. <code class="command">ANALYZE</code> commands, don't forget that
  640. you need to run them on each child table individually. A command like:
  641. </p><pre class="programlisting">
  642. ANALYZE measurement;
  643. </pre><p>
  644. will only process the master table.
  645. </p></li><li class="listitem"><p>
  646. <code class="command">INSERT</code> statements with <code class="literal">ON CONFLICT</code>
  647. clauses are unlikely to work as expected, as the <code class="literal">ON CONFLICT</code>
  648. action is only taken in case of unique violations on the specified
  649. target relation, not its child relations.
  650. </p></li><li class="listitem"><p>
  651. Triggers or rules will be needed to route rows to the desired
  652. child table, unless the application is explicitly aware of the
  653. partitioning scheme. Triggers may be complicated to write, and will
  654. be much slower than the tuple routing performed internally by
  655. declarative partitioning.
  656. </p></li></ul></div><p>
  657. </p></div></div><div class="sect2" id="DDL-PARTITION-PRUNING"><div class="titlepage"><div><div><h3 class="title">5.11.4. Partition Pruning</h3></div></div></div><a id="id-1.5.4.13.9.2" class="indexterm"></a><p>
  658. <em class="firstterm">Partition pruning</em> is a query optimization technique
  659. that improves performance for declaratively partitioned tables.
  660. As an example:
  661. </p><pre class="programlisting">
  662. SET enable_partition_pruning = on; -- the default
  663. SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
  664. </pre><p>
  665. Without partition pruning, the above query would scan each of the
  666. partitions of the <code class="structname">measurement</code> table. With
  667. partition pruning enabled, the planner will examine the definition
  668. of each partition and prove that the partition need not
  669. be scanned because it could not contain any rows meeting the query's
  670. <code class="literal">WHERE</code> clause. When the planner can prove this, it
  671. excludes (<em class="firstterm">prunes</em>) the partition from the query
  672. plan.
  673. </p><p>
  674. By using the EXPLAIN command and the <a class="xref" href="runtime-config-query.html#GUC-ENABLE-PARTITION-PRUNING">enable_partition_pruning</a> configuration parameter, it's
  675. possible to show the difference between a plan for which partitions have
  676. been pruned and one for which they have not. A typical unoptimized
  677. plan for this type of table setup is:
  678. </p><pre class="programlisting">
  679. SET enable_partition_pruning = off;
  680. EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
  681. QUERY PLAN
  682. -----------------------------------------------------------------------------------
  683. Aggregate (cost=188.76..188.77 rows=1 width=8)
  684. -&gt; Append (cost=0.00..181.05 rows=3085 width=0)
  685. -&gt; Seq Scan on measurement_y2006m02 (cost=0.00..33.12 rows=617 width=0)
  686. Filter: (logdate &gt;= '2008-01-01'::date)
  687. -&gt; Seq Scan on measurement_y2006m03 (cost=0.00..33.12 rows=617 width=0)
  688. Filter: (logdate &gt;= '2008-01-01'::date)
  689. ...
  690. -&gt; Seq Scan on measurement_y2007m11 (cost=0.00..33.12 rows=617 width=0)
  691. Filter: (logdate &gt;= '2008-01-01'::date)
  692. -&gt; Seq Scan on measurement_y2007m12 (cost=0.00..33.12 rows=617 width=0)
  693. Filter: (logdate &gt;= '2008-01-01'::date)
  694. -&gt; Seq Scan on measurement_y2008m01 (cost=0.00..33.12 rows=617 width=0)
  695. Filter: (logdate &gt;= '2008-01-01'::date)
  696. </pre><p>
  697. Some or all of the partitions might use index scans instead of
  698. full-table sequential scans, but the point here is that there
  699. is no need to scan the older partitions at all to answer this query.
  700. When we enable partition pruning, we get a significantly
  701. cheaper plan that will deliver the same answer:
  702. </p><pre class="programlisting">
  703. SET enable_partition_pruning = on;
  704. EXPLAIN SELECT count(*) FROM measurement WHERE logdate &gt;= DATE '2008-01-01';
  705. QUERY PLAN
  706. -----------------------------------------------------------------------------------
  707. Aggregate (cost=37.75..37.76 rows=1 width=8)
  708. -&gt; Seq Scan on measurement_y2008m01 (cost=0.00..33.12 rows=617 width=0)
  709. Filter: (logdate &gt;= '2008-01-01'::date)
  710. </pre><p>
  711. </p><p>
  712. Note that partition pruning is driven only by the constraints defined
  713. implicitly by the partition keys, not by the presence of indexes.
  714. Therefore it isn't necessary to define indexes on the key columns.
  715. Whether an index needs to be created for a given partition depends on
  716. whether you expect that queries that scan the partition will
  717. generally scan a large part of the partition or just a small part.
  718. An index will be helpful in the latter case but not the former.
  719. </p><p>
  720. Partition pruning can be performed not only during the planning of a
  721. given query, but also during its execution. This is useful as it can
  722. allow more partitions to be pruned when clauses contain expressions
  723. whose values are not known at query planning time, for example,
  724. parameters defined in a <code class="command">PREPARE</code> statement, using a
  725. value obtained from a subquery, or using a parameterized value on the
  726. inner side of a nested loop join. Partition pruning during execution
  727. can be performed at any of the following times:
  728. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  729. During initialization of the query plan. Partition pruning can be
  730. performed here for parameter values which are known during the
  731. initialization phase of execution. Partitions which are pruned
  732. during this stage will not show up in the query's
  733. <code class="command">EXPLAIN</code> or <code class="command">EXPLAIN ANALYZE</code>.
  734. It is possible to determine the number of partitions which were
  735. removed during this phase by observing the
  736. <span class="quote">“<span class="quote">Subplans Removed</span>”</span> property in the
  737. <code class="command">EXPLAIN</code> output.
  738. </p></li><li class="listitem"><p>
  739. During actual execution of the query plan. Partition pruning may
  740. also be performed here to remove partitions using values which are
  741. only known during actual query execution. This includes values
  742. from subqueries and values from execution-time parameters such as
  743. those from parameterized nested loop joins. Since the value of
  744. these parameters may change many times during the execution of the
  745. query, partition pruning is performed whenever one of the
  746. execution parameters being used by partition pruning changes.
  747. Determining if partitions were pruned during this phase requires
  748. careful inspection of the <code class="literal">loops</code> property in
  749. the <code class="command">EXPLAIN ANALYZE</code> output. Subplans
  750. corresponding to different partitions may have different values
  751. for it depending on how many times each of them was pruned during
  752. execution. Some may be shown as <code class="literal">(never executed)</code>
  753. if they were pruned every time.
  754. </p></li></ul></div><p>
  755. </p><p>
  756. Partition pruning can be disabled using the
  757. <a class="xref" href="runtime-config-query.html#GUC-ENABLE-PARTITION-PRUNING">enable_partition_pruning</a> setting.
  758. </p><div class="note"><h3 class="title">Note</h3><p>
  759. Execution-time partition pruning currently only occurs for the
  760. <code class="literal">Append</code> and <code class="literal">MergeAppend</code> node types.
  761. It is not yet implemented for the <code class="literal">ModifyTable</code> node
  762. type, but that is likely to be changed in a future release of
  763. <span class="productname">PostgreSQL</span>.
  764. </p></div></div><div class="sect2" id="DDL-PARTITIONING-CONSTRAINT-EXCLUSION"><div class="titlepage"><div><div><h3 class="title">5.11.5. Partitioning and Constraint Exclusion</h3></div></div></div><a id="id-1.5.4.13.10.2" class="indexterm"></a><p>
  765. <em class="firstterm">Constraint exclusion</em> is a query optimization
  766. technique similar to partition pruning. While it is primarily used
  767. for partitioning implemented using the legacy inheritance method, it can be
  768. used for other purposes, including with declarative partitioning.
  769. </p><p>
  770. Constraint exclusion works in a very similar way to partition
  771. pruning, except that it uses each table's <code class="literal">CHECK</code>
  772. constraints — which gives it its name — whereas partition
  773. pruning uses the table's partition bounds, which exist only in the
  774. case of declarative partitioning. Another difference is that
  775. constraint exclusion is only applied at plan time; there is no attempt
  776. to remove partitions at execution time.
  777. </p><p>
  778. The fact that constraint exclusion uses <code class="literal">CHECK</code>
  779. constraints, which makes it slow compared to partition pruning, can
  780. sometimes be used as an advantage: because constraints can be defined
  781. even on declaratively-partitioned tables, in addition to their internal
  782. partition bounds, constraint exclusion may be able
  783. to elide additional partitions from the query plan.
  784. </p><p>
  785. The default (and recommended) setting of
  786. <a class="xref" href="runtime-config-query.html#GUC-CONSTRAINT-EXCLUSION">constraint_exclusion</a> is neither
  787. <code class="literal">on</code> nor <code class="literal">off</code>, but an intermediate setting
  788. called <code class="literal">partition</code>, which causes the technique to be
  789. applied only to queries that are likely to be working on inheritance partitioned
  790. tables. The <code class="literal">on</code> setting causes the planner to examine
  791. <code class="literal">CHECK</code> constraints in all queries, even simple ones that
  792. are unlikely to benefit.
  793. </p><p>
  794. The following caveats apply to constraint exclusion:
  795. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  796. Constraint exclusion is only applied during query planning, unlike
  797. partition pruning, which can also be applied during query execution.
  798. </p></li><li class="listitem"><p>
  799. Constraint exclusion only works when the query's <code class="literal">WHERE</code>
  800. clause contains constants (or externally supplied parameters).
  801. For example, a comparison against a non-immutable function such as
  802. <code class="function">CURRENT_TIMESTAMP</code> cannot be optimized, since the
  803. planner cannot know which child table the function's value might fall
  804. into at run time.
  805. </p></li><li class="listitem"><p>
  806. Keep the partitioning constraints simple, else the planner may not be
  807. able to prove that child tables might not need to be visited. Use simple
  808. equality conditions for list partitioning, or simple
  809. range tests for range partitioning, as illustrated in the preceding
  810. examples. A good rule of thumb is that partitioning constraints should
  811. contain only comparisons of the partitioning column(s) to constants
  812. using B-tree-indexable operators, because only B-tree-indexable
  813. column(s) are allowed in the partition key.
  814. </p></li><li class="listitem"><p>
  815. All constraints on all children of the parent table are examined
  816. during constraint exclusion, so large numbers of children are likely
  817. to increase query planning time considerably. So the legacy
  818. inheritance based partitioning will work well with up to perhaps a
  819. hundred child tables; don't try to use many thousands of children.
  820. </p></li></ul></div><p>
  821. </p></div><div class="sect2" id="DDL-PARTITIONING-DECLARATIVE-BEST-PRACTICES"><div class="titlepage"><div><div><h3 class="title">5.11.6. Declarative Partitioning Best Practices</h3></div></div></div><p>
  822. The choice of how to partition a table should be made carefully as the
  823. performance of query planning and execution can be negatively affected by
  824. poor design.
  825. </p><p>
  826. One of the most critical design decisions will be the column or columns
  827. by which you partition your data. Often the best choice will be to
  828. partition by the column or set of columns which most commonly appear in
  829. <code class="literal">WHERE</code> clauses of queries being executed on the
  830. partitioned table. <code class="literal">WHERE</code> clause items that match and
  831. are compatible with the partition key can be used to prune unneeded
  832. partitions. However, you may be forced into making other decisions by
  833. requirements for the <code class="literal">PRIMARY KEY</code> or a
  834. <code class="literal">UNIQUE</code> constraint. Removal of unwanted data is also a
  835. factor to consider when planning your partitioning strategy. An entire
  836. partition can be detached fairly quickly, so it may be beneficial to
  837. design the partition strategy in such a way that all data to be removed
  838. at once is located in a single partition.
  839. </p><p>
  840. Choosing the target number of partitions that the table should be divided
  841. into is also a critical decision to make. Not having enough partitions
  842. may mean that indexes remain too large and that data locality remains poor
  843. which could result in low cache hit ratios. However, dividing the table
  844. into too many partitions can also cause issues. Too many partitions can
  845. mean longer query planning times and higher memory consumption during both
  846. query planning and execution. When choosing how to partition your table,
  847. it's also important to consider what changes may occur in the future. For
  848. example, if you choose to have one partition per customer and you
  849. currently have a small number of large customers, consider the
  850. implications if in several years you instead find yourself with a large
  851. number of small customers. In this case, it may be better to choose to
  852. partition by <code class="literal">HASH</code> and choose a reasonable number of
  853. partitions rather than trying to partition by <code class="literal">LIST</code> and
  854. hoping that the number of customers does not increase beyond what it is
  855. practical to partition the data by.
  856. </p><p>
  857. Sub-partitioning can be useful to further divide partitions that are
  858. expected to become larger than other partitions, although excessive
  859. sub-partitioning can easily lead to large numbers of partitions and can
  860. cause the same problems mentioned in the preceding paragraph.
  861. </p><p>
  862. It is also important to consider the overhead of partitioning during
  863. query planning and execution. The query planner is generally able to
  864. handle partition hierarchies with up to a few thousand partitions fairly
  865. well, provided that typical queries allow the query planner to prune all
  866. but a small number of partitions. Planning times become longer and memory
  867. consumption becomes higher when more partitions remain after the planner
  868. performs partition pruning. This is particularly true for the
  869. <code class="command">UPDATE</code> and <code class="command">DELETE</code> commands. Another
  870. reason to be concerned about having a large number of partitions is that
  871. the server's memory consumption may grow significantly over a period of
  872. time, especially if many sessions touch large numbers of partitions.
  873. That's because each partition requires its metadata to be loaded into the
  874. local memory of each session that touches it.
  875. </p><p>
  876. With data warehouse type workloads, it can make sense to use a larger
  877. number of partitions than with an <acronym class="acronym">OLTP</acronym> type workload.
  878. Generally, in data warehouses, query planning time is less of a concern as
  879. the majority of processing time is spent during query execution. With
  880. either of these two types of workload, it is important to make the right
  881. decisions early, as re-partitioning large quantities of data can be
  882. painfully slow. Simulations of the intended workload are often beneficial
  883. for optimizing the partitioning strategy. Never assume that more
  884. partitions are better than fewer partitions and vice-versa.
  885. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ddl-inherit.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ddl.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="ddl-foreign-data.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">5.10. Inheritance </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 5.12. Foreign Data</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1