Commit 38c7700f authored by Bruce Momjian's avatar Bruce Momjian

Add dynamic record inspection to PL/PgSQL, useful for generic triggers:

  tval2 := r.(cname);

or

  columns := r.(*);

Titus von Boxberg
parent 88ba64d3
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.92 2006/05/30 11:58:05 momjian Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.93 2006/05/30 12:03:12 momjian Exp $ -->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
......@@ -879,6 +879,55 @@ SELECT merge_fields(t.*) FROM table1 t WHERE ... ;
field in it will draw a run-time error.
</para>
<para>
To obtain the values of the fields the record is made up of,
the record variable can be qualified with the column or field
name. This can be done either by literally using the column name
or the column name for indexing the record can be taken out of a scalar
variable. The syntax for this notation is Record_variable.(IndexVariable).
To get information about the column field names of the record,
a special expression exists that returns all column names as an array:
RecordVariable.(*) .
Thus, the RECORD can be viewed
as an associative array that allows for introspection of it's contents.
This feature is especially useful for writing generic triggers that
operate on records with unknown structure.
Here is an example procedure that shows column names and values
of the predefined record NEW in a trigger procedure:
<programlisting>
CREATE OR REPLACE FUNCTION show_associative_records() RETURNS TRIGGER AS $$
DECLARE
colname TEXT;
colcontent TEXT;
colnames TEXT[];
coln INT4;
coli INT4;
BEGIN
-- obtain an array with all field names of the record
colnames := NEW.(*);
RAISE NOTICE 'All column names of test record: %', colnames;
-- show field names and contents of record
coli := 1;
coln := array_upper(colnames,1);
RAISE NOTICE 'Number of columns in NEW: %', coln;
FOR coli IN 1 .. coln LOOP
colname := colnames[coli];
colcontent := NEW.(colname);
RAISE NOTICE 'column % of NEW: %', quote_ident(colname), quote_literal(colcontent);
END LOOP;
-- Do it with a fixed field name:
-- will have to know the column name
RAISE NOTICE 'column someint of NEW: %', quote_literal(NEW.someint);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
--CREATE TABLE test_records (someint INT8, somestring TEXT);
--CREATE TRIGGER tr_test_record BEFORE INSERT ON test_records FOR EACH ROW EXECUTE PROCEDURE show_associative_records();
</programlisting>
</para>
<para>
Note that <literal>RECORD</> is not a true data type, only a placeholder.
One should also realize that when a <application>PL/pgSQL</application>
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.104 2006/05/30 11:58:05 momjian Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.105 2006/05/30 12:03:13 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -884,7 +884,8 @@ plpgsql_parse_dblword(char *word)
new = palloc(sizeof(PLpgSQL_recfield));
new->dtype = PLPGSQL_DTYPE_RECFIELD;
new->fieldname = pstrdup(cp[1]);
new->fieldindex.fieldname = pstrdup(cp[1]);
new->fieldindex_flag = RECFIELD_USE_FIELDNAME;
new->recparentno = ns->itemno;
plpgsql_adddatum((PLpgSQL_datum *) new);
......@@ -990,7 +991,8 @@ plpgsql_parse_tripword(char *word)
new = palloc(sizeof(PLpgSQL_recfield));
new->dtype = PLPGSQL_DTYPE_RECFIELD;
new->fieldname = pstrdup(cp[2]);
new->fieldindex.fieldname = pstrdup(cp[2]);
new->fieldindex_flag = RECFIELD_USE_FIELDNAME;
new->recparentno = ns->itemno;
plpgsql_adddatum((PLpgSQL_datum *) new);
......@@ -1438,6 +1440,132 @@ plpgsql_parse_dblwordrowtype(char *word)
return T_DTYPE;
}
/* ----------
* plpgsql_parse_recindex
* lookup associative index into record
* ----------
*/
int
plpgsql_parse_recindex(char *word)
{
PLpgSQL_nsitem *ns1, *ns2;
char *cp[2];
int ret = T_ERROR;
char *fieldvar;
int fl;
/* Do case conversion and word separation */
plpgsql_convert_ident(word, cp, 2);
Assert(cp[1] != NULL);
/* cleanup the "(identifier)" string to "identifier" */
fieldvar = cp[1];
Assert(*fieldvar == '(');
++fieldvar; /* get rid of ( */
fl = strlen(fieldvar);
Assert(fieldvar[fl-1] == ')');
fieldvar[fl-1] = 0; /* get rid of ) */
/*
* Lookup the first word
*/
ns1 = plpgsql_ns_lookup(cp[0], NULL);
if ( ns1 == NULL )
{
pfree(cp[0]);
pfree(cp[1]);
return T_ERROR;
}
ns2 = plpgsql_ns_lookup(fieldvar, NULL);
pfree(cp[0]);
pfree(cp[1]);
if ( ns2 == NULL ) /* name lookup failed */
return T_ERROR;
switch (ns1->itemtype)
{
case PLPGSQL_NSTYPE_REC:
{
/*
* First word is a record name, so second word must be an
* variable holding the field name in this record.
*/
if ( ns2->itemtype == PLPGSQL_NSTYPE_VAR ) {
PLpgSQL_recfield *new;
new = palloc(sizeof(PLpgSQL_recfield));
new->dtype = PLPGSQL_DTYPE_RECFIELD;
new->fieldindex.indexvar_no = ns2->itemno;
new->fieldindex_flag = RECFIELD_USE_INDEX_VAR;
new->recparentno = ns1->itemno;
plpgsql_adddatum((PLpgSQL_datum *) new);
plpgsql_yylval.scalar = (PLpgSQL_datum *) new;
ret = T_SCALAR;
}
break;
}
default:
break;
}
return ret;
}
/* ----------
* plpgsql_parse_recfieldnames
* create fieldnames of a record
* ----------
*/
int
plpgsql_parse_recfieldnames(char *word)
{
PLpgSQL_nsitem *ns1;
char *cp[2];
int ret = T_ERROR;
/* Do case conversion and word separation */
plpgsql_convert_ident(word, cp, 2);
/*
* Lookup the first word
*/
ns1 = plpgsql_ns_lookup(cp[0], NULL);
if ( ns1 == NULL )
{
pfree(cp[0]);
pfree(cp[1]);
return T_ERROR;
}
pfree(cp[0]);
pfree(cp[1]);
switch (ns1->itemtype)
{
case PLPGSQL_NSTYPE_REC:
{
PLpgSQL_recfieldproperties *new;
new = palloc(sizeof(PLpgSQL_recfieldproperties));
new->dtype = PLPGSQL_DTYPE_RECFIELDNAMES;
new->recparentno = ns1->itemno;
new->save_fieldnames = NULL;
plpgsql_adddatum((PLpgSQL_datum *) new);
plpgsql_yylval.scalar = (PLpgSQL_datum *) new;
ret = T_SCALAR; /* ??? */
break;
}
default:
break;
}
return ret;
}
/*
* plpgsql_build_variable - build a datum-array entry of a given
* datatype
......
This diff is collapsed.
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.50 2006/05/30 11:58:05 momjian Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.51 2006/05/30 12:03:13 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1044,9 +1044,13 @@ plpgsql_dumptree(PLpgSQL_function *func)
printf("REC %s\n", ((PLpgSQL_rec *) d)->refname);
break;
case PLPGSQL_DTYPE_RECFIELD:
printf("RECFIELD %-16s of REC %d\n",
((PLpgSQL_recfield *) d)->fieldname,
((PLpgSQL_recfield *) d)->recparentno);
if ( ((PLpgSQL_recfield *) d)->fieldindex_flag == RECFIELD_USE_FIELDNAME )
printf("RECFIELD %-16s of REC %d\n",
((PLpgSQL_recfield *) d)->fieldindex.fieldname,
((PLpgSQL_recfield *) d)->recparentno);
else
printf("RECFIELD Variable of REC %d\n",
((PLpgSQL_recfield *) d)->recparentno);
break;
case PLPGSQL_DTYPE_ARRAYELEM:
printf("ARRAYELEM of VAR %d subscript ",
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.72 2006/05/30 11:58:05 momjian Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.73 2006/05/30 12:03:13 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -52,7 +52,8 @@ enum
PLPGSQL_DTYPE_RECFIELD,
PLPGSQL_DTYPE_ARRAYELEM,
PLPGSQL_DTYPE_EXPR,
PLPGSQL_DTYPE_TRIGARG
PLPGSQL_DTYPE_TRIGARG,
PLPGSQL_DTYPE_RECFIELDNAMES
};
/* ----------
......@@ -251,10 +252,25 @@ typedef struct
{ /* Field in record */
int dtype;
int rfno;
char *fieldname;
union {
char *fieldname;
int indexvar_no; /* dno of variable holding index string */
} fieldindex;
enum {
RECFIELD_USE_FIELDNAME,
RECFIELD_USE_INDEX_VAR,
} fieldindex_flag;
int recparentno; /* dno of parent record */
} PLpgSQL_recfield;
typedef struct
{ /* Field in record */
int dtype;
int rfno;
int recparentno; /* dno of parent record */
ArrayType * save_fieldnames;
} PLpgSQL_recfieldproperties;
typedef struct
{ /* Element of array variable */
......@@ -661,6 +677,8 @@ extern int plpgsql_parse_dblwordtype(char *word);
extern int plpgsql_parse_tripwordtype(char *word);
extern int plpgsql_parse_wordrowtype(char *word);
extern int plpgsql_parse_dblwordrowtype(char *word);
extern int plpgsql_parse_recfieldnames(char *word);
extern int plpgsql_parse_recindex(char *word);
extern PLpgSQL_type *plpgsql_parse_datatype(const char *string);
extern PLpgSQL_type *plpgsql_build_datatype(Oid typeOid, int32 typmod);
extern PLpgSQL_variable *plpgsql_build_variable(const char *refname, int lineno,
......
......@@ -9,7 +9,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.47 2006/05/30 11:58:05 momjian Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.48 2006/05/30 12:03:13 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -222,6 +222,12 @@ dump { return O_DUMP; }
{param}{space}*\.{space}*{identifier}{space}*%ROWTYPE {
plpgsql_error_lineno = plpgsql_scanner_lineno();
return plpgsql_parse_dblwordrowtype(yytext); }
{identifier}{space}*\.\(\*\) {
plpgsql_error_lineno = plpgsql_scanner_lineno();
return plpgsql_parse_recfieldnames(yytext); }
{identifier}{space}*\.\({identifier}\) {
plpgsql_error_lineno = plpgsql_scanner_lineno();
return plpgsql_parse_recindex(yytext); }
{digit}+ { return T_NUMBER; }
......
......@@ -2725,6 +2725,44 @@ end;
$$ language plpgsql;
ERROR: end label "outer_label" specified for unlabelled block
CONTEXT: compile of PL/pgSQL function "end_label4" near line 5
-- check introspective records
create table ritest (i INT4, t TEXT);
insert into ritest (i, t) VALUES (1, 'sometext');
create function test_record() returns void as $$
declare
cname text;
tval text;
ival int4;
tval2 text;
ival2 int4;
columns text[];
r RECORD;
begin
SELECT INTO r * FROM ritest WHERE i = 1;
ival := r.i;
tval := r.t;
RAISE NOTICE 'ival=%, tval=%', ival, tval;
cname := 'i';
ival2 := r.(cname);
cname :='t';
tval2 := r.(cname);
RAISE NOTICE 'ival2=%, tval2=%', ival2, tval2;
columns := r.(*);
RAISE NOTICE 'fieldnames=%', columns;
RETURN;
end;
$$ language plpgsql;
select test_record();
NOTICE: ival=1, tval=sometext
NOTICE: ival2=1, tval2=sometext
NOTICE: fieldnames={i,t}
test_record
-------------
(1 row)
drop table ritest;
drop function test_record();
-- using list of scalars in fori and fore stmts
create function for_vect() returns void as $proc$
<<lbl>>declare a integer; b varchar; c varchar; r record;
......
......@@ -2281,6 +2281,38 @@ begin
end;
$$ language plpgsql;
-- check introspective records
create table ritest (i INT4, t TEXT);
insert into ritest (i, t) VALUES (1, 'sometext');
create function test_record() returns void as $$
declare
cname text;
tval text;
ival int4;
tval2 text;
ival2 int4;
columns text[];
r RECORD;
begin
SELECT INTO r * FROM ritest WHERE i = 1;
ival := r.i;
tval := r.t;
RAISE NOTICE 'ival=%, tval=%', ival, tval;
cname := 'i';
ival2 := r.(cname);
cname :='t';
tval2 := r.(cname);
RAISE NOTICE 'ival2=%, tval2=%', ival2, tval2;
columns := r.(*);
RAISE NOTICE 'fieldnames=%', columns;
RETURN;
end;
$$ language plpgsql;
select test_record();
drop table ritest;
drop function test_record();
-- using list of scalars in fori and fore stmts
create function for_vect() returns void as $proc$
<<lbl>>declare a integer; b varchar; c varchar; r record;
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment