doc PG 17 relnotes: Fixes from jian he
[pgsql.git] / contrib / tablefunc / tablefunc.c
blob7d1b5f514390c22a6ccce4a19e21f5aba84fad7f
1 /*
2 * contrib/tablefunc/tablefunc.c
5 * tablefunc
7 * Sample to demonstrate C functions which return setof scalar
8 * and setof composite.
9 * Joe Conway <mail@joeconway.com>
10 * And contributors:
11 * Nabil Sayegh <postgresql@e-trolley.de>
13 * Copyright (c) 2002-2024, PostgreSQL Global Development Group
15 * Permission to use, copy, modify, and distribute this software and its
16 * documentation for any purpose, without fee, and without a written agreement
17 * is hereby granted, provided that the above copyright notice and this
18 * paragraph and the following two paragraphs appear in all copies.
20 * IN NO EVENT SHALL THE AUTHORS OR DISTRIBUTORS BE LIABLE TO ANY PARTY FOR
21 * DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
22 * LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
23 * DOCUMENTATION, EVEN IF THE AUTHOR OR DISTRIBUTORS HAVE BEEN ADVISED OF THE
24 * POSSIBILITY OF SUCH DAMAGE.
26 * THE AUTHORS AND DISTRIBUTORS SPECIFICALLY DISCLAIM ANY WARRANTIES,
27 * INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
28 * AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
29 * ON AN "AS IS" BASIS, AND THE AUTHOR AND DISTRIBUTORS HAS NO OBLIGATIONS TO
30 * PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
33 #include "postgres.h"
35 #include <math.h>
37 #include "access/htup_details.h"
38 #include "catalog/pg_type.h"
39 #include "common/pg_prng.h"
40 #include "executor/spi.h"
41 #include "funcapi.h"
42 #include "lib/stringinfo.h"
43 #include "miscadmin.h"
44 #include "tablefunc.h"
45 #include "utils/builtins.h"
47 PG_MODULE_MAGIC;
49 static HTAB *load_categories_hash(char *cats_sql, MemoryContext per_query_ctx);
50 static Tuplestorestate *get_crosstab_tuplestore(char *sql,
51 HTAB *crosstab_hash,
52 TupleDesc tupdesc,
53 bool randomAccess);
54 static void validateConnectbyTupleDesc(TupleDesc td, bool show_branch, bool show_serial);
55 static void compatCrosstabTupleDescs(TupleDesc ret_tupdesc, TupleDesc sql_tupdesc);
56 static void compatConnectbyTupleDescs(TupleDesc ret_tupdesc, TupleDesc sql_tupdesc);
57 static void get_normal_pair(float8 *x1, float8 *x2);
58 static Tuplestorestate *connectby(char *relname,
59 char *key_fld,
60 char *parent_key_fld,
61 char *orderby_fld,
62 char *branch_delim,
63 char *start_with,
64 int max_depth,
65 bool show_branch,
66 bool show_serial,
67 MemoryContext per_query_ctx,
68 bool randomAccess,
69 AttInMetadata *attinmeta);
70 static void build_tuplestore_recursively(char *key_fld,
71 char *parent_key_fld,
72 char *relname,
73 char *orderby_fld,
74 char *branch_delim,
75 char *start_with,
76 char *branch,
77 int level,
78 int *serial,
79 int max_depth,
80 bool show_branch,
81 bool show_serial,
82 MemoryContext per_query_ctx,
83 AttInMetadata *attinmeta,
84 Tuplestorestate *tupstore);
86 typedef struct
88 float8 mean; /* mean of the distribution */
89 float8 stddev; /* stddev of the distribution */
90 float8 carry_val; /* hold second generated value */
91 bool use_carry; /* use second generated value */
92 } normal_rand_fctx;
94 #define xpfree(var_) \
95 do { \
96 if (var_ != NULL) \
97 { \
98 pfree(var_); \
99 var_ = NULL; \
101 } while (0)
103 #define xpstrdup(tgtvar_, srcvar_) \
104 do { \
105 if (srcvar_) \
106 tgtvar_ = pstrdup(srcvar_); \
107 else \
108 tgtvar_ = NULL; \
109 } while (0)
111 #define xstreq(tgtvar_, srcvar_) \
112 (((tgtvar_ == NULL) && (srcvar_ == NULL)) || \
113 ((tgtvar_ != NULL) && (srcvar_ != NULL) && (strcmp(tgtvar_, srcvar_) == 0)))
115 /* sign, 10 digits, '\0' */
116 #define INT32_STRLEN 12
118 /* stored info for a crosstab category */
119 typedef struct crosstab_cat_desc
121 char *catname; /* full category name */
122 uint64 attidx; /* zero based */
123 } crosstab_cat_desc;
125 #define MAX_CATNAME_LEN NAMEDATALEN
126 #define INIT_CATS 64
128 #define crosstab_HashTableLookup(HASHTAB, CATNAME, CATDESC) \
129 do { \
130 crosstab_HashEnt *hentry; char key[MAX_CATNAME_LEN]; \
132 MemSet(key, 0, MAX_CATNAME_LEN); \
133 snprintf(key, MAX_CATNAME_LEN - 1, "%s", CATNAME); \
134 hentry = (crosstab_HashEnt*) hash_search(HASHTAB, \
135 key, HASH_FIND, NULL); \
136 if (hentry) \
137 CATDESC = hentry->catdesc; \
138 else \
139 CATDESC = NULL; \
140 } while(0)
142 #define crosstab_HashTableInsert(HASHTAB, CATDESC) \
143 do { \
144 crosstab_HashEnt *hentry; bool found; char key[MAX_CATNAME_LEN]; \
146 MemSet(key, 0, MAX_CATNAME_LEN); \
147 snprintf(key, MAX_CATNAME_LEN - 1, "%s", CATDESC->catname); \
148 hentry = (crosstab_HashEnt*) hash_search(HASHTAB, \
149 key, HASH_ENTER, &found); \
150 if (found) \
151 ereport(ERROR, \
152 (errcode(ERRCODE_DUPLICATE_OBJECT), \
153 errmsg("duplicate category name"))); \
154 hentry->catdesc = CATDESC; \
155 } while(0)
157 /* hash table */
158 typedef struct crosstab_hashent
160 char internal_catname[MAX_CATNAME_LEN];
161 crosstab_cat_desc *catdesc;
162 } crosstab_HashEnt;
165 * normal_rand - return requested number of random values
166 * with a Gaussian (Normal) distribution.
168 * inputs are int numvals, float8 mean, and float8 stddev
169 * returns setof float8
171 PG_FUNCTION_INFO_V1(normal_rand);
172 Datum
173 normal_rand(PG_FUNCTION_ARGS)
175 FuncCallContext *funcctx;
176 uint64 call_cntr;
177 uint64 max_calls;
178 normal_rand_fctx *fctx;
179 float8 mean;
180 float8 stddev;
181 float8 carry_val;
182 bool use_carry;
183 MemoryContext oldcontext;
185 /* stuff done only on the first call of the function */
186 if (SRF_IS_FIRSTCALL())
188 int32 num_tuples;
190 /* create a function context for cross-call persistence */
191 funcctx = SRF_FIRSTCALL_INIT();
194 * switch to memory context appropriate for multiple function calls
196 oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx);
198 /* total number of tuples to be returned */
199 num_tuples = PG_GETARG_INT32(0);
200 if (num_tuples < 0)
201 ereport(ERROR,
202 (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
203 errmsg("number of rows cannot be negative")));
204 funcctx->max_calls = num_tuples;
206 /* allocate memory for user context */
207 fctx = (normal_rand_fctx *) palloc(sizeof(normal_rand_fctx));
210 * Use fctx to keep track of upper and lower bounds from call to call.
211 * It will also be used to carry over the spare value we get from the
212 * Box-Muller algorithm so that we only actually calculate a new value
213 * every other call.
215 fctx->mean = PG_GETARG_FLOAT8(1);
216 fctx->stddev = PG_GETARG_FLOAT8(2);
217 fctx->carry_val = 0;
218 fctx->use_carry = false;
220 funcctx->user_fctx = fctx;
222 MemoryContextSwitchTo(oldcontext);
225 /* stuff done on every call of the function */
226 funcctx = SRF_PERCALL_SETUP();
228 call_cntr = funcctx->call_cntr;
229 max_calls = funcctx->max_calls;
230 fctx = funcctx->user_fctx;
231 mean = fctx->mean;
232 stddev = fctx->stddev;
233 carry_val = fctx->carry_val;
234 use_carry = fctx->use_carry;
236 if (call_cntr < max_calls) /* do when there is more left to send */
238 float8 result;
240 if (use_carry)
243 * reset use_carry and use second value obtained on last pass
245 fctx->use_carry = false;
246 result = carry_val;
248 else
250 float8 normval_1;
251 float8 normval_2;
253 /* Get the next two normal values */
254 get_normal_pair(&normval_1, &normval_2);
256 /* use the first */
257 result = mean + (stddev * normval_1);
259 /* and save the second */
260 fctx->carry_val = mean + (stddev * normval_2);
261 fctx->use_carry = true;
264 /* send the result */
265 SRF_RETURN_NEXT(funcctx, Float8GetDatum(result));
267 else
268 /* do when there is no more left */
269 SRF_RETURN_DONE(funcctx);
273 * get_normal_pair()
274 * Assigns normally distributed (Gaussian) values to a pair of provided
275 * parameters, with mean 0, standard deviation 1.
277 * This routine implements Algorithm P (Polar method for normal deviates)
278 * from Knuth's _The_Art_of_Computer_Programming_, Volume 2, 3rd ed., pages
279 * 122-126. Knuth cites his source as "The polar method", G. E. P. Box, M. E.
280 * Muller, and G. Marsaglia, _Annals_Math,_Stat._ 29 (1958), 610-611.
283 static void
284 get_normal_pair(float8 *x1, float8 *x2)
286 float8 u1,
294 u1 = pg_prng_double(&pg_global_prng_state);
295 u2 = pg_prng_double(&pg_global_prng_state);
297 v1 = (2.0 * u1) - 1.0;
298 v2 = (2.0 * u2) - 1.0;
300 s = v1 * v1 + v2 * v2;
301 } while (s >= 1.0);
303 if (s == 0)
305 *x1 = 0;
306 *x2 = 0;
308 else
310 s = sqrt((-2.0 * log(s)) / s);
311 *x1 = v1 * s;
312 *x2 = v2 * s;
317 * crosstab - create a crosstab of rowids and values columns from a
318 * SQL statement returning one rowid column, one category column,
319 * and one value column.
321 * e.g. given sql which produces:
323 * rowid cat value
324 * ------+-------+-------
325 * row1 cat1 val1
326 * row1 cat2 val2
327 * row1 cat3 val3
328 * row1 cat4 val4
329 * row2 cat1 val5
330 * row2 cat2 val6
331 * row2 cat3 val7
332 * row2 cat4 val8
334 * crosstab returns:
335 * <===== values columns =====>
336 * rowid cat1 cat2 cat3 cat4
337 * ------+-------+-------+-------+-------
338 * row1 val1 val2 val3 val4
339 * row2 val5 val6 val7 val8
341 * NOTES:
342 * 1. SQL result must be ordered by 1,2.
343 * 2. The number of values columns depends on the tuple description
344 * of the function's declared return type. The return type's columns
345 * must match the datatypes of the SQL query's result. The datatype
346 * of the category column can be anything, however.
347 * 3. Missing values (i.e. not enough adjacent rows of same rowid to
348 * fill the number of result values columns) are filled in with nulls.
349 * 4. Extra values (i.e. too many adjacent rows of same rowid to fill
350 * the number of result values columns) are skipped.
351 * 5. Rows with all nulls in the values columns are skipped.
353 PG_FUNCTION_INFO_V1(crosstab);
354 Datum
355 crosstab(PG_FUNCTION_ARGS)
357 char *sql = text_to_cstring(PG_GETARG_TEXT_PP(0));
358 ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
359 Tuplestorestate *tupstore;
360 TupleDesc tupdesc;
361 uint64 call_cntr;
362 uint64 max_calls;
363 AttInMetadata *attinmeta;
364 SPITupleTable *spi_tuptable;
365 TupleDesc spi_tupdesc;
366 bool firstpass;
367 char *lastrowid;
368 int i;
369 int num_categories;
370 MemoryContext per_query_ctx;
371 MemoryContext oldcontext;
372 int ret;
373 uint64 proc;
375 /* check to see if caller supports us returning a tuplestore */
376 if (rsinfo == NULL || !IsA(rsinfo, ReturnSetInfo))
377 ereport(ERROR,
378 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
379 errmsg("set-valued function called in context that cannot accept a set")));
380 if (!(rsinfo->allowedModes & SFRM_Materialize))
381 ereport(ERROR,
382 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
383 errmsg("materialize mode required, but it is not allowed in this context")));
385 per_query_ctx = rsinfo->econtext->ecxt_per_query_memory;
387 /* Connect to SPI manager */
388 if ((ret = SPI_connect()) < 0)
389 /* internal error */
390 elog(ERROR, "crosstab: SPI_connect returned %d", ret);
392 /* Retrieve the desired rows */
393 ret = SPI_execute(sql, true, 0);
394 proc = SPI_processed;
396 /* If no qualifying tuples, fall out early */
397 if (ret != SPI_OK_SELECT || proc == 0)
399 SPI_finish();
400 rsinfo->isDone = ExprEndResult;
401 PG_RETURN_NULL();
404 spi_tuptable = SPI_tuptable;
405 spi_tupdesc = spi_tuptable->tupdesc;
407 /*----------
408 * The provided SQL query must always return three columns.
410 * 1. rowname
411 * the label or identifier for each row in the final result
412 * 2. category
413 * the label or identifier for each column in the final result
414 * 3. values
415 * the value for each column in the final result
416 *----------
418 if (spi_tupdesc->natts != 3)
419 ereport(ERROR,
420 (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
421 errmsg("invalid crosstab source data query"),
422 errdetail("The query must return 3 columns: row_name, category, and value.")));
424 /* get a tuple descriptor for our result type */
425 switch (get_call_result_type(fcinfo, NULL, &tupdesc))
427 case TYPEFUNC_COMPOSITE:
428 /* success */
429 break;
430 case TYPEFUNC_RECORD:
431 /* failed to determine actual type of RECORD */
432 ereport(ERROR,
433 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
434 errmsg("function returning record called in context "
435 "that cannot accept type record")));
436 break;
437 default:
438 /* result type isn't composite */
439 ereport(ERROR,
440 (errcode(ERRCODE_DATATYPE_MISMATCH),
441 errmsg("return type must be a row type")));
442 break;
446 * Check that return tupdesc is compatible with the data we got from SPI,
447 * at least based on number and type of attributes
449 compatCrosstabTupleDescs(tupdesc, spi_tupdesc);
452 * switch to long-lived memory context
454 oldcontext = MemoryContextSwitchTo(per_query_ctx);
456 /* make sure we have a persistent copy of the result tupdesc */
457 tupdesc = CreateTupleDescCopy(tupdesc);
459 /* initialize our tuplestore in long-lived context */
460 tupstore =
461 tuplestore_begin_heap(rsinfo->allowedModes & SFRM_Materialize_Random,
462 false, work_mem);
464 MemoryContextSwitchTo(oldcontext);
467 * Generate attribute metadata needed later to produce tuples from raw C
468 * strings
470 attinmeta = TupleDescGetAttInMetadata(tupdesc);
472 /* total number of tuples to be examined */
473 max_calls = proc;
475 /* the return tuple always must have 1 rowid + num_categories columns */
476 num_categories = tupdesc->natts - 1;
478 firstpass = true;
479 lastrowid = NULL;
481 for (call_cntr = 0; call_cntr < max_calls; call_cntr++)
483 bool skip_tuple = false;
484 char **values;
486 /* allocate and zero space */
487 values = (char **) palloc0((1 + num_categories) * sizeof(char *));
490 * now loop through the sql results and assign each value in sequence
491 * to the next category
493 for (i = 0; i < num_categories; i++)
495 HeapTuple spi_tuple;
496 char *rowid;
498 /* see if we've gone too far already */
499 if (call_cntr >= max_calls)
500 break;
502 /* get the next sql result tuple */
503 spi_tuple = spi_tuptable->vals[call_cntr];
505 /* get the rowid from the current sql result tuple */
506 rowid = SPI_getvalue(spi_tuple, spi_tupdesc, 1);
509 * If this is the first pass through the values for this rowid,
510 * set the first column to rowid
512 if (i == 0)
514 xpstrdup(values[0], rowid);
517 * Check to see if the rowid is the same as that of the last
518 * tuple sent -- if so, skip this tuple entirely
520 if (!firstpass && xstreq(lastrowid, rowid))
522 xpfree(rowid);
523 skip_tuple = true;
524 break;
529 * If rowid hasn't changed on us, continue building the output
530 * tuple.
532 if (xstreq(rowid, values[0]))
535 * Get the next category item value, which is always attribute
536 * number three.
538 * Be careful to assign the value to the array index based on
539 * which category we are presently processing.
541 values[1 + i] = SPI_getvalue(spi_tuple, spi_tupdesc, 3);
544 * increment the counter since we consume a row for each
545 * category, but not for last pass because the outer loop will
546 * do that for us
548 if (i < (num_categories - 1))
549 call_cntr++;
550 xpfree(rowid);
552 else
555 * We'll fill in NULLs for the missing values, but we need to
556 * decrement the counter since this sql result row doesn't
557 * belong to the current output tuple.
559 call_cntr--;
560 xpfree(rowid);
561 break;
565 if (!skip_tuple)
567 HeapTuple tuple;
569 /* build the tuple and store it */
570 tuple = BuildTupleFromCStrings(attinmeta, values);
571 tuplestore_puttuple(tupstore, tuple);
572 heap_freetuple(tuple);
575 /* Remember current rowid */
576 xpfree(lastrowid);
577 xpstrdup(lastrowid, values[0]);
578 firstpass = false;
580 /* Clean up */
581 for (i = 0; i < num_categories + 1; i++)
582 if (values[i] != NULL)
583 pfree(values[i]);
584 pfree(values);
587 /* let the caller know we're sending back a tuplestore */
588 rsinfo->returnMode = SFRM_Materialize;
589 rsinfo->setResult = tupstore;
590 rsinfo->setDesc = tupdesc;
592 /* release SPI related resources (and return to caller's context) */
593 SPI_finish();
595 return (Datum) 0;
599 * crosstab_hash - reimplement crosstab as materialized function and
600 * properly deal with missing values (i.e. don't pack remaining
601 * values to the left)
603 * crosstab - create a crosstab of rowids and values columns from a
604 * SQL statement returning one rowid column, one category column,
605 * and one value column.
607 * e.g. given sql which produces:
609 * rowid cat value
610 * ------+-------+-------
611 * row1 cat1 val1
612 * row1 cat2 val2
613 * row1 cat4 val4
614 * row2 cat1 val5
615 * row2 cat2 val6
616 * row2 cat3 val7
617 * row2 cat4 val8
619 * crosstab returns:
620 * <===== values columns =====>
621 * rowid cat1 cat2 cat3 cat4
622 * ------+-------+-------+-------+-------
623 * row1 val1 val2 null val4
624 * row2 val5 val6 val7 val8
626 * NOTES:
627 * 1. SQL result must be ordered by 1.
628 * 2. The number of values columns depends on the tuple description
629 * of the function's declared return type.
630 * 3. Missing values (i.e. missing category) are filled in with nulls.
631 * 4. Extra values (i.e. not in category results) are skipped.
633 PG_FUNCTION_INFO_V1(crosstab_hash);
634 Datum
635 crosstab_hash(PG_FUNCTION_ARGS)
637 char *sql = text_to_cstring(PG_GETARG_TEXT_PP(0));
638 char *cats_sql = text_to_cstring(PG_GETARG_TEXT_PP(1));
639 ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
640 TupleDesc tupdesc;
641 MemoryContext per_query_ctx;
642 MemoryContext oldcontext;
643 HTAB *crosstab_hash;
645 /* check to see if caller supports us returning a tuplestore */
646 if (rsinfo == NULL || !IsA(rsinfo, ReturnSetInfo))
647 ereport(ERROR,
648 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
649 errmsg("set-valued function called in context that cannot accept a set")));
650 if (!(rsinfo->allowedModes & SFRM_Materialize) ||
651 rsinfo->expectedDesc == NULL)
652 ereport(ERROR,
653 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
654 errmsg("materialize mode required, but it is not allowed in this context")));
656 per_query_ctx = rsinfo->econtext->ecxt_per_query_memory;
657 oldcontext = MemoryContextSwitchTo(per_query_ctx);
659 /* get the requested return tuple description */
660 tupdesc = CreateTupleDescCopy(rsinfo->expectedDesc);
663 * Check to make sure we have a reasonable tuple descriptor
665 * Note we will attempt to coerce the values into whatever the return
666 * attribute type is and depend on the "in" function to complain if
667 * needed.
669 if (tupdesc->natts < 2)
670 ereport(ERROR,
671 (errcode(ERRCODE_DATATYPE_MISMATCH),
672 errmsg("invalid crosstab return type"),
673 errdetail("Return row must have at least two columns.")));
675 /* load up the categories hash table */
676 crosstab_hash = load_categories_hash(cats_sql, per_query_ctx);
678 /* let the caller know we're sending back a tuplestore */
679 rsinfo->returnMode = SFRM_Materialize;
681 /* now go build it */
682 rsinfo->setResult = get_crosstab_tuplestore(sql,
683 crosstab_hash,
684 tupdesc,
685 rsinfo->allowedModes & SFRM_Materialize_Random);
688 * SFRM_Materialize mode expects us to return a NULL Datum. The actual
689 * tuples are in our tuplestore and passed back through rsinfo->setResult.
690 * rsinfo->setDesc is set to the tuple description that we actually used
691 * to build our tuples with, so the caller can verify we did what it was
692 * expecting.
694 rsinfo->setDesc = tupdesc;
695 MemoryContextSwitchTo(oldcontext);
697 return (Datum) 0;
701 * load up the categories hash table
703 static HTAB *
704 load_categories_hash(char *cats_sql, MemoryContext per_query_ctx)
706 HTAB *crosstab_hash;
707 HASHCTL ctl;
708 int ret;
709 uint64 proc;
710 MemoryContext SPIcontext;
712 /* initialize the category hash table */
713 ctl.keysize = MAX_CATNAME_LEN;
714 ctl.entrysize = sizeof(crosstab_HashEnt);
715 ctl.hcxt = per_query_ctx;
718 * use INIT_CATS, defined above as a guess of how many hash table entries
719 * to create, initially
721 crosstab_hash = hash_create("crosstab hash",
722 INIT_CATS,
723 &ctl,
724 HASH_ELEM | HASH_STRINGS | HASH_CONTEXT);
726 /* Connect to SPI manager */
727 if ((ret = SPI_connect()) < 0)
728 /* internal error */
729 elog(ERROR, "load_categories_hash: SPI_connect returned %d", ret);
731 /* Retrieve the category name rows */
732 ret = SPI_execute(cats_sql, true, 0);
733 proc = SPI_processed;
735 /* Check for qualifying tuples */
736 if ((ret == SPI_OK_SELECT) && (proc > 0))
738 SPITupleTable *spi_tuptable = SPI_tuptable;
739 TupleDesc spi_tupdesc = spi_tuptable->tupdesc;
740 uint64 i;
743 * The provided categories SQL query must always return one column:
744 * category - the label or identifier for each column
746 if (spi_tupdesc->natts != 1)
747 ereport(ERROR,
748 (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
749 errmsg("invalid crosstab categories query"),
750 errdetail("The query must return one column.")));
752 for (i = 0; i < proc; i++)
754 crosstab_cat_desc *catdesc;
755 char *catname;
756 HeapTuple spi_tuple;
758 /* get the next sql result tuple */
759 spi_tuple = spi_tuptable->vals[i];
761 /* get the category from the current sql result tuple */
762 catname = SPI_getvalue(spi_tuple, spi_tupdesc, 1);
763 if (catname == NULL)
764 ereport(ERROR,
765 (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
766 errmsg("crosstab category value must not be null")));
768 SPIcontext = MemoryContextSwitchTo(per_query_ctx);
770 catdesc = (crosstab_cat_desc *) palloc(sizeof(crosstab_cat_desc));
771 catdesc->catname = catname;
772 catdesc->attidx = i;
774 /* Add the proc description block to the hashtable */
775 crosstab_HashTableInsert(crosstab_hash, catdesc);
777 MemoryContextSwitchTo(SPIcontext);
781 if (SPI_finish() != SPI_OK_FINISH)
782 /* internal error */
783 elog(ERROR, "load_categories_hash: SPI_finish() failed");
785 return crosstab_hash;
789 * create and populate the crosstab tuplestore using the provided source query
791 static Tuplestorestate *
792 get_crosstab_tuplestore(char *sql,
793 HTAB *crosstab_hash,
794 TupleDesc tupdesc,
795 bool randomAccess)
797 Tuplestorestate *tupstore;
798 int num_categories = hash_get_num_entries(crosstab_hash);
799 AttInMetadata *attinmeta = TupleDescGetAttInMetadata(tupdesc);
800 char **values;
801 HeapTuple tuple;
802 int ret;
803 uint64 proc;
805 /* initialize our tuplestore (while still in query context!) */
806 tupstore = tuplestore_begin_heap(randomAccess, false, work_mem);
808 /* Connect to SPI manager */
809 if ((ret = SPI_connect()) < 0)
810 /* internal error */
811 elog(ERROR, "get_crosstab_tuplestore: SPI_connect returned %d", ret);
813 /* Now retrieve the crosstab source rows */
814 ret = SPI_execute(sql, true, 0);
815 proc = SPI_processed;
817 /* Check for qualifying tuples */
818 if ((ret == SPI_OK_SELECT) && (proc > 0))
820 SPITupleTable *spi_tuptable = SPI_tuptable;
821 TupleDesc spi_tupdesc = spi_tuptable->tupdesc;
822 int ncols = spi_tupdesc->natts;
823 char *rowid;
824 char *lastrowid = NULL;
825 bool firstpass = true;
826 uint64 i;
827 int j;
828 int result_ncols;
830 if (num_categories == 0)
832 /* no qualifying category tuples */
833 ereport(ERROR,
834 (errcode(ERRCODE_CARDINALITY_VIOLATION),
835 errmsg("crosstab categories query must return at least one row")));
839 * The provided SQL query must always return at least three columns:
841 * 1. rowname the label for each row - column 1 in the final result
842 * 2. category the label for each value-column in the final result 3.
843 * value the values used to populate the value-columns
845 * If there are more than three columns, the last two are taken as
846 * "category" and "values". The first column is taken as "rowname".
847 * Additional columns (2 thru N-2) are assumed the same for the same
848 * "rowname", and are copied into the result tuple from the first time
849 * we encounter a particular rowname.
851 if (ncols < 3)
852 ereport(ERROR,
853 (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
854 errmsg("invalid crosstab source data query"),
855 errdetail("The query must return at least 3 columns: row_name, category, and value.")));
857 result_ncols = (ncols - 2) + num_categories;
859 /* Recheck to make sure output tuple descriptor looks reasonable */
860 if (tupdesc->natts != result_ncols)
861 ereport(ERROR,
862 (errcode(ERRCODE_DATATYPE_MISMATCH),
863 errmsg("invalid crosstab return type"),
864 errdetail("Return row must have %d columns, not %d.",
865 result_ncols, tupdesc->natts)));
867 /* allocate space and make sure it's clear */
868 values = (char **) palloc0(result_ncols * sizeof(char *));
870 for (i = 0; i < proc; i++)
872 HeapTuple spi_tuple;
873 crosstab_cat_desc *catdesc;
874 char *catname;
876 /* get the next sql result tuple */
877 spi_tuple = spi_tuptable->vals[i];
879 /* get the rowid from the current sql result tuple */
880 rowid = SPI_getvalue(spi_tuple, spi_tupdesc, 1);
883 * if we're on a new output row, grab the column values up to
884 * column N-2 now
886 if (firstpass || !xstreq(lastrowid, rowid))
889 * a new row means we need to flush the old one first, unless
890 * we're on the very first row
892 if (!firstpass)
894 /* rowid changed, flush the previous output row */
895 tuple = BuildTupleFromCStrings(attinmeta, values);
897 tuplestore_puttuple(tupstore, tuple);
899 for (j = 0; j < result_ncols; j++)
900 xpfree(values[j]);
903 values[0] = rowid;
904 for (j = 1; j < ncols - 2; j++)
905 values[j] = SPI_getvalue(spi_tuple, spi_tupdesc, j + 1);
907 /* we're no longer on the first pass */
908 firstpass = false;
911 /* look up the category and fill in the appropriate column */
912 catname = SPI_getvalue(spi_tuple, spi_tupdesc, ncols - 1);
914 if (catname != NULL)
916 crosstab_HashTableLookup(crosstab_hash, catname, catdesc);
918 if (catdesc)
919 values[catdesc->attidx + ncols - 2] =
920 SPI_getvalue(spi_tuple, spi_tupdesc, ncols);
923 xpfree(lastrowid);
924 xpstrdup(lastrowid, rowid);
927 /* flush the last output row */
928 tuple = BuildTupleFromCStrings(attinmeta, values);
930 tuplestore_puttuple(tupstore, tuple);
933 if (SPI_finish() != SPI_OK_FINISH)
934 /* internal error */
935 elog(ERROR, "get_crosstab_tuplestore: SPI_finish() failed");
937 return tupstore;
941 * connectby_text - produce a result set from a hierarchical (parent/child)
942 * table.
944 * e.g. given table foo:
946 * keyid parent_keyid pos
947 * ------+------------+--
948 * row1 NULL 0
949 * row2 row1 0
950 * row3 row1 0
951 * row4 row2 1
952 * row5 row2 0
953 * row6 row4 0
954 * row7 row3 0
955 * row8 row6 0
956 * row9 row5 0
959 * connectby(text relname, text keyid_fld, text parent_keyid_fld
960 * [, text orderby_fld], text start_with, int max_depth
961 * [, text branch_delim])
962 * connectby('foo', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~') returns:
964 * keyid parent_id level branch serial
965 * ------+-----------+--------+-----------------------
966 * row2 NULL 0 row2 1
967 * row5 row2 1 row2~row5 2
968 * row9 row5 2 row2~row5~row9 3
969 * row4 row2 1 row2~row4 4
970 * row6 row4 2 row2~row4~row6 5
971 * row8 row6 3 row2~row4~row6~row8 6
974 PG_FUNCTION_INFO_V1(connectby_text);
976 #define CONNECTBY_NCOLS 4
977 #define CONNECTBY_NCOLS_NOBRANCH 3
979 Datum
980 connectby_text(PG_FUNCTION_ARGS)
982 char *relname = text_to_cstring(PG_GETARG_TEXT_PP(0));
983 char *key_fld = text_to_cstring(PG_GETARG_TEXT_PP(1));
984 char *parent_key_fld = text_to_cstring(PG_GETARG_TEXT_PP(2));
985 char *start_with = text_to_cstring(PG_GETARG_TEXT_PP(3));
986 int max_depth = PG_GETARG_INT32(4);
987 char *branch_delim = NULL;
988 bool show_branch = false;
989 bool show_serial = false;
990 ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
991 TupleDesc tupdesc;
992 AttInMetadata *attinmeta;
993 MemoryContext per_query_ctx;
994 MemoryContext oldcontext;
996 /* check to see if caller supports us returning a tuplestore */
997 if (rsinfo == NULL || !IsA(rsinfo, ReturnSetInfo))
998 ereport(ERROR,
999 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
1000 errmsg("set-valued function called in context that cannot accept a set")));
1001 if (!(rsinfo->allowedModes & SFRM_Materialize) ||
1002 rsinfo->expectedDesc == NULL)
1003 ereport(ERROR,
1004 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
1005 errmsg("materialize mode required, but it is not allowed in this context")));
1007 if (fcinfo->nargs == 6)
1009 branch_delim = text_to_cstring(PG_GETARG_TEXT_PP(5));
1010 show_branch = true;
1012 else
1013 /* default is no show, tilde for the delimiter */
1014 branch_delim = pstrdup("~");
1016 per_query_ctx = rsinfo->econtext->ecxt_per_query_memory;
1017 oldcontext = MemoryContextSwitchTo(per_query_ctx);
1019 /* get the requested return tuple description */
1020 tupdesc = CreateTupleDescCopy(rsinfo->expectedDesc);
1022 /* does it meet our needs */
1023 validateConnectbyTupleDesc(tupdesc, show_branch, show_serial);
1025 /* OK, use it then */
1026 attinmeta = TupleDescGetAttInMetadata(tupdesc);
1028 /* OK, go to work */
1029 rsinfo->returnMode = SFRM_Materialize;
1030 rsinfo->setResult = connectby(relname,
1031 key_fld,
1032 parent_key_fld,
1033 NULL,
1034 branch_delim,
1035 start_with,
1036 max_depth,
1037 show_branch,
1038 show_serial,
1039 per_query_ctx,
1040 rsinfo->allowedModes & SFRM_Materialize_Random,
1041 attinmeta);
1042 rsinfo->setDesc = tupdesc;
1044 MemoryContextSwitchTo(oldcontext);
1047 * SFRM_Materialize mode expects us to return a NULL Datum. The actual
1048 * tuples are in our tuplestore and passed back through rsinfo->setResult.
1049 * rsinfo->setDesc is set to the tuple description that we actually used
1050 * to build our tuples with, so the caller can verify we did what it was
1051 * expecting.
1053 return (Datum) 0;
1056 PG_FUNCTION_INFO_V1(connectby_text_serial);
1057 Datum
1058 connectby_text_serial(PG_FUNCTION_ARGS)
1060 char *relname = text_to_cstring(PG_GETARG_TEXT_PP(0));
1061 char *key_fld = text_to_cstring(PG_GETARG_TEXT_PP(1));
1062 char *parent_key_fld = text_to_cstring(PG_GETARG_TEXT_PP(2));
1063 char *orderby_fld = text_to_cstring(PG_GETARG_TEXT_PP(3));
1064 char *start_with = text_to_cstring(PG_GETARG_TEXT_PP(4));
1065 int max_depth = PG_GETARG_INT32(5);
1066 char *branch_delim = NULL;
1067 bool show_branch = false;
1068 bool show_serial = true;
1069 ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
1070 TupleDesc tupdesc;
1071 AttInMetadata *attinmeta;
1072 MemoryContext per_query_ctx;
1073 MemoryContext oldcontext;
1075 /* check to see if caller supports us returning a tuplestore */
1076 if (rsinfo == NULL || !IsA(rsinfo, ReturnSetInfo))
1077 ereport(ERROR,
1078 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
1079 errmsg("set-valued function called in context that cannot accept a set")));
1080 if (!(rsinfo->allowedModes & SFRM_Materialize) ||
1081 rsinfo->expectedDesc == NULL)
1082 ereport(ERROR,
1083 (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
1084 errmsg("materialize mode required, but it is not allowed in this context")));
1086 if (fcinfo->nargs == 7)
1088 branch_delim = text_to_cstring(PG_GETARG_TEXT_PP(6));
1089 show_branch = true;
1091 else
1092 /* default is no show, tilde for the delimiter */
1093 branch_delim = pstrdup("~");
1095 per_query_ctx = rsinfo->econtext->ecxt_per_query_memory;
1096 oldcontext = MemoryContextSwitchTo(per_query_ctx);
1098 /* get the requested return tuple description */
1099 tupdesc = CreateTupleDescCopy(rsinfo->expectedDesc);
1101 /* does it meet our needs */
1102 validateConnectbyTupleDesc(tupdesc, show_branch, show_serial);
1104 /* OK, use it then */
1105 attinmeta = TupleDescGetAttInMetadata(tupdesc);
1107 /* OK, go to work */
1108 rsinfo->returnMode = SFRM_Materialize;
1109 rsinfo->setResult = connectby(relname,
1110 key_fld,
1111 parent_key_fld,
1112 orderby_fld,
1113 branch_delim,
1114 start_with,
1115 max_depth,
1116 show_branch,
1117 show_serial,
1118 per_query_ctx,
1119 rsinfo->allowedModes & SFRM_Materialize_Random,
1120 attinmeta);
1121 rsinfo->setDesc = tupdesc;
1123 MemoryContextSwitchTo(oldcontext);
1126 * SFRM_Materialize mode expects us to return a NULL Datum. The actual
1127 * tuples are in our tuplestore and passed back through rsinfo->setResult.
1128 * rsinfo->setDesc is set to the tuple description that we actually used
1129 * to build our tuples with, so the caller can verify we did what it was
1130 * expecting.
1132 return (Datum) 0;
1137 * connectby - does the real work for connectby_text()
1139 static Tuplestorestate *
1140 connectby(char *relname,
1141 char *key_fld,
1142 char *parent_key_fld,
1143 char *orderby_fld,
1144 char *branch_delim,
1145 char *start_with,
1146 int max_depth,
1147 bool show_branch,
1148 bool show_serial,
1149 MemoryContext per_query_ctx,
1150 bool randomAccess,
1151 AttInMetadata *attinmeta)
1153 Tuplestorestate *tupstore = NULL;
1154 int ret;
1155 MemoryContext oldcontext;
1157 int serial = 1;
1159 /* Connect to SPI manager */
1160 if ((ret = SPI_connect()) < 0)
1161 /* internal error */
1162 elog(ERROR, "connectby: SPI_connect returned %d", ret);
1164 /* switch to longer term context to create the tuple store */
1165 oldcontext = MemoryContextSwitchTo(per_query_ctx);
1167 /* initialize our tuplestore */
1168 tupstore = tuplestore_begin_heap(randomAccess, false, work_mem);
1170 MemoryContextSwitchTo(oldcontext);
1172 /* now go get the whole tree */
1173 build_tuplestore_recursively(key_fld,
1174 parent_key_fld,
1175 relname,
1176 orderby_fld,
1177 branch_delim,
1178 start_with,
1179 start_with, /* current_branch */
1180 0, /* initial level is 0 */
1181 &serial, /* initial serial is 1 */
1182 max_depth,
1183 show_branch,
1184 show_serial,
1185 per_query_ctx,
1186 attinmeta,
1187 tupstore);
1189 SPI_finish();
1191 return tupstore;
1194 static void
1195 build_tuplestore_recursively(char *key_fld,
1196 char *parent_key_fld,
1197 char *relname,
1198 char *orderby_fld,
1199 char *branch_delim,
1200 char *start_with,
1201 char *branch,
1202 int level,
1203 int *serial,
1204 int max_depth,
1205 bool show_branch,
1206 bool show_serial,
1207 MemoryContext per_query_ctx,
1208 AttInMetadata *attinmeta,
1209 Tuplestorestate *tupstore)
1211 TupleDesc tupdesc = attinmeta->tupdesc;
1212 int ret;
1213 uint64 proc;
1214 int serial_column;
1215 StringInfoData sql;
1216 char **values;
1217 char *current_key;
1218 char *current_key_parent;
1219 char current_level[INT32_STRLEN];
1220 char serial_str[INT32_STRLEN];
1221 char *current_branch;
1222 HeapTuple tuple;
1224 if (max_depth > 0 && level > max_depth)
1225 return;
1227 initStringInfo(&sql);
1229 /* Build initial sql statement */
1230 if (!show_serial)
1232 appendStringInfo(&sql, "SELECT %s, %s FROM %s WHERE %s = %s AND %s IS NOT NULL AND %s <> %s",
1233 key_fld,
1234 parent_key_fld,
1235 relname,
1236 parent_key_fld,
1237 quote_literal_cstr(start_with),
1238 key_fld, key_fld, parent_key_fld);
1239 serial_column = 0;
1241 else
1243 appendStringInfo(&sql, "SELECT %s, %s FROM %s WHERE %s = %s AND %s IS NOT NULL AND %s <> %s ORDER BY %s",
1244 key_fld,
1245 parent_key_fld,
1246 relname,
1247 parent_key_fld,
1248 quote_literal_cstr(start_with),
1249 key_fld, key_fld, parent_key_fld,
1250 orderby_fld);
1251 serial_column = 1;
1254 if (show_branch)
1255 values = (char **) palloc((CONNECTBY_NCOLS + serial_column) * sizeof(char *));
1256 else
1257 values = (char **) palloc((CONNECTBY_NCOLS_NOBRANCH + serial_column) * sizeof(char *));
1259 /* First time through, do a little setup */
1260 if (level == 0)
1262 /* root value is the one we initially start with */
1263 values[0] = start_with;
1265 /* root value has no parent */
1266 values[1] = NULL;
1268 /* root level is 0 */
1269 sprintf(current_level, "%d", level);
1270 values[2] = current_level;
1272 /* root branch is just starting root value */
1273 if (show_branch)
1274 values[3] = start_with;
1276 /* root starts the serial with 1 */
1277 if (show_serial)
1279 sprintf(serial_str, "%d", (*serial)++);
1280 if (show_branch)
1281 values[4] = serial_str;
1282 else
1283 values[3] = serial_str;
1286 /* construct the tuple */
1287 tuple = BuildTupleFromCStrings(attinmeta, values);
1289 /* now store it */
1290 tuplestore_puttuple(tupstore, tuple);
1292 /* increment level */
1293 level++;
1296 /* Retrieve the desired rows */
1297 ret = SPI_execute(sql.data, true, 0);
1298 proc = SPI_processed;
1300 /* Check for qualifying tuples */
1301 if ((ret == SPI_OK_SELECT) && (proc > 0))
1303 HeapTuple spi_tuple;
1304 SPITupleTable *tuptable = SPI_tuptable;
1305 TupleDesc spi_tupdesc = tuptable->tupdesc;
1306 uint64 i;
1307 StringInfoData branchstr;
1308 StringInfoData chk_branchstr;
1309 StringInfoData chk_current_key;
1312 * Check that return tupdesc is compatible with the one we got from
1313 * the query.
1315 compatConnectbyTupleDescs(tupdesc, spi_tupdesc);
1317 initStringInfo(&branchstr);
1318 initStringInfo(&chk_branchstr);
1319 initStringInfo(&chk_current_key);
1321 for (i = 0; i < proc; i++)
1323 /* initialize branch for this pass */
1324 appendStringInfoString(&branchstr, branch);
1325 appendStringInfo(&chk_branchstr, "%s%s%s", branch_delim, branch, branch_delim);
1327 /* get the next sql result tuple */
1328 spi_tuple = tuptable->vals[i];
1330 /* get the current key (might be NULL) */
1331 current_key = SPI_getvalue(spi_tuple, spi_tupdesc, 1);
1333 /* get the parent key (might be NULL) */
1334 current_key_parent = SPI_getvalue(spi_tuple, spi_tupdesc, 2);
1336 /* get the current level */
1337 sprintf(current_level, "%d", level);
1339 /* check to see if this key is also an ancestor */
1340 if (current_key)
1342 appendStringInfo(&chk_current_key, "%s%s%s",
1343 branch_delim, current_key, branch_delim);
1344 if (strstr(chk_branchstr.data, chk_current_key.data))
1345 ereport(ERROR,
1346 (errcode(ERRCODE_INVALID_RECURSION),
1347 errmsg("infinite recursion detected")));
1350 /* OK, extend the branch */
1351 if (current_key)
1352 appendStringInfo(&branchstr, "%s%s", branch_delim, current_key);
1353 current_branch = branchstr.data;
1355 /* build a tuple */
1356 values[0] = current_key;
1357 values[1] = current_key_parent;
1358 values[2] = current_level;
1359 if (show_branch)
1360 values[3] = current_branch;
1361 if (show_serial)
1363 sprintf(serial_str, "%d", (*serial)++);
1364 if (show_branch)
1365 values[4] = serial_str;
1366 else
1367 values[3] = serial_str;
1370 tuple = BuildTupleFromCStrings(attinmeta, values);
1372 /* store the tuple for later use */
1373 tuplestore_puttuple(tupstore, tuple);
1375 heap_freetuple(tuple);
1377 /* recurse using current_key as the new start_with */
1378 if (current_key)
1379 build_tuplestore_recursively(key_fld,
1380 parent_key_fld,
1381 relname,
1382 orderby_fld,
1383 branch_delim,
1384 current_key,
1385 current_branch,
1386 level + 1,
1387 serial,
1388 max_depth,
1389 show_branch,
1390 show_serial,
1391 per_query_ctx,
1392 attinmeta,
1393 tupstore);
1395 xpfree(current_key);
1396 xpfree(current_key_parent);
1398 /* reset branch for next pass */
1399 resetStringInfo(&branchstr);
1400 resetStringInfo(&chk_branchstr);
1401 resetStringInfo(&chk_current_key);
1404 xpfree(branchstr.data);
1405 xpfree(chk_branchstr.data);
1406 xpfree(chk_current_key.data);
1411 * Check expected (query runtime) tupdesc suitable for Connectby
1413 static void
1414 validateConnectbyTupleDesc(TupleDesc td, bool show_branch, bool show_serial)
1416 int expected_cols;
1418 /* are there the correct number of columns */
1419 if (show_branch)
1420 expected_cols = CONNECTBY_NCOLS;
1421 else
1422 expected_cols = CONNECTBY_NCOLS_NOBRANCH;
1423 if (show_serial)
1424 expected_cols++;
1426 if (td->natts != expected_cols)
1427 ereport(ERROR,
1428 (errcode(ERRCODE_DATATYPE_MISMATCH),
1429 errmsg("invalid connectby return type"),
1430 errdetail("Return row must have %d columns, not %d.",
1431 expected_cols, td->natts)));
1433 /* the first two columns will be checked against the input tuples later */
1435 /* check that the type of the third column is INT4 */
1436 if (TupleDescAttr(td, 2)->atttypid != INT4OID)
1437 ereport(ERROR,
1438 (errcode(ERRCODE_DATATYPE_MISMATCH),
1439 errmsg("invalid connectby return type"),
1440 errdetail("Third return column (depth) must be type %s.",
1441 format_type_be(INT4OID))));
1443 /* check that the type of the branch column is TEXT if applicable */
1444 if (show_branch && TupleDescAttr(td, 3)->atttypid != TEXTOID)
1445 ereport(ERROR,
1446 (errcode(ERRCODE_DATATYPE_MISMATCH),
1447 errmsg("invalid connectby return type"),
1448 errdetail("Fourth return column (branch) must be type %s.",
1449 format_type_be(TEXTOID))));
1451 /* check that the type of the serial column is INT4 if applicable */
1452 if (show_branch && show_serial &&
1453 TupleDescAttr(td, 4)->atttypid != INT4OID)
1454 ereport(ERROR,
1455 (errcode(ERRCODE_DATATYPE_MISMATCH),
1456 errmsg("invalid connectby return type"),
1457 errdetail("Fifth return column (serial) must be type %s.",
1458 format_type_be(INT4OID))));
1459 if (!show_branch && show_serial &&
1460 TupleDescAttr(td, 3)->atttypid != INT4OID)
1461 ereport(ERROR,
1462 (errcode(ERRCODE_DATATYPE_MISMATCH),
1463 errmsg("invalid connectby return type"),
1464 errdetail("Fourth return column (serial) must be type %s.",
1465 format_type_be(INT4OID))));
1467 /* OK, the tupdesc is valid for our purposes */
1471 * Check if output tupdesc and SQL query's tupdesc are compatible
1473 static void
1474 compatConnectbyTupleDescs(TupleDesc ret_tupdesc, TupleDesc sql_tupdesc)
1476 Oid ret_atttypid;
1477 Oid sql_atttypid;
1478 int32 ret_atttypmod;
1479 int32 sql_atttypmod;
1482 * Query result must have at least 2 columns.
1484 if (sql_tupdesc->natts < 2)
1485 ereport(ERROR,
1486 (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
1487 errmsg("invalid connectby source data query"),
1488 errdetail("The query must return at least two columns.")));
1491 * These columns must match the result type indicated by the calling
1492 * query.
1494 ret_atttypid = TupleDescAttr(ret_tupdesc, 0)->atttypid;
1495 sql_atttypid = TupleDescAttr(sql_tupdesc, 0)->atttypid;
1496 ret_atttypmod = TupleDescAttr(ret_tupdesc, 0)->atttypmod;
1497 sql_atttypmod = TupleDescAttr(sql_tupdesc, 0)->atttypmod;
1498 if (ret_atttypid != sql_atttypid ||
1499 (ret_atttypmod >= 0 && ret_atttypmod != sql_atttypmod))
1500 ereport(ERROR,
1501 (errcode(ERRCODE_DATATYPE_MISMATCH),
1502 errmsg("invalid connectby return type"),
1503 errdetail("Source key type %s does not match return key type %s.",
1504 format_type_with_typemod(sql_atttypid, sql_atttypmod),
1505 format_type_with_typemod(ret_atttypid, ret_atttypmod))));
1507 ret_atttypid = TupleDescAttr(ret_tupdesc, 1)->atttypid;
1508 sql_atttypid = TupleDescAttr(sql_tupdesc, 1)->atttypid;
1509 ret_atttypmod = TupleDescAttr(ret_tupdesc, 1)->atttypmod;
1510 sql_atttypmod = TupleDescAttr(sql_tupdesc, 1)->atttypmod;
1511 if (ret_atttypid != sql_atttypid ||
1512 (ret_atttypmod >= 0 && ret_atttypmod != sql_atttypmod))
1513 ereport(ERROR,
1514 (errcode(ERRCODE_DATATYPE_MISMATCH),
1515 errmsg("invalid connectby return type"),
1516 errdetail("Source parent key type %s does not match return parent key type %s.",
1517 format_type_with_typemod(sql_atttypid, sql_atttypmod),
1518 format_type_with_typemod(ret_atttypid, ret_atttypmod))));
1520 /* OK, the two tupdescs are compatible for our purposes */
1524 * Check if crosstab output tupdesc agrees with input tupdesc
1526 static void
1527 compatCrosstabTupleDescs(TupleDesc ret_tupdesc, TupleDesc sql_tupdesc)
1529 int i;
1530 Oid ret_atttypid;
1531 Oid sql_atttypid;
1532 int32 ret_atttypmod;
1533 int32 sql_atttypmod;
1535 if (ret_tupdesc->natts < 2)
1536 ereport(ERROR,
1537 (errcode(ERRCODE_DATATYPE_MISMATCH),
1538 errmsg("invalid crosstab return type"),
1539 errdetail("Return row must have at least two columns.")));
1540 Assert(sql_tupdesc->natts == 3); /* already checked by caller */
1542 /* check the row_name types match */
1543 ret_atttypid = TupleDescAttr(ret_tupdesc, 0)->atttypid;
1544 sql_atttypid = TupleDescAttr(sql_tupdesc, 0)->atttypid;
1545 ret_atttypmod = TupleDescAttr(ret_tupdesc, 0)->atttypmod;
1546 sql_atttypmod = TupleDescAttr(sql_tupdesc, 0)->atttypmod;
1547 if (ret_atttypid != sql_atttypid ||
1548 (ret_atttypmod >= 0 && ret_atttypmod != sql_atttypmod))
1549 ereport(ERROR,
1550 (errcode(ERRCODE_DATATYPE_MISMATCH),
1551 errmsg("invalid crosstab return type"),
1552 errdetail("Source row_name datatype %s does not match return row_name datatype %s.",
1553 format_type_with_typemod(sql_atttypid, sql_atttypmod),
1554 format_type_with_typemod(ret_atttypid, ret_atttypmod))));
1557 * attribute [1] of sql tuple is the category; no need to check it
1558 * attribute [2] of sql tuple should match attributes [1] to [natts - 1]
1559 * of the return tuple
1561 sql_atttypid = TupleDescAttr(sql_tupdesc, 2)->atttypid;
1562 sql_atttypmod = TupleDescAttr(sql_tupdesc, 2)->atttypmod;
1563 for (i = 1; i < ret_tupdesc->natts; i++)
1565 ret_atttypid = TupleDescAttr(ret_tupdesc, i)->atttypid;
1566 ret_atttypmod = TupleDescAttr(ret_tupdesc, i)->atttypmod;
1568 if (ret_atttypid != sql_atttypid ||
1569 (ret_atttypmod >= 0 && ret_atttypmod != sql_atttypmod))
1570 ereport(ERROR,
1571 (errcode(ERRCODE_DATATYPE_MISMATCH),
1572 errmsg("invalid crosstab return type"),
1573 errdetail("Source value datatype %s does not match return value datatype %s in column %d.",
1574 format_type_with_typemod(sql_atttypid, sql_atttypmod),
1575 format_type_with_typemod(ret_atttypid, ret_atttypmod),
1576 i + 1)));
1579 /* OK, the two tupdescs are compatible for our purposes */