mirror of https://github.com/postgres/postgres
Formerly, DTYPE_REC was used only for variables declared as "record";
variables of named composite types used DTYPE_ROW, which is faster for
some purposes but much less flexible. In particular, the ROW code paths
are entirely incapable of dealing with DDL-caused changes to the number
or data types of the columns of a row variable, once a particular plpgsql
function has been parsed for the first time in a session. And, since the
stored representation of a ROW isn't a tuple, there wasn't any easy way
to deal with variables of domain-over-composite types, since the domain
constraint checking code would expect the value to be checked to be a
tuple. A lesser, but still real, annoyance is that ROW format cannot
represent a true NULL composite value, only a row of per-field NULL
values, which is not exactly the same thing.
Hence, switch to using DTYPE_REC for all composite-typed variables,
whether "record", named composite type, or domain over named composite
type. DTYPE_ROW remains but is used only for its native purpose, to
represent a fixed-at-compile-time list of variables, for instance the
targets of an INTO clause.
To accomplish this without taking significant performance losses, introduce
infrastructure that allows storing composite-type variables as "expanded
objects", similar to the "expanded array" infrastructure introduced in
commit 1dc5ebc90
. A composite variable's value is thereby kept (most of
the time) in the form of separate Datums, so that field accesses and
updates are not much more expensive than they were in the ROW format.
This holds the line, more or less, on performance of variables of named
composite types in field-access-intensive microbenchmarks, and makes
variables declared "record" perform much better than before in similar
tests. In addition, the logic involved with enforcing composite-domain
constraints against updates of individual fields is in the expanded
record infrastructure not plpgsql proper, so that it might be reusable
for other purposes.
In further support of this, introduce a typcache feature for assigning a
unique-within-process identifier to each distinct tuple descriptor of
interest; in particular, DDL alterations on composite types result in a new
identifier for that type. This allows very cheap detection of the need to
refresh tupdesc-dependent data. This improves on the "tupDescSeqNo" idea
I had in commit 687f096ea: that assigned identifying sequence numbers to
successive versions of individual composite types, but the numbers were not
unique across different types, nor was there support for assigning numbers
to registered record types.
In passing, allow plpgsql functions to accept as well as return type
"record". There was no good reason for the old restriction, and it
was out of step with most of the other PLs.
Tom Lane, reviewed by Pavel Stehule
Discussion: https://postgr.es/m/8962.1514399547@sss.pgh.pa.us
pull/31/merge
parent
2ac3e6acc2
commit
4b93f57999
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,227 @@ |
|||||||
|
/*-------------------------------------------------------------------------
|
||||||
|
* |
||||||
|
* expandedrecord.h |
||||||
|
* Declarations for composite expanded objects. |
||||||
|
* |
||||||
|
* Portions Copyright (c) 1996-2018, PostgreSQL Global Development Group |
||||||
|
* Portions Copyright (c) 1994, Regents of the University of California |
||||||
|
* |
||||||
|
* src/include/utils/expandedrecord.h |
||||||
|
* |
||||||
|
*------------------------------------------------------------------------- |
||||||
|
*/ |
||||||
|
#ifndef EXPANDEDRECORD_H |
||||||
|
#define EXPANDEDRECORD_H |
||||||
|
|
||||||
|
#include "access/htup.h" |
||||||
|
#include "access/tupdesc.h" |
||||||
|
#include "fmgr.h" |
||||||
|
#include "utils/expandeddatum.h" |
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* An expanded record is contained within a private memory context (as |
||||||
|
* all expanded objects must be) and has a control structure as below. |
||||||
|
* |
||||||
|
* The expanded record might contain a regular "flat" tuple if that was the |
||||||
|
* original input and we've not modified it. Otherwise, the contents are |
||||||
|
* represented by Datum/isnull arrays plus type information. We could also |
||||||
|
* have both forms, if we've deconstructed the original tuple for access |
||||||
|
* purposes but not yet changed it. For pass-by-reference field types, the |
||||||
|
* Datums would point into the flat tuple in this situation. Once we start |
||||||
|
* modifying tuple fields, new pass-by-ref fields are separately palloc'd |
||||||
|
* within the memory context. |
||||||
|
* |
||||||
|
* It's possible to build an expanded record that references a "flat" tuple |
||||||
|
* stored externally, if the caller can guarantee that that tuple will not |
||||||
|
* change for the lifetime of the expanded record. (This frammish is mainly |
||||||
|
* meant to avoid unnecessary data copying in trigger functions.) |
||||||
|
*/ |
||||||
|
#define ER_MAGIC 1384727874 /* ID for debugging crosschecks */ |
||||||
|
|
||||||
|
typedef struct ExpandedRecordHeader |
||||||
|
{ |
||||||
|
/* Standard header for expanded objects */ |
||||||
|
ExpandedObjectHeader hdr; |
||||||
|
|
||||||
|
/* Magic value identifying an expanded record (for debugging only) */ |
||||||
|
int er_magic; |
||||||
|
|
||||||
|
/* Assorted flag bits */ |
||||||
|
int flags; |
||||||
|
#define ER_FLAG_FVALUE_VALID 0x0001 /* fvalue is up to date? */ |
||||||
|
#define ER_FLAG_FVALUE_ALLOCED 0x0002 /* fvalue is local storage? */ |
||||||
|
#define ER_FLAG_DVALUES_VALID 0x0004 /* dvalues/dnulls are up to date? */ |
||||||
|
#define ER_FLAG_DVALUES_ALLOCED 0x0008 /* any field values local storage? */ |
||||||
|
#define ER_FLAG_HAVE_EXTERNAL 0x0010 /* any field values are external? */ |
||||||
|
#define ER_FLAG_TUPDESC_ALLOCED 0x0020 /* tupdesc is local storage? */ |
||||||
|
#define ER_FLAG_IS_DOMAIN 0x0040 /* er_decltypeid is domain? */ |
||||||
|
#define ER_FLAG_IS_DUMMY 0x0080 /* this header is dummy (see below) */ |
||||||
|
/* flag bits that are not to be cleared when replacing tuple data: */ |
||||||
|
#define ER_FLAGS_NON_DATA \ |
||||||
|
(ER_FLAG_TUPDESC_ALLOCED | ER_FLAG_IS_DOMAIN | ER_FLAG_IS_DUMMY) |
||||||
|
|
||||||
|
/* Declared type of the record variable (could be a domain type) */ |
||||||
|
Oid er_decltypeid; |
||||||
|
|
||||||
|
/*
|
||||||
|
* Actual composite type/typmod; never a domain (if ER_FLAG_IS_DOMAIN, |
||||||
|
* these identify the composite base type). These will match |
||||||
|
* er_tupdesc->tdtypeid/tdtypmod, as well as the header fields of |
||||||
|
* composite datums made from or stored in this expanded record. |
||||||
|
*/ |
||||||
|
Oid er_typeid; /* type OID of the composite type */ |
||||||
|
int32 er_typmod; /* typmod of the composite type */ |
||||||
|
|
||||||
|
/*
|
||||||
|
* Tuple descriptor, if we have one, else NULL. This may point to a |
||||||
|
* reference-counted tupdesc originally belonging to the typcache, in |
||||||
|
* which case we use a memory context reset callback to release the |
||||||
|
* refcount. It can also be locally allocated in this object's private |
||||||
|
* context (in which case ER_FLAG_TUPDESC_ALLOCED is set). |
||||||
|
*/ |
||||||
|
TupleDesc er_tupdesc; |
||||||
|
|
||||||
|
/*
|
||||||
|
* Unique-within-process identifier for the tupdesc (see typcache.h). This |
||||||
|
* field will never be equal to INVALID_TUPLEDESC_IDENTIFIER. |
||||||
|
*/ |
||||||
|
uint64 er_tupdesc_id; |
||||||
|
|
||||||
|
/*
|
||||||
|
* If we have a Datum-array representation of the record, it's kept here; |
||||||
|
* else ER_FLAG_DVALUES_VALID is not set, and dvalues/dnulls may be NULL |
||||||
|
* if they've not yet been allocated. If allocated, the dvalues and |
||||||
|
* dnulls arrays are palloc'd within the object private context, and are |
||||||
|
* of length matching er_tupdesc->natts. For pass-by-ref field types, |
||||||
|
* dvalues entries might point either into the fstartptr..fendptr area, or |
||||||
|
* to separately palloc'd chunks. |
||||||
|
*/ |
||||||
|
Datum *dvalues; /* array of Datums */ |
||||||
|
bool *dnulls; /* array of is-null flags for Datums */ |
||||||
|
int nfields; /* length of above arrays */ |
||||||
|
|
||||||
|
/*
|
||||||
|
* flat_size is the current space requirement for the flat equivalent of |
||||||
|
* the expanded record, if known; otherwise it's 0. We store this to make |
||||||
|
* consecutive calls of get_flat_size cheap. If flat_size is not 0, the |
||||||
|
* component values data_len, hoff, and hasnull must be valid too. |
||||||
|
*/ |
||||||
|
Size flat_size; |
||||||
|
|
||||||
|
Size data_len; /* data len within flat_size */ |
||||||
|
int hoff; /* header offset */ |
||||||
|
bool hasnull; /* null bitmap needed? */ |
||||||
|
|
||||||
|
/*
|
||||||
|
* fvalue points to the flat representation if we have one, else it is |
||||||
|
* NULL. If the flat representation is valid (up to date) then |
||||||
|
* ER_FLAG_FVALUE_VALID is set. Even if we've outdated the flat |
||||||
|
* representation due to changes of user fields, it can still be used to |
||||||
|
* fetch system column values. If we have a flat representation then |
||||||
|
* fstartptr/fendptr point to the start and end+1 of its data area; this |
||||||
|
* is so that we can tell which Datum pointers point into the flat |
||||||
|
* representation rather than being pointers to separately palloc'd data. |
||||||
|
*/ |
||||||
|
HeapTuple fvalue; /* might or might not be private storage */ |
||||||
|
char *fstartptr; /* start of its data area */ |
||||||
|
char *fendptr; /* end+1 of its data area */ |
||||||
|
|
||||||
|
/* Working state for domain checking, used if ER_FLAG_IS_DOMAIN is set */ |
||||||
|
MemoryContext er_domain_check_cxt; /* short-term memory context */ |
||||||
|
struct ExpandedRecordHeader *er_dummy_header; /* dummy record header */ |
||||||
|
void *er_domaininfo; /* cache space for domain_check() */ |
||||||
|
|
||||||
|
/* Callback info (it's active if er_mcb.arg is not NULL) */ |
||||||
|
MemoryContextCallback er_mcb; |
||||||
|
} ExpandedRecordHeader; |
||||||
|
|
||||||
|
/* fmgr macros for expanded record objects */ |
||||||
|
#define PG_GETARG_EXPANDED_RECORD(n) DatumGetExpandedRecord(PG_GETARG_DATUM(n)) |
||||||
|
#define ExpandedRecordGetDatum(erh) EOHPGetRWDatum(&(erh)->hdr) |
||||||
|
#define ExpandedRecordGetRODatum(erh) EOHPGetRODatum(&(erh)->hdr) |
||||||
|
#define PG_RETURN_EXPANDED_RECORD(x) PG_RETURN_DATUM(ExpandedRecordGetDatum(x)) |
||||||
|
|
||||||
|
/* assorted other macros */ |
||||||
|
#define ExpandedRecordIsEmpty(erh) \ |
||||||
|
(((erh)->flags & (ER_FLAG_DVALUES_VALID | ER_FLAG_FVALUE_VALID)) == 0) |
||||||
|
#define ExpandedRecordIsDomain(erh) \ |
||||||
|
(((erh)->flags & ER_FLAG_IS_DOMAIN) != 0) |
||||||
|
|
||||||
|
/* this can substitute for TransferExpandedObject() when we already have erh */ |
||||||
|
#define TransferExpandedRecord(erh, cxt) \ |
||||||
|
MemoryContextSetParent((erh)->hdr.eoh_context, cxt) |
||||||
|
|
||||||
|
/* information returned by expanded_record_lookup_field() */ |
||||||
|
typedef struct ExpandedRecordFieldInfo |
||||||
|
{ |
||||||
|
int fnumber; /* field's attr number in record */ |
||||||
|
Oid ftypeid; /* field's type/typmod info */ |
||||||
|
int32 ftypmod; |
||||||
|
Oid fcollation; /* field's collation if any */ |
||||||
|
} ExpandedRecordFieldInfo; |
||||||
|
|
||||||
|
/*
|
||||||
|
* prototypes for functions defined in expandedrecord.c |
||||||
|
*/ |
||||||
|
extern ExpandedRecordHeader *make_expanded_record_from_typeid(Oid type_id, int32 typmod, |
||||||
|
MemoryContext parentcontext); |
||||||
|
extern ExpandedRecordHeader *make_expanded_record_from_tupdesc(TupleDesc tupdesc, |
||||||
|
MemoryContext parentcontext); |
||||||
|
extern ExpandedRecordHeader *make_expanded_record_from_exprecord(ExpandedRecordHeader *olderh, |
||||||
|
MemoryContext parentcontext); |
||||||
|
extern void expanded_record_set_tuple(ExpandedRecordHeader *erh, |
||||||
|
HeapTuple tuple, bool copy); |
||||||
|
extern Datum make_expanded_record_from_datum(Datum recorddatum, |
||||||
|
MemoryContext parentcontext); |
||||||
|
extern TupleDesc expanded_record_fetch_tupdesc(ExpandedRecordHeader *erh); |
||||||
|
extern HeapTuple expanded_record_get_tuple(ExpandedRecordHeader *erh); |
||||||
|
extern ExpandedRecordHeader *DatumGetExpandedRecord(Datum d); |
||||||
|
extern void deconstruct_expanded_record(ExpandedRecordHeader *erh); |
||||||
|
extern bool expanded_record_lookup_field(ExpandedRecordHeader *erh, |
||||||
|
const char *fieldname, |
||||||
|
ExpandedRecordFieldInfo *finfo); |
||||||
|
extern Datum expanded_record_fetch_field(ExpandedRecordHeader *erh, int fnumber, |
||||||
|
bool *isnull); |
||||||
|
extern void expanded_record_set_field_internal(ExpandedRecordHeader *erh, |
||||||
|
int fnumber, |
||||||
|
Datum newValue, bool isnull, |
||||||
|
bool check_constraints); |
||||||
|
extern void expanded_record_set_fields(ExpandedRecordHeader *erh, |
||||||
|
const Datum *newValues, const bool *isnulls); |
||||||
|
|
||||||
|
/* outside code should never call expanded_record_set_field_internal as such */ |
||||||
|
#define expanded_record_set_field(erh, fnumber, newValue, isnull) \ |
||||||
|
expanded_record_set_field_internal(erh, fnumber, newValue, isnull, true) |
||||||
|
|
||||||
|
/*
|
||||||
|
* Inline-able fast cases. The expanded_record_fetch_xxx functions above |
||||||
|
* handle the general cases. |
||||||
|
*/ |
||||||
|
|
||||||
|
/* Get the tupdesc for the expanded record's actual type */ |
||||||
|
static inline TupleDesc |
||||||
|
expanded_record_get_tupdesc(ExpandedRecordHeader *erh) |
||||||
|
{ |
||||||
|
if (likely(erh->er_tupdesc != NULL)) |
||||||
|
return erh->er_tupdesc; |
||||||
|
else |
||||||
|
return expanded_record_fetch_tupdesc(erh); |
||||||
|
} |
||||||
|
|
||||||
|
/* Get value of record field */ |
||||||
|
static inline Datum |
||||||
|
expanded_record_get_field(ExpandedRecordHeader *erh, int fnumber, |
||||||
|
bool *isnull) |
||||||
|
{ |
||||||
|
if ((erh->flags & ER_FLAG_DVALUES_VALID) && |
||||||
|
likely(fnumber > 0 && fnumber <= erh->nfields)) |
||||||
|
{ |
||||||
|
*isnull = erh->dnulls[fnumber - 1]; |
||||||
|
return erh->dvalues[fnumber - 1]; |
||||||
|
} |
||||||
|
else |
||||||
|
return expanded_record_fetch_field(erh, fnumber, isnull); |
||||||
|
} |
||||||
|
|
||||||
|
#endif /* EXPANDEDRECORD_H */ |
@ -0,0 +1,662 @@ |
|||||||
|
-- |
||||||
|
-- Tests for PL/pgSQL handling of composite (record) variables |
||||||
|
-- |
||||||
|
create type two_int4s as (f1 int4, f2 int4); |
||||||
|
create type two_int8s as (q1 int8, q2 int8); |
||||||
|
-- base-case return of a composite type |
||||||
|
create function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1,1)::two_int8s; end $$; |
||||||
|
select retc(42); |
||||||
|
retc |
||||||
|
-------- |
||||||
|
(42,1) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- ok to return a matching record type |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1::int8, 1::int8); end $$; |
||||||
|
select retc(42); |
||||||
|
retc |
||||||
|
-------- |
||||||
|
(42,1) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- we don't currently support implicit casting |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1,1); end $$; |
||||||
|
select retc(42); |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Returned type integer does not match expected type bigint in column 1. |
||||||
|
CONTEXT: PL/pgSQL function retc(integer) while casting return value to function's return type |
||||||
|
-- nor extra columns |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1::int8, 1::int8, 42); end $$; |
||||||
|
select retc(42); |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (3) does not match expected column count (2). |
||||||
|
CONTEXT: PL/pgSQL function retc(integer) while casting return value to function's return type |
||||||
|
-- same cases with an intermediate "record" variable |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1::int8, 1::int8); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
retc |
||||||
|
-------- |
||||||
|
(42,1) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1,1); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Returned type integer does not match expected type bigint in column 1. |
||||||
|
CONTEXT: PL/pgSQL function retc(integer) while casting return value to function's return type |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1::int8, 1::int8, 42); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (3) does not match expected column count (2). |
||||||
|
CONTEXT: PL/pgSQL function retc(integer) while casting return value to function's return type |
||||||
|
-- but, for mostly historical reasons, we do convert when assigning |
||||||
|
-- to a named-composite-type variable |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r two_int8s; begin r := row($1::int8, 1::int8, 42); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
retc |
||||||
|
-------- |
||||||
|
(42,1) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
do $$ declare c two_int8s; |
||||||
|
begin c := row(1,2); raise notice 'c = %', c; end$$; |
||||||
|
NOTICE: c = (1,2) |
||||||
|
do $$ declare c two_int8s; |
||||||
|
begin for c in select 1,2 loop raise notice 'c = %', c; end loop; end$$; |
||||||
|
NOTICE: c = (1,2) |
||||||
|
do $$ declare c4 two_int4s; c8 two_int8s; |
||||||
|
begin |
||||||
|
c8 := row(1,2); |
||||||
|
c4 := c8; |
||||||
|
c8 := c4; |
||||||
|
raise notice 'c4 = %', c4; |
||||||
|
raise notice 'c8 = %', c8; |
||||||
|
end$$; |
||||||
|
NOTICE: c4 = (1,2) |
||||||
|
NOTICE: c8 = (1,2) |
||||||
|
-- check passing composite result to another function |
||||||
|
create function getq1(two_int8s) returns int8 language plpgsql as $$ |
||||||
|
declare r two_int8s; begin r := $1; return r.q1; end $$; |
||||||
|
select getq1(retc(344)); |
||||||
|
getq1 |
||||||
|
------- |
||||||
|
344 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select getq1(row(1,2)); |
||||||
|
getq1 |
||||||
|
------- |
||||||
|
1 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; r2 record; x int8; |
||||||
|
begin |
||||||
|
r1 := retc(345); |
||||||
|
perform getq1(r1); |
||||||
|
x := getq1(r1); |
||||||
|
raise notice 'x = %', x; |
||||||
|
r2 := retc(346); |
||||||
|
perform getq1(r2); |
||||||
|
x := getq1(r2); |
||||||
|
raise notice 'x = %', x; |
||||||
|
end$$; |
||||||
|
NOTICE: x = 345 |
||||||
|
NOTICE: x = 346 |
||||||
|
-- check assignments of composites |
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; r2 two_int8s; r3 record; r4 record; |
||||||
|
begin |
||||||
|
r1 := row(1,2); |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r1 := r1; -- shouldn't do anything |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r2 := r1; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r2.q2 = r1.q1 + 3; -- check that r2 has distinct storage |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r1 := null; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r1 := row(7,11)::two_int8s; |
||||||
|
r2 := r1; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r3 := row(1,2); |
||||||
|
r4 := r3; |
||||||
|
raise notice 'r3 = %', r3; |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
r4.f1 := r4.f1 + 3; -- check that r4 has distinct storage |
||||||
|
raise notice 'r3 = %', r3; |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
r1 := r3; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r4 := r1; |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
r4.q2 := r4.q2 + 1; -- r4's field names have changed |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
end$$; |
||||||
|
NOTICE: r1 = (1,2) |
||||||
|
NOTICE: r1 = (1,2) |
||||||
|
NOTICE: r1 = (1,2) |
||||||
|
NOTICE: r2 = (1,2) |
||||||
|
NOTICE: r1 = (1,2) |
||||||
|
NOTICE: r2 = (1,4) |
||||||
|
NOTICE: r1 = <NULL> |
||||||
|
NOTICE: r2 = (1,4) |
||||||
|
NOTICE: r1 = (7,11) |
||||||
|
NOTICE: r2 = (7,11) |
||||||
|
NOTICE: r3 = (1,2) |
||||||
|
NOTICE: r4 = (1,2) |
||||||
|
NOTICE: r3 = (1,2) |
||||||
|
NOTICE: r4 = (4,2) |
||||||
|
NOTICE: r1 = (1,2) |
||||||
|
NOTICE: r4 = (1,2) |
||||||
|
NOTICE: r4 = (1,3) |
||||||
|
-- fields of named-type vars read as null if uninitialized |
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; |
||||||
|
begin |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.q1 = %', r1.q1; |
||||||
|
raise notice 'r1.q2 = %', r1.q2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
end$$; |
||||||
|
NOTICE: r1 = <NULL> |
||||||
|
NOTICE: r1.q1 = <NULL> |
||||||
|
NOTICE: r1.q2 = <NULL> |
||||||
|
NOTICE: r1 = <NULL> |
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; |
||||||
|
begin |
||||||
|
raise notice 'r1.q1 = %', r1.q1; |
||||||
|
raise notice 'r1.q2 = %', r1.q2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.nosuchfield = %', r1.nosuchfield; |
||||||
|
end$$; |
||||||
|
NOTICE: r1.q1 = <NULL> |
||||||
|
NOTICE: r1.q2 = <NULL> |
||||||
|
NOTICE: r1 = <NULL> |
||||||
|
ERROR: record "r1" has no field "nosuchfield" |
||||||
|
CONTEXT: SQL statement "SELECT r1.nosuchfield" |
||||||
|
PL/pgSQL function inline_code_block line 7 at RAISE |
||||||
|
-- records, not so much |
||||||
|
do $$ |
||||||
|
declare r1 record; |
||||||
|
begin |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.f1 = %', r1.f1; |
||||||
|
raise notice 'r1.f2 = %', r1.f2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
end$$; |
||||||
|
NOTICE: r1 = <NULL> |
||||||
|
ERROR: record "r1" is not assigned yet |
||||||
|
DETAIL: The tuple structure of a not-yet-assigned record is indeterminate. |
||||||
|
CONTEXT: SQL statement "SELECT r1.f1" |
||||||
|
PL/pgSQL function inline_code_block line 5 at RAISE |
||||||
|
-- but OK if you assign first |
||||||
|
do $$ |
||||||
|
declare r1 record; |
||||||
|
begin |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r1 := row(1,2); |
||||||
|
raise notice 'r1.f1 = %', r1.f1; |
||||||
|
raise notice 'r1.f2 = %', r1.f2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.nosuchfield = %', r1.nosuchfield; |
||||||
|
end$$; |
||||||
|
NOTICE: r1 = <NULL> |
||||||
|
NOTICE: r1.f1 = 1 |
||||||
|
NOTICE: r1.f2 = 2 |
||||||
|
NOTICE: r1 = (1,2) |
||||||
|
ERROR: record "r1" has no field "nosuchfield" |
||||||
|
CONTEXT: SQL statement "SELECT r1.nosuchfield" |
||||||
|
PL/pgSQL function inline_code_block line 9 at RAISE |
||||||
|
-- check repeated assignments to composite fields |
||||||
|
create table some_table (id int, data text); |
||||||
|
do $$ |
||||||
|
declare r some_table; |
||||||
|
begin |
||||||
|
r := (23, 'skidoo'); |
||||||
|
for i in 1 .. 10 loop |
||||||
|
r.id := r.id + i; |
||||||
|
r.data := r.data || ' ' || i; |
||||||
|
end loop; |
||||||
|
raise notice 'r = %', r; |
||||||
|
end$$; |
||||||
|
NOTICE: r = (78,"skidoo 1 2 3 4 5 6 7 8 9 10") |
||||||
|
-- check behavior of function declared to return "record" |
||||||
|
create function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ begin return row($1,$1+1); end $$; |
||||||
|
select returnsrecord(42); |
||||||
|
returnsrecord |
||||||
|
--------------- |
||||||
|
(42,43) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
x | y |
||||||
|
----+---- |
||||||
|
42 | 43 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (2) does not match expected column count (3). |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Returned type integer does not match expected type bigint in column 2. |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
-- same with an intermediate record variable |
||||||
|
create or replace function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1,$1+1); return r; end $$; |
||||||
|
select returnsrecord(42); |
||||||
|
returnsrecord |
||||||
|
--------------- |
||||||
|
(42,43) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
x | y |
||||||
|
----+---- |
||||||
|
42 | 43 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (2) does not match expected column count (3). |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Returned type integer does not match expected type bigint in column 2. |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
-- should work the same with a missing column in the actual result value |
||||||
|
create table has_hole(f1 int, f2 int, f3 int); |
||||||
|
alter table has_hole drop column f2; |
||||||
|
create or replace function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ begin return row($1,$1+1)::has_hole; end $$; |
||||||
|
select returnsrecord(42); |
||||||
|
returnsrecord |
||||||
|
--------------- |
||||||
|
(42,43) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
x | y |
||||||
|
----+---- |
||||||
|
42 | 43 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (2) does not match expected column count (3). |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Returned type integer does not match expected type bigint in column 2. |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
-- same with an intermediate record variable |
||||||
|
create or replace function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1,$1+1)::has_hole; return r; end $$; |
||||||
|
select returnsrecord(42); |
||||||
|
returnsrecord |
||||||
|
--------------- |
||||||
|
(42,43) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
x | y |
||||||
|
----+---- |
||||||
|
42 | 43 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (2) does not match expected column count (3). |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Returned type integer does not match expected type bigint in column 2. |
||||||
|
CONTEXT: PL/pgSQL function returnsrecord(integer) while casting return value to function's return type |
||||||
|
-- check access to a field of an argument declared "record" |
||||||
|
create function getf1(x record) returns int language plpgsql as |
||||||
|
$$ begin return x.f1; end $$; |
||||||
|
select getf1(1); |
||||||
|
ERROR: function getf1(integer) does not exist |
||||||
|
LINE 1: select getf1(1); |
||||||
|
^ |
||||||
|
HINT: No function matches the given name and argument types. You might need to add explicit type casts. |
||||||
|
select getf1(row(1,2)); |
||||||
|
getf1 |
||||||
|
------- |
||||||
|
1 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select getf1(row(1,2)::two_int8s); |
||||||
|
ERROR: record "x" has no field "f1" |
||||||
|
CONTEXT: PL/pgSQL function getf1(record) line 1 at RETURN |
||||||
|
select getf1(row(1,2)); |
||||||
|
getf1 |
||||||
|
------- |
||||||
|
1 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- check behavior when assignment to FOR-loop variable requires coercion |
||||||
|
do $$ |
||||||
|
declare r two_int8s; |
||||||
|
begin |
||||||
|
for r in select i, i+1 from generate_series(1,4) i |
||||||
|
loop |
||||||
|
raise notice 'r = %', r; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
NOTICE: r = (1,2) |
||||||
|
NOTICE: r = (2,3) |
||||||
|
NOTICE: r = (3,4) |
||||||
|
NOTICE: r = (4,5) |
||||||
|
-- check behavior when returning setof composite |
||||||
|
create function returnssetofholes() returns setof has_hole language plpgsql as |
||||||
|
$$ |
||||||
|
declare r record; |
||||||
|
h has_hole; |
||||||
|
begin |
||||||
|
return next h; |
||||||
|
r := (1,2); |
||||||
|
h := (3,4); |
||||||
|
return next r; |
||||||
|
return next h; |
||||||
|
return next row(5,6); |
||||||
|
return next row(7,8)::has_hole; |
||||||
|
end$$; |
||||||
|
select returnssetofholes(); |
||||||
|
returnssetofholes |
||||||
|
------------------- |
||||||
|
(,) |
||||||
|
(1,2) |
||||||
|
(3,4) |
||||||
|
(5,6) |
||||||
|
(7,8) |
||||||
|
(5 rows) |
||||||
|
|
||||||
|
create or replace function returnssetofholes() returns setof has_hole language plpgsql as |
||||||
|
$$ |
||||||
|
declare r record; |
||||||
|
begin |
||||||
|
return next r; -- fails, not assigned yet |
||||||
|
end$$; |
||||||
|
select returnssetofholes(); |
||||||
|
ERROR: record "r" is not assigned yet |
||||||
|
DETAIL: The tuple structure of a not-yet-assigned record is indeterminate. |
||||||
|
CONTEXT: PL/pgSQL function returnssetofholes() line 4 at RETURN NEXT |
||||||
|
create or replace function returnssetofholes() returns setof has_hole language plpgsql as |
||||||
|
$$ |
||||||
|
begin |
||||||
|
return next row(1,2,3); -- fails |
||||||
|
end$$; |
||||||
|
select returnssetofholes(); |
||||||
|
ERROR: returned record type does not match expected record type |
||||||
|
DETAIL: Number of returned columns (3) does not match expected column count (2). |
||||||
|
CONTEXT: PL/pgSQL function returnssetofholes() line 3 at RETURN NEXT |
||||||
|
-- check behavior with changes of a named rowtype |
||||||
|
create table mutable(f1 int, f2 text); |
||||||
|
create function sillyaddone(int) returns int language plpgsql as |
||||||
|
$$ declare r mutable; begin r.f1 := $1; return r.f1 + 1; end $$; |
||||||
|
select sillyaddone(42); |
||||||
|
sillyaddone |
||||||
|
------------- |
||||||
|
43 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
alter table mutable drop column f1; |
||||||
|
alter table mutable add column f1 float8; |
||||||
|
-- currently, this fails due to cached plan for "r.f1 + 1" expression |
||||||
|
select sillyaddone(42); |
||||||
|
ERROR: type of parameter 4 (double precision) does not match that when preparing the plan (integer) |
||||||
|
CONTEXT: PL/pgSQL function sillyaddone(integer) line 1 at RETURN |
||||||
|
\c - |
||||||
|
-- but it's OK after a reconnect |
||||||
|
select sillyaddone(42); |
||||||
|
sillyaddone |
||||||
|
------------- |
||||||
|
43 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
alter table mutable drop column f1; |
||||||
|
select sillyaddone(42); -- fail |
||||||
|
ERROR: record "r" has no field "f1" |
||||||
|
CONTEXT: PL/pgSQL function sillyaddone(integer) line 1 at assignment |
||||||
|
create function getf3(x mutable) returns int language plpgsql as |
||||||
|
$$ begin return x.f3; end $$; |
||||||
|
select getf3(null::mutable); -- doesn't work yet |
||||||
|
ERROR: record "x" has no field "f3" |
||||||
|
CONTEXT: SQL statement "SELECT x.f3" |
||||||
|
PL/pgSQL function getf3(mutable) line 1 at RETURN |
||||||
|
alter table mutable add column f3 int; |
||||||
|
select getf3(null::mutable); -- now it works |
||||||
|
getf3 |
||||||
|
------- |
||||||
|
|
||||||
|
(1 row) |
||||||
|
|
||||||
|
alter table mutable drop column f3; |
||||||
|
select getf3(null::mutable); -- fails again |
||||||
|
ERROR: record "x" has no field "f3" |
||||||
|
CONTEXT: PL/pgSQL function getf3(mutable) line 1 at RETURN |
||||||
|
-- check access to system columns in a record variable |
||||||
|
create function sillytrig() returns trigger language plpgsql as |
||||||
|
$$begin |
||||||
|
raise notice 'old.ctid = %', old.ctid; |
||||||
|
raise notice 'old.tableoid = %', old.tableoid::regclass; |
||||||
|
return new; |
||||||
|
end$$; |
||||||
|
create trigger mutable_trig before update on mutable for each row |
||||||
|
execute procedure sillytrig(); |
||||||
|
insert into mutable values ('foo'), ('bar'); |
||||||
|
update mutable set f2 = f2 || ' baz'; |
||||||
|
NOTICE: old.ctid = (0,1) |
||||||
|
NOTICE: old.tableoid = mutable |
||||||
|
NOTICE: old.ctid = (0,2) |
||||||
|
NOTICE: old.tableoid = mutable |
||||||
|
table mutable; |
||||||
|
f2 |
||||||
|
--------- |
||||||
|
foo baz |
||||||
|
bar baz |
||||||
|
(2 rows) |
||||||
|
|
||||||
|
-- check returning a composite datum from a trigger |
||||||
|
create or replace function sillytrig() returns trigger language plpgsql as |
||||||
|
$$begin |
||||||
|
return row(new.*); |
||||||
|
end$$; |
||||||
|
update mutable set f2 = f2 || ' baz'; |
||||||
|
table mutable; |
||||||
|
f2 |
||||||
|
------------- |
||||||
|
foo baz baz |
||||||
|
bar baz baz |
||||||
|
(2 rows) |
||||||
|
|
||||||
|
create or replace function sillytrig() returns trigger language plpgsql as |
||||||
|
$$declare r record; |
||||||
|
begin |
||||||
|
r := row(new.*); |
||||||
|
return r; |
||||||
|
end$$; |
||||||
|
update mutable set f2 = f2 || ' baz'; |
||||||
|
table mutable; |
||||||
|
f2 |
||||||
|
----------------- |
||||||
|
foo baz baz baz |
||||||
|
bar baz baz baz |
||||||
|
(2 rows) |
||||||
|
|
||||||
|
-- |
||||||
|
-- Domains of composite |
||||||
|
-- |
||||||
|
create domain ordered_int8s as two_int8s check((value).q1 <= (value).q2); |
||||||
|
create function read_ordered_int8s(p ordered_int8s) returns int8 as $$ |
||||||
|
begin return p.q1 + p.q2; end |
||||||
|
$$ language plpgsql; |
||||||
|
select read_ordered_int8s(row(1, 2)); |
||||||
|
read_ordered_int8s |
||||||
|
-------------------- |
||||||
|
3 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select read_ordered_int8s(row(2, 1)); -- fail |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
create function build_ordered_int8s(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
begin return row(i,j); end |
||||||
|
$$ language plpgsql; |
||||||
|
select build_ordered_int8s(1,2); |
||||||
|
build_ordered_int8s |
||||||
|
--------------------- |
||||||
|
(1,2) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select build_ordered_int8s(2,1); -- fail |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function build_ordered_int8s(bigint,bigint) while casting return value to function's return type |
||||||
|
create function build_ordered_int8s_2(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
declare r record; begin r := row(i,j); return r; end |
||||||
|
$$ language plpgsql; |
||||||
|
select build_ordered_int8s_2(1,2); |
||||||
|
build_ordered_int8s_2 |
||||||
|
----------------------- |
||||||
|
(1,2) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select build_ordered_int8s_2(2,1); -- fail |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function build_ordered_int8s_2(bigint,bigint) while casting return value to function's return type |
||||||
|
create function build_ordered_int8s_3(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
declare r two_int8s; begin r := row(i,j); return r; end |
||||||
|
$$ language plpgsql; |
||||||
|
select build_ordered_int8s_3(1,2); |
||||||
|
build_ordered_int8s_3 |
||||||
|
----------------------- |
||||||
|
(1,2) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select build_ordered_int8s_3(2,1); -- fail |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function build_ordered_int8s_3(bigint,bigint) while casting return value to function's return type |
||||||
|
create function build_ordered_int8s_4(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
declare r ordered_int8s; begin r := row(i,j); return r; end |
||||||
|
$$ language plpgsql; |
||||||
|
select build_ordered_int8s_4(1,2); |
||||||
|
build_ordered_int8s_4 |
||||||
|
----------------------- |
||||||
|
(1,2) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select build_ordered_int8s_4(2,1); -- fail |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function build_ordered_int8s_4(bigint,bigint) line 2 at assignment |
||||||
|
create function build_ordered_int8s_a(i int8, j int8) returns ordered_int8s[] as $$ |
||||||
|
begin return array[row(i,j), row(i,j+1)]; end |
||||||
|
$$ language plpgsql; |
||||||
|
select build_ordered_int8s_a(1,2); |
||||||
|
build_ordered_int8s_a |
||||||
|
----------------------- |
||||||
|
{"(1,2)","(1,3)"} |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select build_ordered_int8s_a(2,1); -- fail |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function build_ordered_int8s_a(bigint,bigint) while casting return value to function's return type |
||||||
|
-- check field assignment |
||||||
|
do $$ |
||||||
|
declare r ordered_int8s; |
||||||
|
begin |
||||||
|
r.q1 := null; |
||||||
|
r.q2 := 43; |
||||||
|
r.q1 := 42; |
||||||
|
r.q2 := 41; -- fail |
||||||
|
end$$; |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function inline_code_block line 7 at assignment |
||||||
|
-- check whole-row assignment |
||||||
|
do $$ |
||||||
|
declare r ordered_int8s; |
||||||
|
begin |
||||||
|
r := null; |
||||||
|
r := row(null,null); |
||||||
|
r := row(1,2); |
||||||
|
r := row(2,1); -- fail |
||||||
|
end$$; |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function inline_code_block line 7 at assignment |
||||||
|
-- check assignment in for-loop |
||||||
|
do $$ |
||||||
|
declare r ordered_int8s; |
||||||
|
begin |
||||||
|
for r in values (1,2),(3,4),(6,5) loop |
||||||
|
raise notice 'r = %', r; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
NOTICE: r = (1,2) |
||||||
|
NOTICE: r = (3,4) |
||||||
|
ERROR: value for domain ordered_int8s violates check constraint "ordered_int8s_check" |
||||||
|
CONTEXT: PL/pgSQL function inline_code_block line 4 at FOR over SELECT rows |
||||||
|
-- check behavior with toastable fields, too |
||||||
|
create type two_texts as (f1 text, f2 text); |
||||||
|
create domain ordered_texts as two_texts check((value).f1 <= (value).f2); |
||||||
|
create table sometable (id int, a text, b text); |
||||||
|
-- b should be compressed, but in-line |
||||||
|
insert into sometable values (1, 'a', repeat('ffoob',1000)); |
||||||
|
-- this b should be out-of-line |
||||||
|
insert into sometable values (2, 'a', repeat('ffoob',100000)); |
||||||
|
-- this pair should fail the domain check |
||||||
|
insert into sometable values (3, 'z', repeat('ffoob',100000)); |
||||||
|
do $$ |
||||||
|
declare d ordered_texts; |
||||||
|
begin |
||||||
|
for d in select a, b from sometable loop |
||||||
|
raise notice 'succeeded at "%"', d.f1; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
NOTICE: succeeded at "a" |
||||||
|
NOTICE: succeeded at "a" |
||||||
|
ERROR: value for domain ordered_texts violates check constraint "ordered_texts_check" |
||||||
|
CONTEXT: PL/pgSQL function inline_code_block line 4 at FOR over SELECT rows |
||||||
|
do $$ |
||||||
|
declare r record; d ordered_texts; |
||||||
|
begin |
||||||
|
for r in select * from sometable loop |
||||||
|
raise notice 'processing row %', r.id; |
||||||
|
d := row(r.a, r.b); |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
NOTICE: processing row 1 |
||||||
|
NOTICE: processing row 2 |
||||||
|
NOTICE: processing row 3 |
||||||
|
ERROR: value for domain ordered_texts violates check constraint "ordered_texts_check" |
||||||
|
CONTEXT: PL/pgSQL function inline_code_block line 6 at assignment |
||||||
|
do $$ |
||||||
|
declare r record; d ordered_texts; |
||||||
|
begin |
||||||
|
for r in select * from sometable loop |
||||||
|
raise notice 'processing row %', r.id; |
||||||
|
d := null; |
||||||
|
d.f1 := r.a; |
||||||
|
d.f2 := r.b; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
NOTICE: processing row 1 |
||||||
|
NOTICE: processing row 2 |
||||||
|
NOTICE: processing row 3 |
||||||
|
ERROR: value for domain ordered_texts violates check constraint "ordered_texts_check" |
||||||
|
CONTEXT: PL/pgSQL function inline_code_block line 8 at assignment |
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,441 @@ |
|||||||
|
-- |
||||||
|
-- Tests for PL/pgSQL handling of composite (record) variables |
||||||
|
-- |
||||||
|
|
||||||
|
create type two_int4s as (f1 int4, f2 int4); |
||||||
|
create type two_int8s as (q1 int8, q2 int8); |
||||||
|
|
||||||
|
-- base-case return of a composite type |
||||||
|
create function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1,1)::two_int8s; end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
-- ok to return a matching record type |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1::int8, 1::int8); end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
-- we don't currently support implicit casting |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1,1); end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
-- nor extra columns |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ begin return row($1::int8, 1::int8, 42); end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
-- same cases with an intermediate "record" variable |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1::int8, 1::int8); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1,1); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1::int8, 1::int8, 42); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
-- but, for mostly historical reasons, we do convert when assigning |
||||||
|
-- to a named-composite-type variable |
||||||
|
create or replace function retc(int) returns two_int8s language plpgsql as |
||||||
|
$$ declare r two_int8s; begin r := row($1::int8, 1::int8, 42); return r; end $$; |
||||||
|
select retc(42); |
||||||
|
|
||||||
|
do $$ declare c two_int8s; |
||||||
|
begin c := row(1,2); raise notice 'c = %', c; end$$; |
||||||
|
|
||||||
|
do $$ declare c two_int8s; |
||||||
|
begin for c in select 1,2 loop raise notice 'c = %', c; end loop; end$$; |
||||||
|
|
||||||
|
do $$ declare c4 two_int4s; c8 two_int8s; |
||||||
|
begin |
||||||
|
c8 := row(1,2); |
||||||
|
c4 := c8; |
||||||
|
c8 := c4; |
||||||
|
raise notice 'c4 = %', c4; |
||||||
|
raise notice 'c8 = %', c8; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check passing composite result to another function |
||||||
|
create function getq1(two_int8s) returns int8 language plpgsql as $$ |
||||||
|
declare r two_int8s; begin r := $1; return r.q1; end $$; |
||||||
|
|
||||||
|
select getq1(retc(344)); |
||||||
|
select getq1(row(1,2)); |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; r2 record; x int8; |
||||||
|
begin |
||||||
|
r1 := retc(345); |
||||||
|
perform getq1(r1); |
||||||
|
x := getq1(r1); |
||||||
|
raise notice 'x = %', x; |
||||||
|
r2 := retc(346); |
||||||
|
perform getq1(r2); |
||||||
|
x := getq1(r2); |
||||||
|
raise notice 'x = %', x; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check assignments of composites |
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; r2 two_int8s; r3 record; r4 record; |
||||||
|
begin |
||||||
|
r1 := row(1,2); |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r1 := r1; -- shouldn't do anything |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r2 := r1; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r2.q2 = r1.q1 + 3; -- check that r2 has distinct storage |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r1 := null; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r1 := row(7,11)::two_int8s; |
||||||
|
r2 := r1; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r2 = %', r2; |
||||||
|
r3 := row(1,2); |
||||||
|
r4 := r3; |
||||||
|
raise notice 'r3 = %', r3; |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
r4.f1 := r4.f1 + 3; -- check that r4 has distinct storage |
||||||
|
raise notice 'r3 = %', r3; |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
r1 := r3; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r4 := r1; |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
r4.q2 := r4.q2 + 1; -- r4's field names have changed |
||||||
|
raise notice 'r4 = %', r4; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- fields of named-type vars read as null if uninitialized |
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; |
||||||
|
begin |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.q1 = %', r1.q1; |
||||||
|
raise notice 'r1.q2 = %', r1.q2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
end$$; |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare r1 two_int8s; |
||||||
|
begin |
||||||
|
raise notice 'r1.q1 = %', r1.q1; |
||||||
|
raise notice 'r1.q2 = %', r1.q2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.nosuchfield = %', r1.nosuchfield; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- records, not so much |
||||||
|
do $$ |
||||||
|
declare r1 record; |
||||||
|
begin |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.f1 = %', r1.f1; |
||||||
|
raise notice 'r1.f2 = %', r1.f2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- but OK if you assign first |
||||||
|
do $$ |
||||||
|
declare r1 record; |
||||||
|
begin |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
r1 := row(1,2); |
||||||
|
raise notice 'r1.f1 = %', r1.f1; |
||||||
|
raise notice 'r1.f2 = %', r1.f2; |
||||||
|
raise notice 'r1 = %', r1; |
||||||
|
raise notice 'r1.nosuchfield = %', r1.nosuchfield; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check repeated assignments to composite fields |
||||||
|
create table some_table (id int, data text); |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare r some_table; |
||||||
|
begin |
||||||
|
r := (23, 'skidoo'); |
||||||
|
for i in 1 .. 10 loop |
||||||
|
r.id := r.id + i; |
||||||
|
r.data := r.data || ' ' || i; |
||||||
|
end loop; |
||||||
|
raise notice 'r = %', r; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check behavior of function declared to return "record" |
||||||
|
|
||||||
|
create function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ begin return row($1,$1+1); end $$; |
||||||
|
|
||||||
|
select returnsrecord(42); |
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
|
||||||
|
-- same with an intermediate record variable |
||||||
|
create or replace function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1,$1+1); return r; end $$; |
||||||
|
|
||||||
|
select returnsrecord(42); |
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
|
||||||
|
-- should work the same with a missing column in the actual result value |
||||||
|
create table has_hole(f1 int, f2 int, f3 int); |
||||||
|
alter table has_hole drop column f2; |
||||||
|
|
||||||
|
create or replace function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ begin return row($1,$1+1)::has_hole; end $$; |
||||||
|
|
||||||
|
select returnsrecord(42); |
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
|
||||||
|
-- same with an intermediate record variable |
||||||
|
create or replace function returnsrecord(int) returns record language plpgsql as |
||||||
|
$$ declare r record; begin r := row($1,$1+1)::has_hole; return r; end $$; |
||||||
|
|
||||||
|
select returnsrecord(42); |
||||||
|
select * from returnsrecord(42) as r(x int, y int); |
||||||
|
select * from returnsrecord(42) as r(x int, y int, z int); -- fail |
||||||
|
select * from returnsrecord(42) as r(x int, y bigint); -- fail |
||||||
|
|
||||||
|
-- check access to a field of an argument declared "record" |
||||||
|
create function getf1(x record) returns int language plpgsql as |
||||||
|
$$ begin return x.f1; end $$; |
||||||
|
select getf1(1); |
||||||
|
select getf1(row(1,2)); |
||||||
|
select getf1(row(1,2)::two_int8s); |
||||||
|
select getf1(row(1,2)); |
||||||
|
|
||||||
|
-- check behavior when assignment to FOR-loop variable requires coercion |
||||||
|
do $$ |
||||||
|
declare r two_int8s; |
||||||
|
begin |
||||||
|
for r in select i, i+1 from generate_series(1,4) i |
||||||
|
loop |
||||||
|
raise notice 'r = %', r; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check behavior when returning setof composite |
||||||
|
create function returnssetofholes() returns setof has_hole language plpgsql as |
||||||
|
$$ |
||||||
|
declare r record; |
||||||
|
h has_hole; |
||||||
|
begin |
||||||
|
return next h; |
||||||
|
r := (1,2); |
||||||
|
h := (3,4); |
||||||
|
return next r; |
||||||
|
return next h; |
||||||
|
return next row(5,6); |
||||||
|
return next row(7,8)::has_hole; |
||||||
|
end$$; |
||||||
|
select returnssetofholes(); |
||||||
|
|
||||||
|
create or replace function returnssetofholes() returns setof has_hole language plpgsql as |
||||||
|
$$ |
||||||
|
declare r record; |
||||||
|
begin |
||||||
|
return next r; -- fails, not assigned yet |
||||||
|
end$$; |
||||||
|
select returnssetofholes(); |
||||||
|
|
||||||
|
create or replace function returnssetofholes() returns setof has_hole language plpgsql as |
||||||
|
$$ |
||||||
|
begin |
||||||
|
return next row(1,2,3); -- fails |
||||||
|
end$$; |
||||||
|
select returnssetofholes(); |
||||||
|
|
||||||
|
-- check behavior with changes of a named rowtype |
||||||
|
create table mutable(f1 int, f2 text); |
||||||
|
|
||||||
|
create function sillyaddone(int) returns int language plpgsql as |
||||||
|
$$ declare r mutable; begin r.f1 := $1; return r.f1 + 1; end $$; |
||||||
|
select sillyaddone(42); |
||||||
|
|
||||||
|
alter table mutable drop column f1; |
||||||
|
alter table mutable add column f1 float8; |
||||||
|
|
||||||
|
-- currently, this fails due to cached plan for "r.f1 + 1" expression |
||||||
|
select sillyaddone(42); |
||||||
|
\c - |
||||||
|
-- but it's OK after a reconnect |
||||||
|
select sillyaddone(42); |
||||||
|
|
||||||
|
alter table mutable drop column f1; |
||||||
|
select sillyaddone(42); -- fail |
||||||
|
|
||||||
|
create function getf3(x mutable) returns int language plpgsql as |
||||||
|
$$ begin return x.f3; end $$; |
||||||
|
select getf3(null::mutable); -- doesn't work yet |
||||||
|
alter table mutable add column f3 int; |
||||||
|
select getf3(null::mutable); -- now it works |
||||||
|
alter table mutable drop column f3; |
||||||
|
select getf3(null::mutable); -- fails again |
||||||
|
|
||||||
|
-- check access to system columns in a record variable |
||||||
|
|
||||||
|
create function sillytrig() returns trigger language plpgsql as |
||||||
|
$$begin |
||||||
|
raise notice 'old.ctid = %', old.ctid; |
||||||
|
raise notice 'old.tableoid = %', old.tableoid::regclass; |
||||||
|
return new; |
||||||
|
end$$; |
||||||
|
|
||||||
|
create trigger mutable_trig before update on mutable for each row |
||||||
|
execute procedure sillytrig(); |
||||||
|
|
||||||
|
insert into mutable values ('foo'), ('bar'); |
||||||
|
update mutable set f2 = f2 || ' baz'; |
||||||
|
table mutable; |
||||||
|
|
||||||
|
-- check returning a composite datum from a trigger |
||||||
|
|
||||||
|
create or replace function sillytrig() returns trigger language plpgsql as |
||||||
|
$$begin |
||||||
|
return row(new.*); |
||||||
|
end$$; |
||||||
|
|
||||||
|
update mutable set f2 = f2 || ' baz'; |
||||||
|
table mutable; |
||||||
|
|
||||||
|
create or replace function sillytrig() returns trigger language plpgsql as |
||||||
|
$$declare r record; |
||||||
|
begin |
||||||
|
r := row(new.*); |
||||||
|
return r; |
||||||
|
end$$; |
||||||
|
|
||||||
|
update mutable set f2 = f2 || ' baz'; |
||||||
|
table mutable; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Domains of composite |
||||||
|
-- |
||||||
|
|
||||||
|
create domain ordered_int8s as two_int8s check((value).q1 <= (value).q2); |
||||||
|
|
||||||
|
create function read_ordered_int8s(p ordered_int8s) returns int8 as $$ |
||||||
|
begin return p.q1 + p.q2; end |
||||||
|
$$ language plpgsql; |
||||||
|
|
||||||
|
select read_ordered_int8s(row(1, 2)); |
||||||
|
select read_ordered_int8s(row(2, 1)); -- fail |
||||||
|
|
||||||
|
create function build_ordered_int8s(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
begin return row(i,j); end |
||||||
|
$$ language plpgsql; |
||||||
|
|
||||||
|
select build_ordered_int8s(1,2); |
||||||
|
select build_ordered_int8s(2,1); -- fail |
||||||
|
|
||||||
|
create function build_ordered_int8s_2(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
declare r record; begin r := row(i,j); return r; end |
||||||
|
$$ language plpgsql; |
||||||
|
|
||||||
|
select build_ordered_int8s_2(1,2); |
||||||
|
select build_ordered_int8s_2(2,1); -- fail |
||||||
|
|
||||||
|
create function build_ordered_int8s_3(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
declare r two_int8s; begin r := row(i,j); return r; end |
||||||
|
$$ language plpgsql; |
||||||
|
|
||||||
|
select build_ordered_int8s_3(1,2); |
||||||
|
select build_ordered_int8s_3(2,1); -- fail |
||||||
|
|
||||||
|
create function build_ordered_int8s_4(i int8, j int8) returns ordered_int8s as $$ |
||||||
|
declare r ordered_int8s; begin r := row(i,j); return r; end |
||||||
|
$$ language plpgsql; |
||||||
|
|
||||||
|
select build_ordered_int8s_4(1,2); |
||||||
|
select build_ordered_int8s_4(2,1); -- fail |
||||||
|
|
||||||
|
create function build_ordered_int8s_a(i int8, j int8) returns ordered_int8s[] as $$ |
||||||
|
begin return array[row(i,j), row(i,j+1)]; end |
||||||
|
$$ language plpgsql; |
||||||
|
|
||||||
|
select build_ordered_int8s_a(1,2); |
||||||
|
select build_ordered_int8s_a(2,1); -- fail |
||||||
|
|
||||||
|
-- check field assignment |
||||||
|
do $$ |
||||||
|
declare r ordered_int8s; |
||||||
|
begin |
||||||
|
r.q1 := null; |
||||||
|
r.q2 := 43; |
||||||
|
r.q1 := 42; |
||||||
|
r.q2 := 41; -- fail |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check whole-row assignment |
||||||
|
do $$ |
||||||
|
declare r ordered_int8s; |
||||||
|
begin |
||||||
|
r := null; |
||||||
|
r := row(null,null); |
||||||
|
r := row(1,2); |
||||||
|
r := row(2,1); -- fail |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check assignment in for-loop |
||||||
|
do $$ |
||||||
|
declare r ordered_int8s; |
||||||
|
begin |
||||||
|
for r in values (1,2),(3,4),(6,5) loop |
||||||
|
raise notice 'r = %', r; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
|
||||||
|
-- check behavior with toastable fields, too |
||||||
|
|
||||||
|
create type two_texts as (f1 text, f2 text); |
||||||
|
create domain ordered_texts as two_texts check((value).f1 <= (value).f2); |
||||||
|
|
||||||
|
create table sometable (id int, a text, b text); |
||||||
|
-- b should be compressed, but in-line |
||||||
|
insert into sometable values (1, 'a', repeat('ffoob',1000)); |
||||||
|
-- this b should be out-of-line |
||||||
|
insert into sometable values (2, 'a', repeat('ffoob',100000)); |
||||||
|
-- this pair should fail the domain check |
||||||
|
insert into sometable values (3, 'z', repeat('ffoob',100000)); |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare d ordered_texts; |
||||||
|
begin |
||||||
|
for d in select a, b from sometable loop |
||||||
|
raise notice 'succeeded at "%"', d.f1; |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare r record; d ordered_texts; |
||||||
|
begin |
||||||
|
for r in select * from sometable loop |
||||||
|
raise notice 'processing row %', r.id; |
||||||
|
d := row(r.a, r.b); |
||||||
|
end loop; |
||||||
|
end$$; |
||||||
|
|
||||||
|
do $$ |
||||||
|
declare r record; d ordered_texts; |
||||||
|
begin |
||||||
|
for r in select * from sometable loop |
||||||
|
raise notice 'processing row %', r.id; |
||||||
|
d := null; |
||||||
|
d.f1 := r.a; |
||||||
|
d.f2 := r.b; |
||||||
|
end loop; |
||||||
|
end$$; |
Loading…
Reference in new issue