gooderp18绿色标准版
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

645 lines
30KB

  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>8.15. Arrays</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="datatype-json.html" title="8.14. JSON Types" /><link rel="next" href="rowtypes.html" title="8.16. Composite Types" /></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">8.15. Arrays</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="datatype-json.html" title="8.14. JSON Types">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="datatype.html" title="Chapter 8. Data Types">Up</a></td><th width="60%" align="center">Chapter 8. Data Types</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="rowtypes.html" title="8.16. Composite Types">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="ARRAYS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">8.15. Arrays</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="arrays.html#ARRAYS-DECLARATION">8.15.1. Declaration of Array Types</a></span></dt><dt><span class="sect2"><a href="arrays.html#ARRAYS-INPUT">8.15.2. Array Value Input</a></span></dt><dt><span class="sect2"><a href="arrays.html#ARRAYS-ACCESSING">8.15.3. Accessing Arrays</a></span></dt><dt><span class="sect2"><a href="arrays.html#ARRAYS-MODIFYING">8.15.4. Modifying Arrays</a></span></dt><dt><span class="sect2"><a href="arrays.html#ARRAYS-SEARCHING">8.15.5. Searching in Arrays</a></span></dt><dt><span class="sect2"><a href="arrays.html#ARRAYS-IO">8.15.6. Array Input and Output Syntax</a></span></dt></dl></div><a id="id-1.5.7.23.2" class="indexterm"></a><p>
  3. <span class="productname">PostgreSQL</span> allows columns of a table to be
  4. defined as variable-length multidimensional arrays. Arrays of any
  5. built-in or user-defined base type, enum type, composite type, range type,
  6. or domain can be created.
  7. </p><div class="sect2" id="ARRAYS-DECLARATION"><div class="titlepage"><div><div><h3 class="title">8.15.1. Declaration of Array Types</h3></div></div></div><a id="id-1.5.7.23.4.2" class="indexterm"></a><p>
  8. To illustrate the use of array types, we create this table:
  9. </p><pre class="programlisting">
  10. CREATE TABLE sal_emp (
  11. name text,
  12. pay_by_quarter integer[],
  13. schedule text[][]
  14. );
  15. </pre><p>
  16. As shown, an array data type is named by appending square brackets
  17. (<code class="literal">[]</code>) to the data type name of the array elements. The
  18. above command will create a table named
  19. <code class="structname">sal_emp</code> with a column of type
  20. <code class="type">text</code> (<code class="structfield">name</code>), a
  21. one-dimensional array of type <code class="type">integer</code>
  22. (<code class="structfield">pay_by_quarter</code>), which represents the
  23. employee's salary by quarter, and a two-dimensional array of
  24. <code class="type">text</code> (<code class="structfield">schedule</code>), which
  25. represents the employee's weekly schedule.
  26. </p><p>
  27. The syntax for <code class="command">CREATE TABLE</code> allows the exact size of
  28. arrays to be specified, for example:
  29. </p><pre class="programlisting">
  30. CREATE TABLE tictactoe (
  31. squares integer[3][3]
  32. );
  33. </pre><p>
  34. However, the current implementation ignores any supplied array size
  35. limits, i.e., the behavior is the same as for arrays of unspecified
  36. length.
  37. </p><p>
  38. The current implementation does not enforce the declared
  39. number of dimensions either. Arrays of a particular element type are
  40. all considered to be of the same type, regardless of size or number
  41. of dimensions. So, declaring the array size or number of dimensions in
  42. <code class="command">CREATE TABLE</code> is simply documentation; it does not
  43. affect run-time behavior.
  44. </p><p>
  45. An alternative syntax, which conforms to the SQL standard by using
  46. the keyword <code class="literal">ARRAY</code>, can be used for one-dimensional arrays.
  47. <code class="structfield">pay_by_quarter</code> could have been defined
  48. as:
  49. </p><pre class="programlisting">
  50. pay_by_quarter integer ARRAY[4],
  51. </pre><p>
  52. Or, if no array size is to be specified:
  53. </p><pre class="programlisting">
  54. pay_by_quarter integer ARRAY,
  55. </pre><p>
  56. As before, however, <span class="productname">PostgreSQL</span> does not enforce the
  57. size restriction in any case.
  58. </p></div><div class="sect2" id="ARRAYS-INPUT"><div class="titlepage"><div><div><h3 class="title">8.15.2. Array Value Input</h3></div></div></div><a id="id-1.5.7.23.5.2" class="indexterm"></a><p>
  59. To write an array value as a literal constant, enclose the element
  60. values within curly braces and separate them by commas. (If you
  61. know C, this is not unlike the C syntax for initializing
  62. structures.) You can put double quotes around any element value,
  63. and must do so if it contains commas or curly braces. (More
  64. details appear below.) Thus, the general format of an array
  65. constant is the following:
  66. </p><pre class="synopsis">
  67. '{ <em class="replaceable"><code>val1</code></em> <em class="replaceable"><code>delim</code></em> <em class="replaceable"><code>val2</code></em> <em class="replaceable"><code>delim</code></em> ... }'
  68. </pre><p>
  69. where <em class="replaceable"><code>delim</code></em> is the delimiter character
  70. for the type, as recorded in its <code class="literal">pg_type</code> entry.
  71. Among the standard data types provided in the
  72. <span class="productname">PostgreSQL</span> distribution, all use a comma
  73. (<code class="literal">,</code>), except for type <code class="type">box</code> which uses a semicolon
  74. (<code class="literal">;</code>). Each <em class="replaceable"><code>val</code></em> is
  75. either a constant of the array element type, or a subarray. An example
  76. of an array constant is:
  77. </p><pre class="programlisting">
  78. '{{1,2,3},{4,5,6},{7,8,9}}'
  79. </pre><p>
  80. This constant is a two-dimensional, 3-by-3 array consisting of
  81. three subarrays of integers.
  82. </p><p>
  83. To set an element of an array constant to NULL, write <code class="literal">NULL</code>
  84. for the element value. (Any upper- or lower-case variant of
  85. <code class="literal">NULL</code> will do.) If you want an actual string value
  86. <span class="quote">“<span class="quote">NULL</span>”</span>, you must put double quotes around it.
  87. </p><p>
  88. (These kinds of array constants are actually only a special case of
  89. the generic type constants discussed in <a class="xref" href="sql-syntax-lexical.html#SQL-SYNTAX-CONSTANTS-GENERIC" title="4.1.2.7. Constants of Other Types">Section 4.1.2.7</a>. The constant is initially
  90. treated as a string and passed to the array input conversion
  91. routine. An explicit type specification might be necessary.)
  92. </p><p>
  93. Now we can show some <code class="command">INSERT</code> statements:
  94. </p><pre class="programlisting">
  95. INSERT INTO sal_emp
  96. VALUES ('Bill',
  97. '{10000, 10000, 10000, 10000}',
  98. '{{"meeting", "lunch"}, {"training", "presentation"}}');
  99. INSERT INTO sal_emp
  100. VALUES ('Carol',
  101. '{20000, 25000, 25000, 25000}',
  102. '{{"breakfast", "consulting"}, {"meeting", "lunch"}}');
  103. </pre><p>
  104. </p><p>
  105. The result of the previous two inserts looks like this:
  106. </p><pre class="programlisting">
  107. SELECT * FROM sal_emp;
  108. name | pay_by_quarter | schedule
  109. -------+---------------------------+-------------------------------------------
  110. Bill | {10000,10000,10000,10000} | {{meeting,lunch},{training,presentation}}
  111. Carol | {20000,25000,25000,25000} | {{breakfast,consulting},{meeting,lunch}}
  112. (2 rows)
  113. </pre><p>
  114. </p><p>
  115. Multidimensional arrays must have matching extents for each
  116. dimension. A mismatch causes an error, for example:
  117. </p><pre class="programlisting">
  118. INSERT INTO sal_emp
  119. VALUES ('Bill',
  120. '{10000, 10000, 10000, 10000}',
  121. '{{"meeting", "lunch"}, {"meeting"}}');
  122. ERROR: multidimensional arrays must have array expressions with matching dimensions
  123. </pre><p>
  124. </p><p>
  125. The <code class="literal">ARRAY</code> constructor syntax can also be used:
  126. </p><pre class="programlisting">
  127. INSERT INTO sal_emp
  128. VALUES ('Bill',
  129. ARRAY[10000, 10000, 10000, 10000],
  130. ARRAY[['meeting', 'lunch'], ['training', 'presentation']]);
  131. INSERT INTO sal_emp
  132. VALUES ('Carol',
  133. ARRAY[20000, 25000, 25000, 25000],
  134. ARRAY[['breakfast', 'consulting'], ['meeting', 'lunch']]);
  135. </pre><p>
  136. Notice that the array elements are ordinary SQL constants or
  137. expressions; for instance, string literals are single quoted, instead of
  138. double quoted as they would be in an array literal. The <code class="literal">ARRAY</code>
  139. constructor syntax is discussed in more detail in
  140. <a class="xref" href="sql-expressions.html#SQL-SYNTAX-ARRAY-CONSTRUCTORS" title="4.2.12. Array Constructors">Section 4.2.12</a>.
  141. </p></div><div class="sect2" id="ARRAYS-ACCESSING"><div class="titlepage"><div><div><h3 class="title">8.15.3. Accessing Arrays</h3></div></div></div><a id="id-1.5.7.23.6.2" class="indexterm"></a><p>
  142. Now, we can run some queries on the table.
  143. First, we show how to access a single element of an array.
  144. This query retrieves the names of the employees whose pay changed in
  145. the second quarter:
  146. </p><pre class="programlisting">
  147. SELECT name FROM sal_emp WHERE pay_by_quarter[1] &lt;&gt; pay_by_quarter[2];
  148. name
  149. -------
  150. Carol
  151. (1 row)
  152. </pre><p>
  153. The array subscript numbers are written within square brackets.
  154. By default <span class="productname">PostgreSQL</span> uses a
  155. one-based numbering convention for arrays, that is,
  156. an array of <em class="replaceable"><code>n</code></em> elements starts with <code class="literal">array[1]</code> and
  157. ends with <code class="literal">array[<em class="replaceable"><code>n</code></em>]</code>.
  158. </p><p>
  159. This query retrieves the third quarter pay of all employees:
  160. </p><pre class="programlisting">
  161. SELECT pay_by_quarter[3] FROM sal_emp;
  162. pay_by_quarter
  163. ----------------
  164. 10000
  165. 25000
  166. (2 rows)
  167. </pre><p>
  168. </p><p>
  169. We can also access arbitrary rectangular slices of an array, or
  170. subarrays. An array slice is denoted by writing
  171. <code class="literal"><em class="replaceable"><code>lower-bound</code></em>:<em class="replaceable"><code>upper-bound</code></em></code>
  172. for one or more array dimensions. For example, this query retrieves the first
  173. item on Bill's schedule for the first two days of the week:
  174. </p><pre class="programlisting">
  175. SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';
  176. schedule
  177. ------------------------
  178. {{meeting},{training}}
  179. (1 row)
  180. </pre><p>
  181. If any dimension is written as a slice, i.e., contains a colon, then all
  182. dimensions are treated as slices. Any dimension that has only a single
  183. number (no colon) is treated as being from 1
  184. to the number specified. For example, <code class="literal">[2]</code> is treated as
  185. <code class="literal">[1:2]</code>, as in this example:
  186. </p><pre class="programlisting">
  187. SELECT schedule[1:2][2] FROM sal_emp WHERE name = 'Bill';
  188. schedule
  189. -------------------------------------------
  190. {{meeting,lunch},{training,presentation}}
  191. (1 row)
  192. </pre><p>
  193. To avoid confusion with the non-slice case, it's best to use slice syntax
  194. for all dimensions, e.g., <code class="literal">[1:2][1:1]</code>, not <code class="literal">[2][1:1]</code>.
  195. </p><p>
  196. It is possible to omit the <em class="replaceable"><code>lower-bound</code></em> and/or
  197. <em class="replaceable"><code>upper-bound</code></em> of a slice specifier; the missing
  198. bound is replaced by the lower or upper limit of the array's subscripts.
  199. For example:
  200. </p><pre class="programlisting">
  201. SELECT schedule[:2][2:] FROM sal_emp WHERE name = 'Bill';
  202. schedule
  203. ------------------------
  204. {{lunch},{presentation}}
  205. (1 row)
  206. SELECT schedule[:][1:1] FROM sal_emp WHERE name = 'Bill';
  207. schedule
  208. ------------------------
  209. {{meeting},{training}}
  210. (1 row)
  211. </pre><p>
  212. </p><p>
  213. An array subscript expression will return null if either the array itself or
  214. any of the subscript expressions are null. Also, null is returned if a
  215. subscript is outside the array bounds (this case does not raise an error).
  216. For example, if <code class="literal">schedule</code>
  217. currently has the dimensions <code class="literal">[1:3][1:2]</code> then referencing
  218. <code class="literal">schedule[3][3]</code> yields NULL. Similarly, an array reference
  219. with the wrong number of subscripts yields a null rather than an error.
  220. </p><p>
  221. An array slice expression likewise yields null if the array itself or
  222. any of the subscript expressions are null. However, in other
  223. cases such as selecting an array slice that
  224. is completely outside the current array bounds, a slice expression
  225. yields an empty (zero-dimensional) array instead of null. (This
  226. does not match non-slice behavior and is done for historical reasons.)
  227. If the requested slice partially overlaps the array bounds, then it
  228. is silently reduced to just the overlapping region instead of
  229. returning null.
  230. </p><p>
  231. The current dimensions of any array value can be retrieved with the
  232. <code class="function">array_dims</code> function:
  233. </p><pre class="programlisting">
  234. SELECT array_dims(schedule) FROM sal_emp WHERE name = 'Carol';
  235. array_dims
  236. ------------
  237. [1:2][1:2]
  238. (1 row)
  239. </pre><p>
  240. <code class="function">array_dims</code> produces a <code class="type">text</code> result,
  241. which is convenient for people to read but perhaps inconvenient
  242. for programs. Dimensions can also be retrieved with
  243. <code class="function">array_upper</code> and <code class="function">array_lower</code>,
  244. which return the upper and lower bound of a
  245. specified array dimension, respectively:
  246. </p><pre class="programlisting">
  247. SELECT array_upper(schedule, 1) FROM sal_emp WHERE name = 'Carol';
  248. array_upper
  249. -------------
  250. 2
  251. (1 row)
  252. </pre><p>
  253. <code class="function">array_length</code> will return the length of a specified
  254. array dimension:
  255. </p><pre class="programlisting">
  256. SELECT array_length(schedule, 1) FROM sal_emp WHERE name = 'Carol';
  257. array_length
  258. --------------
  259. 2
  260. (1 row)
  261. </pre><p>
  262. <code class="function">cardinality</code> returns the total number of elements in an
  263. array across all dimensions. It is effectively the number of rows a call to
  264. <code class="function">unnest</code> would yield:
  265. </p><pre class="programlisting">
  266. SELECT cardinality(schedule) FROM sal_emp WHERE name = 'Carol';
  267. cardinality
  268. -------------
  269. 4
  270. (1 row)
  271. </pre><p>
  272. </p></div><div class="sect2" id="ARRAYS-MODIFYING"><div class="titlepage"><div><div><h3 class="title">8.15.4. Modifying Arrays</h3></div></div></div><a id="id-1.5.7.23.7.2" class="indexterm"></a><p>
  273. An array value can be replaced completely:
  274. </p><pre class="programlisting">
  275. UPDATE sal_emp SET pay_by_quarter = '{25000,25000,27000,27000}'
  276. WHERE name = 'Carol';
  277. </pre><p>
  278. or using the <code class="literal">ARRAY</code> expression syntax:
  279. </p><pre class="programlisting">
  280. UPDATE sal_emp SET pay_by_quarter = ARRAY[25000,25000,27000,27000]
  281. WHERE name = 'Carol';
  282. </pre><p>
  283. An array can also be updated at a single element:
  284. </p><pre class="programlisting">
  285. UPDATE sal_emp SET pay_by_quarter[4] = 15000
  286. WHERE name = 'Bill';
  287. </pre><p>
  288. or updated in a slice:
  289. </p><pre class="programlisting">
  290. UPDATE sal_emp SET pay_by_quarter[1:2] = '{27000,27000}'
  291. WHERE name = 'Carol';
  292. </pre><p>
  293. The slice syntaxes with omitted <em class="replaceable"><code>lower-bound</code></em> and/or
  294. <em class="replaceable"><code>upper-bound</code></em> can be used too, but only when
  295. updating an array value that is not NULL or zero-dimensional (otherwise,
  296. there is no existing subscript limit to substitute).
  297. </p><p>
  298. A stored array value can be enlarged by assigning to elements not already
  299. present. Any positions between those previously present and the newly
  300. assigned elements will be filled with nulls. For example, if array
  301. <code class="literal">myarray</code> currently has 4 elements, it will have six
  302. elements after an update that assigns to <code class="literal">myarray[6]</code>;
  303. <code class="literal">myarray[5]</code> will contain null.
  304. Currently, enlargement in this fashion is only allowed for one-dimensional
  305. arrays, not multidimensional arrays.
  306. </p><p>
  307. Subscripted assignment allows creation of arrays that do not use one-based
  308. subscripts. For example one might assign to <code class="literal">myarray[-2:7]</code> to
  309. create an array with subscript values from -2 to 7.
  310. </p><p>
  311. New array values can also be constructed using the concatenation operator,
  312. <code class="literal">||</code>:
  313. </p><pre class="programlisting">
  314. SELECT ARRAY[1,2] || ARRAY[3,4];
  315. ?column?
  316. -----------
  317. {1,2,3,4}
  318. (1 row)
  319. SELECT ARRAY[5,6] || ARRAY[[1,2],[3,4]];
  320. ?column?
  321. ---------------------
  322. {{5,6},{1,2},{3,4}}
  323. (1 row)
  324. </pre><p>
  325. </p><p>
  326. The concatenation operator allows a single element to be pushed onto the
  327. beginning or end of a one-dimensional array. It also accepts two
  328. <em class="replaceable"><code>N</code></em>-dimensional arrays, or an <em class="replaceable"><code>N</code></em>-dimensional
  329. and an <em class="replaceable"><code>N+1</code></em>-dimensional array.
  330. </p><p>
  331. When a single element is pushed onto either the beginning or end of a
  332. one-dimensional array, the result is an array with the same lower bound
  333. subscript as the array operand. For example:
  334. </p><pre class="programlisting">
  335. SELECT array_dims(1 || '[0:1]={2,3}'::int[]);
  336. array_dims
  337. ------------
  338. [0:2]
  339. (1 row)
  340. SELECT array_dims(ARRAY[1,2] || 3);
  341. array_dims
  342. ------------
  343. [1:3]
  344. (1 row)
  345. </pre><p>
  346. </p><p>
  347. When two arrays with an equal number of dimensions are concatenated, the
  348. result retains the lower bound subscript of the left-hand operand's outer
  349. dimension. The result is an array comprising every element of the left-hand
  350. operand followed by every element of the right-hand operand. For example:
  351. </p><pre class="programlisting">
  352. SELECT array_dims(ARRAY[1,2] || ARRAY[3,4,5]);
  353. array_dims
  354. ------------
  355. [1:5]
  356. (1 row)
  357. SELECT array_dims(ARRAY[[1,2],[3,4]] || ARRAY[[5,6],[7,8],[9,0]]);
  358. array_dims
  359. ------------
  360. [1:5][1:2]
  361. (1 row)
  362. </pre><p>
  363. </p><p>
  364. When an <em class="replaceable"><code>N</code></em>-dimensional array is pushed onto the beginning
  365. or end of an <em class="replaceable"><code>N+1</code></em>-dimensional array, the result is
  366. analogous to the element-array case above. Each <em class="replaceable"><code>N</code></em>-dimensional
  367. sub-array is essentially an element of the <em class="replaceable"><code>N+1</code></em>-dimensional
  368. array's outer dimension. For example:
  369. </p><pre class="programlisting">
  370. SELECT array_dims(ARRAY[1,2] || ARRAY[[3,4],[5,6]]);
  371. array_dims
  372. ------------
  373. [1:3][1:2]
  374. (1 row)
  375. </pre><p>
  376. </p><p>
  377. An array can also be constructed by using the functions
  378. <code class="function">array_prepend</code>, <code class="function">array_append</code>,
  379. or <code class="function">array_cat</code>. The first two only support one-dimensional
  380. arrays, but <code class="function">array_cat</code> supports multidimensional arrays.
  381. Some examples:
  382. </p><pre class="programlisting">
  383. SELECT array_prepend(1, ARRAY[2,3]);
  384. array_prepend
  385. ---------------
  386. {1,2,3}
  387. (1 row)
  388. SELECT array_append(ARRAY[1,2], 3);
  389. array_append
  390. --------------
  391. {1,2,3}
  392. (1 row)
  393. SELECT array_cat(ARRAY[1,2], ARRAY[3,4]);
  394. array_cat
  395. -----------
  396. {1,2,3,4}
  397. (1 row)
  398. SELECT array_cat(ARRAY[[1,2],[3,4]], ARRAY[5,6]);
  399. array_cat
  400. ---------------------
  401. {{1,2},{3,4},{5,6}}
  402. (1 row)
  403. SELECT array_cat(ARRAY[5,6], ARRAY[[1,2],[3,4]]);
  404. array_cat
  405. ---------------------
  406. {{5,6},{1,2},{3,4}}
  407. </pre><p>
  408. </p><p>
  409. In simple cases, the concatenation operator discussed above is preferred
  410. over direct use of these functions. However, because the concatenation
  411. operator is overloaded to serve all three cases, there are situations where
  412. use of one of the functions is helpful to avoid ambiguity. For example
  413. consider:
  414. </p><pre class="programlisting">
  415. SELECT ARRAY[1, 2] || '{3, 4}'; -- the untyped literal is taken as an array
  416. ?column?
  417. -----------
  418. {1,2,3,4}
  419. SELECT ARRAY[1, 2] || '7'; -- so is this one
  420. ERROR: malformed array literal: "7"
  421. SELECT ARRAY[1, 2] || NULL; -- so is an undecorated NULL
  422. ?column?
  423. ----------
  424. {1,2}
  425. (1 row)
  426. SELECT array_append(ARRAY[1, 2], NULL); -- this might have been meant
  427. array_append
  428. --------------
  429. {1,2,NULL}
  430. </pre><p>
  431. In the examples above, the parser sees an integer array on one side of the
  432. concatenation operator, and a constant of undetermined type on the other.
  433. The heuristic it uses to resolve the constant's type is to assume it's of
  434. the same type as the operator's other input — in this case,
  435. integer array. So the concatenation operator is presumed to
  436. represent <code class="function">array_cat</code>, not <code class="function">array_append</code>. When
  437. that's the wrong choice, it could be fixed by casting the constant to the
  438. array's element type; but explicit use of <code class="function">array_append</code> might
  439. be a preferable solution.
  440. </p></div><div class="sect2" id="ARRAYS-SEARCHING"><div class="titlepage"><div><div><h3 class="title">8.15.5. Searching in Arrays</h3></div></div></div><a id="id-1.5.7.23.8.2" class="indexterm"></a><p>
  441. To search for a value in an array, each value must be checked.
  442. This can be done manually, if you know the size of the array.
  443. For example:
  444. </p><pre class="programlisting">
  445. SELECT * FROM sal_emp WHERE pay_by_quarter[1] = 10000 OR
  446. pay_by_quarter[2] = 10000 OR
  447. pay_by_quarter[3] = 10000 OR
  448. pay_by_quarter[4] = 10000;
  449. </pre><p>
  450. However, this quickly becomes tedious for large arrays, and is not
  451. helpful if the size of the array is unknown. An alternative method is
  452. described in <a class="xref" href="functions-comparisons.html" title="9.23. Row and Array Comparisons">Section 9.23</a>. The above
  453. query could be replaced by:
  454. </p><pre class="programlisting">
  455. SELECT * FROM sal_emp WHERE 10000 = ANY (pay_by_quarter);
  456. </pre><p>
  457. In addition, you can find rows where the array has all values
  458. equal to 10000 with:
  459. </p><pre class="programlisting">
  460. SELECT * FROM sal_emp WHERE 10000 = ALL (pay_by_quarter);
  461. </pre><p>
  462. </p><p>
  463. Alternatively, the <code class="function">generate_subscripts</code> function can be used.
  464. For example:
  465. </p><pre class="programlisting">
  466. SELECT * FROM
  467. (SELECT pay_by_quarter,
  468. generate_subscripts(pay_by_quarter, 1) AS s
  469. FROM sal_emp) AS foo
  470. WHERE pay_by_quarter[s] = 10000;
  471. </pre><p>
  472. This function is described in <a class="xref" href="functions-srf.html#FUNCTIONS-SRF-SUBSCRIPTS" title="Table 9.62. Subscript Generating Functions">Table 9.62</a>.
  473. </p><p>
  474. You can also search an array using the <code class="literal">&amp;&amp;</code> operator,
  475. which checks whether the left operand overlaps with the right operand.
  476. For instance:
  477. </p><pre class="programlisting">
  478. SELECT * FROM sal_emp WHERE pay_by_quarter &amp;&amp; ARRAY[10000];
  479. </pre><p>
  480. This and other array operators are further described in
  481. <a class="xref" href="functions-array.html" title="9.18. Array Functions and Operators">Section 9.18</a>. It can be accelerated by an appropriate
  482. index, as described in <a class="xref" href="indexes-types.html" title="11.2. Index Types">Section 11.2</a>.
  483. </p><p>
  484. You can also search for specific values in an array using the <code class="function">array_position</code>
  485. and <code class="function">array_positions</code> functions. The former returns the subscript of
  486. the first occurrence of a value in an array; the latter returns an array with the
  487. subscripts of all occurrences of the value in the array. For example:
  488. </p><pre class="programlisting">
  489. SELECT array_position(ARRAY['sun','mon','tue','wed','thu','fri','sat'], 'mon');
  490. array_positions
  491. -----------------
  492. 2
  493. SELECT array_positions(ARRAY[1, 4, 3, 1, 3, 4, 2, 1], 1);
  494. array_positions
  495. -----------------
  496. {1,4,8}
  497. </pre><p>
  498. </p><div class="tip"><h3 class="title">Tip</h3><p>
  499. Arrays are not sets; searching for specific array elements
  500. can be a sign of database misdesign. Consider
  501. using a separate table with a row for each item that would be an
  502. array element. This will be easier to search, and is likely to
  503. scale better for a large number of elements.
  504. </p></div></div><div class="sect2" id="ARRAYS-IO"><div class="titlepage"><div><div><h3 class="title">8.15.6. Array Input and Output Syntax</h3></div></div></div><a id="id-1.5.7.23.9.2" class="indexterm"></a><p>
  505. The external text representation of an array value consists of items that
  506. are interpreted according to the I/O conversion rules for the array's
  507. element type, plus decoration that indicates the array structure.
  508. The decoration consists of curly braces (<code class="literal">{</code> and <code class="literal">}</code>)
  509. around the array value plus delimiter characters between adjacent items.
  510. The delimiter character is usually a comma (<code class="literal">,</code>) but can be
  511. something else: it is determined by the <code class="literal">typdelim</code> setting
  512. for the array's element type. Among the standard data types provided
  513. in the <span class="productname">PostgreSQL</span> distribution, all use a comma,
  514. except for type <code class="type">box</code>, which uses a semicolon (<code class="literal">;</code>).
  515. In a multidimensional array, each dimension (row, plane,
  516. cube, etc.) gets its own level of curly braces, and delimiters
  517. must be written between adjacent curly-braced entities of the same level.
  518. </p><p>
  519. The array output routine will put double quotes around element values
  520. if they are empty strings, contain curly braces, delimiter characters,
  521. double quotes, backslashes, or white space, or match the word
  522. <code class="literal">NULL</code>. Double quotes and backslashes
  523. embedded in element values will be backslash-escaped. For numeric
  524. data types it is safe to assume that double quotes will never appear, but
  525. for textual data types one should be prepared to cope with either the presence
  526. or absence of quotes.
  527. </p><p>
  528. By default, the lower bound index value of an array's dimensions is
  529. set to one. To represent arrays with other lower bounds, the array
  530. subscript ranges can be specified explicitly before writing the
  531. array contents.
  532. This decoration consists of square brackets (<code class="literal">[]</code>)
  533. around each array dimension's lower and upper bounds, with
  534. a colon (<code class="literal">:</code>) delimiter character in between. The
  535. array dimension decoration is followed by an equal sign (<code class="literal">=</code>).
  536. For example:
  537. </p><pre class="programlisting">
  538. SELECT f1[1][-2][3] AS e1, f1[1][-1][5] AS e2
  539. FROM (SELECT '[1:1][-2:-1][3:5]={{{1,2,3},{4,5,6}}}'::int[] AS f1) AS ss;
  540. e1 | e2
  541. ----+----
  542. 1 | 6
  543. (1 row)
  544. </pre><p>
  545. The array output routine will include explicit dimensions in its result
  546. only when there are one or more lower bounds different from one.
  547. </p><p>
  548. If the value written for an element is <code class="literal">NULL</code> (in any case
  549. variant), the element is taken to be NULL. The presence of any quotes
  550. or backslashes disables this and allows the literal string value
  551. <span class="quote">“<span class="quote">NULL</span>”</span> to be entered. Also, for backward compatibility with
  552. pre-8.2 versions of <span class="productname">PostgreSQL</span>, the <a class="xref" href="runtime-config-compatible.html#GUC-ARRAY-NULLS">array_nulls</a> configuration parameter can be turned
  553. <code class="literal">off</code> to suppress recognition of <code class="literal">NULL</code> as a NULL.
  554. </p><p>
  555. As shown previously, when writing an array value you can use double
  556. quotes around any individual array element. You <span class="emphasis"><em>must</em></span> do so
  557. if the element value would otherwise confuse the array-value parser.
  558. For example, elements containing curly braces, commas (or the data type's
  559. delimiter character), double quotes, backslashes, or leading or trailing
  560. whitespace must be double-quoted. Empty strings and strings matching the
  561. word <code class="literal">NULL</code> must be quoted, too. To put a double
  562. quote or backslash in a quoted array element value, precede it
  563. with a backslash. Alternatively, you can avoid quotes and use
  564. backslash-escaping to protect all data characters that would otherwise
  565. be taken as array syntax.
  566. </p><p>
  567. You can add whitespace before a left brace or after a right
  568. brace. You can also add whitespace before or after any individual item
  569. string. In all of these cases the whitespace will be ignored. However,
  570. whitespace within double-quoted elements, or surrounded on both sides by
  571. non-whitespace characters of an element, is not ignored.
  572. </p><div class="tip"><h3 class="title">Tip</h3><p>
  573. The <code class="literal">ARRAY</code> constructor syntax (see
  574. <a class="xref" href="sql-expressions.html#SQL-SYNTAX-ARRAY-CONSTRUCTORS" title="4.2.12. Array Constructors">Section 4.2.12</a>) is often easier to work
  575. with than the array-literal syntax when writing array values in SQL
  576. commands. In <code class="literal">ARRAY</code>, individual element values are written the
  577. same way they would be written when not members of an array.
  578. </p></div></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="datatype-json.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="datatype.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="rowtypes.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">8.14. <acronym class="acronym">JSON</acronym> Types </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 8.16. Composite Types</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1