gooderp18绿色标准版
Ви не можете вибрати більше 25 тем Теми мають розпочинатися з літери або цифри, можуть містити дефіси (-) і не повинні перевищувати 35 символів.

585 lines
33KB

  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>F.38. tablefunc</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="sslinfo.html" title="F.37. sslinfo" /><link rel="next" href="tcn.html" title="F.39. tcn" /></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">F.38. tablefunc</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sslinfo.html" title="F.37. sslinfo">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="contrib.html" title="Appendix F. Additional Supplied Modules">Up</a></td><th width="60%" align="center">Appendix F. Additional Supplied Modules</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="tcn.html" title="F.39. tcn">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="TABLEFUNC"><div class="titlepage"><div><div><h2 class="title" style="clear: both">F.38. tablefunc</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="tablefunc.html#id-1.11.7.47.4">F.38.1. Functions Provided</a></span></dt><dt><span class="sect2"><a href="tablefunc.html#id-1.11.7.47.5">F.38.2. Author</a></span></dt></dl></div><a id="id-1.11.7.47.2" class="indexterm"></a><p>
  3. The <code class="filename">tablefunc</code> module includes various functions that return
  4. tables (that is, multiple rows). These functions are useful both in their
  5. own right and as examples of how to write C functions that return
  6. multiple rows.
  7. </p><div class="sect2" id="id-1.11.7.47.4"><div class="titlepage"><div><div><h3 class="title">F.38.1. Functions Provided</h3></div></div></div><p>
  8. <a class="xref" href="tablefunc.html#TABLEFUNC-FUNCTIONS" title="Table F.30. tablefunc Functions">Table F.30</a> shows the functions provided
  9. by the <code class="filename">tablefunc</code> module.
  10. </p><div class="table" id="TABLEFUNC-FUNCTIONS"><p class="title"><strong>Table F.30. <code class="filename">tablefunc</code> Functions</strong></p><div class="table-contents"><table class="table" summary="tablefunc Functions" border="1"><colgroup><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Returns</th><th>Description</th></tr></thead><tbody><tr><td><code class="function">normal_rand(int numvals, float8 mean, float8 stddev)</code></td><td><code class="type">setof float8</code></td><td>
  11. Produces a set of normally distributed random values
  12. </td></tr><tr><td><code class="function">crosstab(text sql)</code></td><td><code class="type">setof record</code></td><td>
  13. Produces a <span class="quote">“<span class="quote">pivot table</span>”</span> containing
  14. row names plus <em class="replaceable"><code>N</code></em> value columns, where
  15. <em class="replaceable"><code>N</code></em> is determined by the row type specified in the calling
  16. query
  17. </td></tr><tr><td><code class="function">crosstab<em class="replaceable"><code>N</code></em>(text sql)</code></td><td><code class="type">setof table_crosstab_<em class="replaceable"><code>N</code></em></code></td><td>
  18. Produces a <span class="quote">“<span class="quote">pivot table</span>”</span> containing
  19. row names plus <em class="replaceable"><code>N</code></em> value columns.
  20. <code class="function">crosstab2</code>, <code class="function">crosstab3</code>, and
  21. <code class="function">crosstab4</code> are predefined, but you can create additional
  22. <code class="function">crosstab<em class="replaceable"><code>N</code></em></code> functions as described below
  23. </td></tr><tr><td><code class="function">crosstab(text source_sql, text category_sql)</code></td><td><code class="type">setof record</code></td><td>
  24. Produces a <span class="quote">“<span class="quote">pivot table</span>”</span>
  25. with the value columns specified by a second query
  26. </td></tr><tr><td><code class="function">crosstab(text sql, int N)</code></td><td><code class="type">setof record</code></td><td>
  27. <p>Obsolete version of <code class="function">crosstab(text)</code>.
  28. The parameter <em class="replaceable"><code>N</code></em> is now ignored, since the number of
  29. value columns is always determined by the calling query
  30. </p>
  31. </td></tr><tr><td>
  32. <code class="function">
  33. connectby(text relname, text keyid_fld, text parent_keyid_fld
  34. [, text orderby_fld ], text start_with, int max_depth
  35. [, text branch_delim ])
  36. </code>
  37. <a id="id-1.11.7.47.4.3.2.2.6.1.2" class="indexterm"></a>
  38. </td><td><code class="type">setof record</code></td><td>
  39. Produces a representation of a hierarchical tree structure
  40. </td></tr></tbody></table></div></div><br class="table-break" /><div class="sect3" id="id-1.11.7.47.4.4"><div class="titlepage"><div><div><h4 class="title">F.38.1.1. <code class="function">normal_rand</code></h4></div></div></div><a id="id-1.11.7.47.4.4.2" class="indexterm"></a><pre class="synopsis">
  41. normal_rand(int numvals, float8 mean, float8 stddev) returns setof float8
  42. </pre><p>
  43. <code class="function">normal_rand</code> produces a set of normally distributed random
  44. values (Gaussian distribution).
  45. </p><p>
  46. <em class="parameter"><code>numvals</code></em> is the number of values to be returned
  47. from the function. <em class="parameter"><code>mean</code></em> is the mean of the normal
  48. distribution of values and <em class="parameter"><code>stddev</code></em> is the standard
  49. deviation of the normal distribution of values.
  50. </p><p>
  51. For example, this call requests 1000 values with a mean of 5 and a
  52. standard deviation of 3:
  53. </p><pre class="screen">
  54. test=# SELECT * FROM normal_rand(1000, 5, 3);
  55. normal_rand
  56. ----------------------
  57. 1.56556322244898
  58. 9.10040991424657
  59. 5.36957140345079
  60. -0.369151492880995
  61. 0.283600703686639
  62. .
  63. .
  64. .
  65. 4.82992125404908
  66. 9.71308014517282
  67. 2.49639286969028
  68. (1000 rows)
  69. </pre></div><div class="sect3" id="id-1.11.7.47.4.5"><div class="titlepage"><div><div><h4 class="title">F.38.1.2. <code class="function">crosstab(text)</code></h4></div></div></div><a id="id-1.11.7.47.4.5.2" class="indexterm"></a><pre class="synopsis">
  70. crosstab(text sql)
  71. crosstab(text sql, int N)
  72. </pre><p>
  73. The <code class="function">crosstab</code> function is used to produce <span class="quote">“<span class="quote">pivot</span>”</span>
  74. displays, wherein data is listed across the page rather than down.
  75. For example, we might have data like
  76. </p><pre class="programlisting">
  77. row1 val11
  78. row1 val12
  79. row1 val13
  80. ...
  81. row2 val21
  82. row2 val22
  83. row2 val23
  84. ...
  85. </pre><p>
  86. which we wish to display like
  87. </p><pre class="programlisting">
  88. row1 val11 val12 val13 ...
  89. row2 val21 val22 val23 ...
  90. ...
  91. </pre><p>
  92. The <code class="function">crosstab</code> function takes a text parameter that is a SQL
  93. query producing raw data formatted in the first way, and produces a table
  94. formatted in the second way.
  95. </p><p>
  96. The <em class="parameter"><code>sql</code></em> parameter is a SQL statement that produces
  97. the source set of data. This statement must return one
  98. <code class="structfield">row_name</code> column, one
  99. <code class="structfield">category</code> column, and one
  100. <code class="structfield">value</code> column. <em class="parameter"><code>N</code></em> is an
  101. obsolete parameter, ignored if supplied (formerly this had to match the
  102. number of output value columns, but now that is determined by the
  103. calling query).
  104. </p><p>
  105. For example, the provided query might produce a set something like:
  106. </p><pre class="programlisting">
  107. row_name cat value
  108. ----------+-------+-------
  109. row1 cat1 val1
  110. row1 cat2 val2
  111. row1 cat3 val3
  112. row1 cat4 val4
  113. row2 cat1 val5
  114. row2 cat2 val6
  115. row2 cat3 val7
  116. row2 cat4 val8
  117. </pre><p>
  118. </p><p>
  119. The <code class="function">crosstab</code> function is declared to return <code class="type">setof
  120. record</code>, so the actual names and types of the output columns must be
  121. defined in the <code class="literal">FROM</code> clause of the calling <code class="command">SELECT</code>
  122. statement, for example:
  123. </p><pre class="programlisting">
  124. SELECT * FROM crosstab('...') AS ct(row_name text, category_1 text, category_2 text);
  125. </pre><p>
  126. This example produces a set something like:
  127. </p><pre class="programlisting">
  128. &lt;== value columns ==&gt;
  129. row_name category_1 category_2
  130. ----------+------------+------------
  131. row1 val1 val2
  132. row2 val5 val6
  133. </pre><p>
  134. </p><p>
  135. The <code class="literal">FROM</code> clause must define the output as one
  136. <code class="structfield">row_name</code> column (of the same data type as the first result
  137. column of the SQL query) followed by N <code class="structfield">value</code> columns
  138. (all of the same data type as the third result column of the SQL query).
  139. You can set up as many output value columns as you wish. The names of the
  140. output columns are up to you.
  141. </p><p>
  142. The <code class="function">crosstab</code> function produces one output row for each
  143. consecutive group of input rows with the same
  144. <code class="structfield">row_name</code> value. It fills the output
  145. <code class="structfield">value</code> columns, left to right, with the
  146. <code class="structfield">value</code> fields from these rows. If there
  147. are fewer rows in a group than there are output <code class="structfield">value</code>
  148. columns, the extra output columns are filled with nulls; if there are
  149. more rows, the extra input rows are skipped.
  150. </p><p>
  151. In practice the SQL query should always specify <code class="literal">ORDER BY 1,2</code>
  152. to ensure that the input rows are properly ordered, that is, values with
  153. the same <code class="structfield">row_name</code> are brought together and
  154. correctly ordered within the row. Notice that <code class="function">crosstab</code>
  155. itself does not pay any attention to the second column of the query
  156. result; it's just there to be ordered by, to control the order in which
  157. the third-column values appear across the page.
  158. </p><p>
  159. Here is a complete example:
  160. </p><pre class="programlisting">
  161. CREATE TABLE ct(id SERIAL, rowid TEXT, attribute TEXT, value TEXT);
  162. INSERT INTO ct(rowid, attribute, value) VALUES('test1','att1','val1');
  163. INSERT INTO ct(rowid, attribute, value) VALUES('test1','att2','val2');
  164. INSERT INTO ct(rowid, attribute, value) VALUES('test1','att3','val3');
  165. INSERT INTO ct(rowid, attribute, value) VALUES('test1','att4','val4');
  166. INSERT INTO ct(rowid, attribute, value) VALUES('test2','att1','val5');
  167. INSERT INTO ct(rowid, attribute, value) VALUES('test2','att2','val6');
  168. INSERT INTO ct(rowid, attribute, value) VALUES('test2','att3','val7');
  169. INSERT INTO ct(rowid, attribute, value) VALUES('test2','att4','val8');
  170. SELECT *
  171. FROM crosstab(
  172. 'select rowid, attribute, value
  173. from ct
  174. where attribute = ''att2'' or attribute = ''att3''
  175. order by 1,2')
  176. AS ct(row_name text, category_1 text, category_2 text, category_3 text);
  177. row_name | category_1 | category_2 | category_3
  178. ----------+------------+------------+------------
  179. test1 | val2 | val3 |
  180. test2 | val6 | val7 |
  181. (2 rows)
  182. </pre><p>
  183. </p><p>
  184. You can avoid always having to write out a <code class="literal">FROM</code> clause to
  185. define the output columns, by setting up a custom crosstab function that
  186. has the desired output row type wired into its definition. This is
  187. described in the next section. Another possibility is to embed the
  188. required <code class="literal">FROM</code> clause in a view definition.
  189. </p><div class="note"><h3 class="title">Note</h3><p>
  190. See also the <code class="command"><a class="link" href="app-psql.html#APP-PSQL-META-COMMANDS-CROSSTABVIEW">\crosstabview</a></code>
  191. command in <span class="application">psql</span>, which provides functionality similar
  192. to <code class="function">crosstab()</code>.
  193. </p></div></div><div class="sect3" id="id-1.11.7.47.4.6"><div class="titlepage"><div><div><h4 class="title">F.38.1.3. <code class="function">crosstab<em class="replaceable"><code>N</code></em>(text)</code></h4></div></div></div><a id="id-1.11.7.47.4.6.2" class="indexterm"></a><pre class="synopsis">
  194. crosstab<em class="replaceable"><code>N</code></em>(text sql)
  195. </pre><p>
  196. The <code class="function">crosstab<em class="replaceable"><code>N</code></em></code> functions are examples of how
  197. to set up custom wrappers for the general <code class="function">crosstab</code> function,
  198. so that you need not write out column names and types in the calling
  199. <code class="command">SELECT</code> query. The <code class="filename">tablefunc</code> module includes
  200. <code class="function">crosstab2</code>, <code class="function">crosstab3</code>, and
  201. <code class="function">crosstab4</code>, whose output row types are defined as
  202. </p><pre class="programlisting">
  203. CREATE TYPE tablefunc_crosstab_N AS (
  204. row_name TEXT,
  205. category_1 TEXT,
  206. category_2 TEXT,
  207. .
  208. .
  209. .
  210. category_N TEXT
  211. );
  212. </pre><p>
  213. Thus, these functions can be used directly when the input query produces
  214. <code class="structfield">row_name</code> and <code class="structfield">value</code> columns of type
  215. <code class="type">text</code>, and you want 2, 3, or 4 output values columns.
  216. In all other ways they behave exactly as described above for the
  217. general <code class="function">crosstab</code> function.
  218. </p><p>
  219. For instance, the example given in the previous section would also
  220. work as
  221. </p><pre class="programlisting">
  222. SELECT *
  223. FROM crosstab3(
  224. 'select rowid, attribute, value
  225. from ct
  226. where attribute = ''att2'' or attribute = ''att3''
  227. order by 1,2');
  228. </pre><p>
  229. </p><p>
  230. These functions are provided mostly for illustration purposes. You
  231. can create your own return types and functions based on the
  232. underlying <code class="function">crosstab()</code> function. There are two ways
  233. to do it:
  234. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  235. Create a composite type describing the desired output columns,
  236. similar to the examples in
  237. <code class="filename">contrib/tablefunc/tablefunc--1.0.sql</code>.
  238. Then define a
  239. unique function name accepting one <code class="type">text</code> parameter and returning
  240. <code class="type">setof your_type_name</code>, but linking to the same underlying
  241. <code class="function">crosstab</code> C function. For example, if your source data
  242. produces row names that are <code class="type">text</code>, and values that are
  243. <code class="type">float8</code>, and you want 5 value columns:
  244. </p><pre class="programlisting">
  245. CREATE TYPE my_crosstab_float8_5_cols AS (
  246. my_row_name text,
  247. my_category_1 float8,
  248. my_category_2 float8,
  249. my_category_3 float8,
  250. my_category_4 float8,
  251. my_category_5 float8
  252. );
  253. CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(text)
  254. RETURNS setof my_crosstab_float8_5_cols
  255. AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT;
  256. </pre><p>
  257. </p></li><li class="listitem"><p>
  258. Use <code class="literal">OUT</code> parameters to define the return type implicitly.
  259. The same example could also be done this way:
  260. </p><pre class="programlisting">
  261. CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(
  262. IN text,
  263. OUT my_row_name text,
  264. OUT my_category_1 float8,
  265. OUT my_category_2 float8,
  266. OUT my_category_3 float8,
  267. OUT my_category_4 float8,
  268. OUT my_category_5 float8)
  269. RETURNS setof record
  270. AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT;
  271. </pre><p>
  272. </p></li></ul></div><p>
  273. </p></div><div class="sect3" id="id-1.11.7.47.4.7"><div class="titlepage"><div><div><h4 class="title">F.38.1.4. <code class="function">crosstab(text, text)</code></h4></div></div></div><a id="id-1.11.7.47.4.7.2" class="indexterm"></a><pre class="synopsis">
  274. crosstab(text source_sql, text category_sql)
  275. </pre><p>
  276. The main limitation of the single-parameter form of <code class="function">crosstab</code>
  277. is that it treats all values in a group alike, inserting each value into
  278. the first available column. If you want the value
  279. columns to correspond to specific categories of data, and some groups
  280. might not have data for some of the categories, that doesn't work well.
  281. The two-parameter form of <code class="function">crosstab</code> handles this case by
  282. providing an explicit list of the categories corresponding to the
  283. output columns.
  284. </p><p>
  285. <em class="parameter"><code>source_sql</code></em> is a SQL statement that produces the
  286. source set of data. This statement must return one
  287. <code class="structfield">row_name</code> column, one
  288. <code class="structfield">category</code> column, and one
  289. <code class="structfield">value</code> column. It may also have one or more
  290. <span class="quote">“<span class="quote">extra</span>”</span> columns.
  291. The <code class="structfield">row_name</code> column must be first. The
  292. <code class="structfield">category</code> and <code class="structfield">value</code>
  293. columns must be the last two columns, in that order. Any columns between
  294. <code class="structfield">row_name</code> and
  295. <code class="structfield">category</code> are treated as <span class="quote">“<span class="quote">extra</span>”</span>.
  296. The <span class="quote">“<span class="quote">extra</span>”</span> columns are expected to be the same for all rows
  297. with the same <code class="structfield">row_name</code> value.
  298. </p><p>
  299. For example, <em class="parameter"><code>source_sql</code></em> might produce a set
  300. something like:
  301. </p><pre class="programlisting">
  302. SELECT row_name, extra_col, cat, value FROM foo ORDER BY 1;
  303. row_name extra_col cat value
  304. ----------+------------+-----+---------
  305. row1 extra1 cat1 val1
  306. row1 extra1 cat2 val2
  307. row1 extra1 cat4 val4
  308. row2 extra2 cat1 val5
  309. row2 extra2 cat2 val6
  310. row2 extra2 cat3 val7
  311. row2 extra2 cat4 val8
  312. </pre><p>
  313. </p><p>
  314. <em class="parameter"><code>category_sql</code></em> is a SQL statement that produces
  315. the set of categories. This statement must return only one column.
  316. It must produce at least one row, or an error will be generated.
  317. Also, it must not produce duplicate values, or an error will be
  318. generated. <em class="parameter"><code>category_sql</code></em> might be something like:
  319. </p><pre class="programlisting">
  320. SELECT DISTINCT cat FROM foo ORDER BY 1;
  321. cat
  322. -------
  323. cat1
  324. cat2
  325. cat3
  326. cat4
  327. </pre><p>
  328. </p><p>
  329. The <code class="function">crosstab</code> function is declared to return <code class="type">setof
  330. record</code>, so the actual names and types of the output columns must be
  331. defined in the <code class="literal">FROM</code> clause of the calling <code class="command">SELECT</code>
  332. statement, for example:
  333. </p><pre class="programlisting">
  334. SELECT * FROM crosstab('...', '...')
  335. AS ct(row_name text, extra text, cat1 text, cat2 text, cat3 text, cat4 text);
  336. </pre><p>
  337. </p><p>
  338. This will produce a result something like:
  339. </p><pre class="programlisting">
  340. &lt;== value columns ==&gt;
  341. row_name extra cat1 cat2 cat3 cat4
  342. ---------+-------+------+------+------+------
  343. row1 extra1 val1 val2 val4
  344. row2 extra2 val5 val6 val7 val8
  345. </pre><p>
  346. </p><p>
  347. The <code class="literal">FROM</code> clause must define the proper number of output
  348. columns of the proper data types. If there are <em class="replaceable"><code>N</code></em>
  349. columns in the <em class="parameter"><code>source_sql</code></em> query's result, the first
  350. <em class="replaceable"><code>N</code></em>-2 of them must match up with the first
  351. <em class="replaceable"><code>N</code></em>-2 output columns. The remaining output columns
  352. must have the type of the last column of the <em class="parameter"><code>source_sql</code></em>
  353. query's result, and there must be exactly as many of them as there
  354. are rows in the <em class="parameter"><code>category_sql</code></em> query's result.
  355. </p><p>
  356. The <code class="function">crosstab</code> function produces one output row for each
  357. consecutive group of input rows with the same
  358. <code class="structfield">row_name</code> value. The output
  359. <code class="structfield">row_name</code> column, plus any <span class="quote">“<span class="quote">extra</span>”</span>
  360. columns, are copied from the first row of the group. The output
  361. <code class="structfield">value</code> columns are filled with the
  362. <code class="structfield">value</code> fields from rows having matching
  363. <code class="structfield">category</code> values. If a row's <code class="structfield">category</code>
  364. does not match any output of the <em class="parameter"><code>category_sql</code></em>
  365. query, its <code class="structfield">value</code> is ignored. Output
  366. columns whose matching category is not present in any input row
  367. of the group are filled with nulls.
  368. </p><p>
  369. In practice the <em class="parameter"><code>source_sql</code></em> query should always
  370. specify <code class="literal">ORDER BY 1</code> to ensure that values with the same
  371. <code class="structfield">row_name</code> are brought together. However,
  372. ordering of the categories within a group is not important.
  373. Also, it is essential to be sure that the order of the
  374. <em class="parameter"><code>category_sql</code></em> query's output matches the specified
  375. output column order.
  376. </p><p>
  377. Here are two complete examples:
  378. </p><pre class="programlisting">
  379. create table sales(year int, month int, qty int);
  380. insert into sales values(2007, 1, 1000);
  381. insert into sales values(2007, 2, 1500);
  382. insert into sales values(2007, 7, 500);
  383. insert into sales values(2007, 11, 1500);
  384. insert into sales values(2007, 12, 2000);
  385. insert into sales values(2008, 1, 1000);
  386. select * from crosstab(
  387. 'select year, month, qty from sales order by 1',
  388. 'select m from generate_series(1,12) m'
  389. ) as (
  390. year int,
  391. "Jan" int,
  392. "Feb" int,
  393. "Mar" int,
  394. "Apr" int,
  395. "May" int,
  396. "Jun" int,
  397. "Jul" int,
  398. "Aug" int,
  399. "Sep" int,
  400. "Oct" int,
  401. "Nov" int,
  402. "Dec" int
  403. );
  404. year | Jan | Feb | Mar | Apr | May | Jun | Jul | Aug | Sep | Oct | Nov | Dec
  405. ------+------+------+-----+-----+-----+-----+-----+-----+-----+-----+------+------
  406. 2007 | 1000 | 1500 | | | | | 500 | | | | 1500 | 2000
  407. 2008 | 1000 | | | | | | | | | | |
  408. (2 rows)
  409. </pre><p>
  410. </p><pre class="programlisting">
  411. CREATE TABLE cth(rowid text, rowdt timestamp, attribute text, val text);
  412. INSERT INTO cth VALUES('test1','01 March 2003','temperature','42');
  413. INSERT INTO cth VALUES('test1','01 March 2003','test_result','PASS');
  414. INSERT INTO cth VALUES('test1','01 March 2003','volts','2.6987');
  415. INSERT INTO cth VALUES('test2','02 March 2003','temperature','53');
  416. INSERT INTO cth VALUES('test2','02 March 2003','test_result','FAIL');
  417. INSERT INTO cth VALUES('test2','02 March 2003','test_startdate','01 March 2003');
  418. INSERT INTO cth VALUES('test2','02 March 2003','volts','3.1234');
  419. SELECT * FROM crosstab
  420. (
  421. 'SELECT rowid, rowdt, attribute, val FROM cth ORDER BY 1',
  422. 'SELECT DISTINCT attribute FROM cth ORDER BY 1'
  423. )
  424. AS
  425. (
  426. rowid text,
  427. rowdt timestamp,
  428. temperature int4,
  429. test_result text,
  430. test_startdate timestamp,
  431. volts float8
  432. );
  433. rowid | rowdt | temperature | test_result | test_startdate | volts
  434. -------+--------------------------+-------------+-------------+--------------------------+--------
  435. test1 | Sat Mar 01 00:00:00 2003 | 42 | PASS | | 2.6987
  436. test2 | Sun Mar 02 00:00:00 2003 | 53 | FAIL | Sat Mar 01 00:00:00 2003 | 3.1234
  437. (2 rows)
  438. </pre><p>
  439. </p><p>
  440. You can create predefined functions to avoid having to write out
  441. the result column names and types in each query. See the examples
  442. in the previous section. The underlying C function for this form
  443. of <code class="function">crosstab</code> is named <code class="literal">crosstab_hash</code>.
  444. </p></div><div class="sect3" id="id-1.11.7.47.4.8"><div class="titlepage"><div><div><h4 class="title">F.38.1.5. <code class="function">connectby</code></h4></div></div></div><a id="id-1.11.7.47.4.8.2" class="indexterm"></a><pre class="synopsis">
  445. connectby(text relname, text keyid_fld, text parent_keyid_fld
  446. [, text orderby_fld ], text start_with, int max_depth
  447. [, text branch_delim ])
  448. </pre><p>
  449. The <code class="function">connectby</code> function produces a display of hierarchical
  450. data that is stored in a table. The table must have a key field that
  451. uniquely identifies rows, and a parent-key field that references the
  452. parent (if any) of each row. <code class="function">connectby</code> can display the
  453. sub-tree descending from any row.
  454. </p><p>
  455. <a class="xref" href="tablefunc.html#TABLEFUNC-CONNECTBY-PARAMETERS" title="Table F.31. connectby Parameters">Table F.31</a> explains the
  456. parameters.
  457. </p><div class="table" id="TABLEFUNC-CONNECTBY-PARAMETERS"><p class="title"><strong>Table F.31. <code class="function">connectby</code> Parameters</strong></p><div class="table-contents"><table class="table" summary="connectby Parameters" border="1"><colgroup><col /><col /></colgroup><thead><tr><th>Parameter</th><th>Description</th></tr></thead><tbody><tr><td><em class="parameter"><code>relname</code></em></td><td>Name of the source relation</td></tr><tr><td><em class="parameter"><code>keyid_fld</code></em></td><td>Name of the key field</td></tr><tr><td><em class="parameter"><code>parent_keyid_fld</code></em></td><td>Name of the parent-key field</td></tr><tr><td><em class="parameter"><code>orderby_fld</code></em></td><td>Name of the field to order siblings by (optional)</td></tr><tr><td><em class="parameter"><code>start_with</code></em></td><td>Key value of the row to start at</td></tr><tr><td><em class="parameter"><code>max_depth</code></em></td><td>Maximum depth to descend to, or zero for unlimited depth</td></tr><tr><td><em class="parameter"><code>branch_delim</code></em></td><td>String to separate keys with in branch output (optional)</td></tr></tbody></table></div></div><br class="table-break" /><p>
  458. The key and parent-key fields can be any data type, but they must be
  459. the same type. Note that the <em class="parameter"><code>start_with</code></em> value must be
  460. entered as a text string, regardless of the type of the key field.
  461. </p><p>
  462. The <code class="function">connectby</code> function is declared to return <code class="type">setof
  463. record</code>, so the actual names and types of the output columns must be
  464. defined in the <code class="literal">FROM</code> clause of the calling <code class="command">SELECT</code>
  465. statement, for example:
  466. </p><pre class="programlisting">
  467. SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~')
  468. AS t(keyid text, parent_keyid text, level int, branch text, pos int);
  469. </pre><p>
  470. The first two output columns are used for the current row's key and
  471. its parent row's key; they must match the type of the table's key field.
  472. The third output column is the depth in the tree and must be of type
  473. <code class="type">integer</code>. If a <em class="parameter"><code>branch_delim</code></em> parameter was
  474. given, the next output column is the branch display and must be of type
  475. <code class="type">text</code>. Finally, if an <em class="parameter"><code>orderby_fld</code></em>
  476. parameter was given, the last output column is a serial number, and must
  477. be of type <code class="type">integer</code>.
  478. </p><p>
  479. The <span class="quote">“<span class="quote">branch</span>”</span> output column shows the path of keys taken to
  480. reach the current row. The keys are separated by the specified
  481. <em class="parameter"><code>branch_delim</code></em> string. If no branch display is
  482. wanted, omit both the <em class="parameter"><code>branch_delim</code></em> parameter
  483. and the branch column in the output column list.
  484. </p><p>
  485. If the ordering of siblings of the same parent is important,
  486. include the <em class="parameter"><code>orderby_fld</code></em> parameter to
  487. specify which field to order siblings by. This field can be of any
  488. sortable data type. The output column list must include a final
  489. integer serial-number column, if and only if
  490. <em class="parameter"><code>orderby_fld</code></em> is specified.
  491. </p><p>
  492. The parameters representing table and field names are copied as-is
  493. into the SQL queries that <code class="function">connectby</code> generates internally.
  494. Therefore, include double quotes if the names are mixed-case or contain
  495. special characters. You may also need to schema-qualify the table name.
  496. </p><p>
  497. In large tables, performance will be poor unless there is an index on
  498. the parent-key field.
  499. </p><p>
  500. It is important that the <em class="parameter"><code>branch_delim</code></em> string
  501. not appear in any key values, else <code class="function">connectby</code> may incorrectly
  502. report an infinite-recursion error. Note that if
  503. <em class="parameter"><code>branch_delim</code></em> is not provided, a default value
  504. of <code class="literal">~</code> is used for recursion detection purposes.
  505. </p><p>
  506. Here is an example:
  507. </p><pre class="programlisting">
  508. CREATE TABLE connectby_tree(keyid text, parent_keyid text, pos int);
  509. INSERT INTO connectby_tree VALUES('row1',NULL, 0);
  510. INSERT INTO connectby_tree VALUES('row2','row1', 0);
  511. INSERT INTO connectby_tree VALUES('row3','row1', 0);
  512. INSERT INTO connectby_tree VALUES('row4','row2', 1);
  513. INSERT INTO connectby_tree VALUES('row5','row2', 0);
  514. INSERT INTO connectby_tree VALUES('row6','row4', 0);
  515. INSERT INTO connectby_tree VALUES('row7','row3', 0);
  516. INSERT INTO connectby_tree VALUES('row8','row6', 0);
  517. INSERT INTO connectby_tree VALUES('row9','row5', 0);
  518. -- with branch, without orderby_fld (order of results is not guaranteed)
  519. SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~')
  520. AS t(keyid text, parent_keyid text, level int, branch text);
  521. keyid | parent_keyid | level | branch
  522. -------+--------------+-------+---------------------
  523. row2 | | 0 | row2
  524. row4 | row2 | 1 | row2~row4
  525. row6 | row4 | 2 | row2~row4~row6
  526. row8 | row6 | 3 | row2~row4~row6~row8
  527. row5 | row2 | 1 | row2~row5
  528. row9 | row5 | 2 | row2~row5~row9
  529. (6 rows)
  530. -- without branch, without orderby_fld (order of results is not guaranteed)
  531. SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0)
  532. AS t(keyid text, parent_keyid text, level int);
  533. keyid | parent_keyid | level
  534. -------+--------------+-------
  535. row2 | | 0
  536. row4 | row2 | 1
  537. row6 | row4 | 2
  538. row8 | row6 | 3
  539. row5 | row2 | 1
  540. row9 | row5 | 2
  541. (6 rows)
  542. -- with branch, with orderby_fld (notice that row5 comes before row4)
  543. SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~')
  544. AS t(keyid text, parent_keyid text, level int, branch text, pos int);
  545. keyid | parent_keyid | level | branch | pos
  546. -------+--------------+-------+---------------------+-----
  547. row2 | | 0 | row2 | 1
  548. row5 | row2 | 1 | row2~row5 | 2
  549. row9 | row5 | 2 | row2~row5~row9 | 3
  550. row4 | row2 | 1 | row2~row4 | 4
  551. row6 | row4 | 2 | row2~row4~row6 | 5
  552. row8 | row6 | 3 | row2~row4~row6~row8 | 6
  553. (6 rows)
  554. -- without branch, with orderby_fld (notice that row5 comes before row4)
  555. SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0)
  556. AS t(keyid text, parent_keyid text, level int, pos int);
  557. keyid | parent_keyid | level | pos
  558. -------+--------------+-------+-----
  559. row2 | | 0 | 1
  560. row5 | row2 | 1 | 2
  561. row9 | row5 | 2 | 3
  562. row4 | row2 | 1 | 4
  563. row6 | row4 | 2 | 5
  564. row8 | row6 | 3 | 6
  565. (6 rows)
  566. </pre><p>
  567. </p></div></div><div class="sect2" id="id-1.11.7.47.5"><div class="titlepage"><div><div><h3 class="title">F.38.2. Author</h3></div></div></div><p>
  568. Joe Conway
  569. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sslinfo.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="contrib.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="tcn.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">F.37. sslinfo </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> F.39. tcn</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1