Commit bc411f25 authored by Peter Eisentraut's avatar Peter Eisentraut

Table function support for PL/Python

This allows functions with multiple OUT parameters returning both one
or multiple records (RECORD or SETOF RECORD).

Jan Urbański, reviewed by Hitoshi Harada
parent 772dcfe7
......@@ -390,18 +390,6 @@ $$ LANGUAGE plpythonu;
return type and the Python data type of the actual return object
are not flagged; the value will be converted in any case.
</para>
<tip>
<para>
<application>PL/Python</application> functions cannot return
either type <type>RECORD</type> or <type>SETOF RECORD</type>. A
workaround is to write a <application>PL/pgSQL</application>
function that creates a temporary table, have it call the
<application>PL/Python</application> function to fill the table,
and then have the <application>PL/pgSQL</application> function
return the generic <type>RECORD</type> from the temporary table.
</para>
</tip>
</sect2>
<sect2>
......@@ -593,6 +581,17 @@ $$ LANGUAGE plpythonu;
</varlistentry>
</variablelist>
</para>
<para>
Functions with <literal>OUT</literal> parameters are also supported. For example:
<programlisting>
CREATE FUNCTION multiout_simple(OUT i integer, OUT j integer) AS $$
return (1, 2)
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_simple();
</programlisting>
</para>
</sect2>
<sect2>
......@@ -692,6 +691,19 @@ $$ LANGUAGE plpythonu;
</varlistentry>
</variablelist>
</para>
<para>
Set-returning functions with <literal>OUT</literal> parameters
(using <literal>RETURNS SETOF record</literal>) are also
supported. For example:
<programlisting>
CREATE FUNCTION multiout_simple_setof(n integer, OUT integer, OUT integer) RETURNS SETOF record AS $$
return [(1, 2)] * n
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_simple_setof(3);
</programlisting>
</para>
</sect2>
</sect1>
......
......@@ -80,6 +80,7 @@ REGRESS = \
plpython_error \
plpython_unicode \
plpython_quote \
plpython_composite \
plpython_drop
# where to find psql for running the tests
PSQLDIR = $(bindir)
......
CREATE FUNCTION multiout_simple(OUT i integer, OUT j integer) AS $$
return (1, 2)
$$ LANGUAGE plpythonu;
SELECT multiout_simple();
multiout_simple
-----------------
(1,2)
(1 row)
SELECT * FROM multiout_simple();
i | j
---+---
1 | 2
(1 row)
SELECT i, j + 2 FROM multiout_simple();
i | ?column?
---+----------
1 | 4
(1 row)
SELECT (multiout_simple()).j + 3;
?column?
----------
5
(1 row)
CREATE FUNCTION multiout_simple_setof(n integer = 1, OUT integer, OUT integer) RETURNS SETOF record AS $$
return [(1, 2)] * n
$$ LANGUAGE plpythonu;
SELECT multiout_simple_setof();
multiout_simple_setof
-----------------------
(1,2)
(1 row)
SELECT * FROM multiout_simple_setof();
column1 | column2
---------+---------
1 | 2
(1 row)
SELECT * FROM multiout_simple_setof(3);
column1 | column2
---------+---------
1 | 2
1 | 2
1 | 2
(3 rows)
CREATE FUNCTION multiout_record_as(typ text,
first text, OUT first text,
second integer, OUT second integer,
retnull boolean) RETURNS record AS $$
if retnull:
return None
if typ == 'dict':
return { 'first': first, 'second': second, 'additionalfield': 'must not cause trouble' }
elif typ == 'tuple':
return ( first, second )
elif typ == 'list':
return [ first, second ]
elif typ == 'obj':
class type_record: pass
type_record.first = first
type_record.second = second
return type_record
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_record_as('dict', 'foo', 1, 'f');
first | second
-------+--------
foo | 1
(1 row)
SELECT multiout_record_as('dict', 'foo', 1, 'f');
multiout_record_as
--------------------
(foo,1)
(1 row)
SELECT *, s IS NULL AS snull FROM multiout_record_as('tuple', 'xxx', NULL, 'f') AS f(f, s);
f | s | snull
-----+---+-------
xxx | | t
(1 row)
SELECT *, f IS NULL AS fnull, s IS NULL AS snull FROM multiout_record_as('tuple', 'xxx', 1, 't') AS f(f, s);
f | s | fnull | snull
---+---+-------+-------
| | t | t
(1 row)
SELECT * FROM multiout_record_as('obj', NULL, 10, 'f');
first | second
-------+--------
| 10
(1 row)
CREATE FUNCTION multiout_setof(n integer,
OUT power_of_2 integer,
OUT length integer) RETURNS SETOF record AS $$
for i in range(n):
power = 2 ** i
length = plpy.execute("select length('%d')" % power)[0]['length']
yield power, length
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_setof(3);
power_of_2 | length
------------+--------
1 | 1
2 | 1
4 | 1
(3 rows)
SELECT multiout_setof(5);
multiout_setof
----------------
(1,1)
(2,1)
(4,1)
(8,1)
(16,2)
(5 rows)
CREATE FUNCTION multiout_return_table() RETURNS TABLE (x integer, y text) AS $$
return [{'x': 4, 'y' :'four'},
{'x': 7, 'y' :'seven'},
{'x': 0, 'y' :'zero'}]
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_return_table();
x | y
---+-------
4 | four
7 | seven
0 | zero
(3 rows)
CREATE FUNCTION multiout_array(OUT integer[], OUT text) RETURNS SETOF record AS $$
yield [[1], 'a']
yield [[1,2], 'b']
yield [[1,2,3], None]
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_array();
column1 | column2
---------+---------
{1} | a
{1,2} | b
{1,2,3} |
(3 rows)
CREATE FUNCTION singleout_composite(OUT type_record) AS $$
return {'first': 1, 'second': 2}
$$ LANGUAGE plpythonu;
CREATE FUNCTION multiout_composite(OUT type_record) RETURNS SETOF type_record AS $$
return [{'first': 1, 'second': 2},
{'first': 3, 'second': 4 }]
$$ LANGUAGE plpythonu;
SELECT * FROM singleout_composite();
first | second
-------+--------
1 | 2
(1 row)
SELECT * FROM multiout_composite();
first | second
-------+--------
1 | 2
3 | 4
(2 rows)
-- composite OUT parameters in functions returning RECORD not supported yet
CREATE FUNCTION multiout_composite(INOUT n integer, OUT type_record) AS $$
return (n, (n * 2, n * 3))
$$ LANGUAGE plpythonu;
CREATE FUNCTION multiout_table_type_setof(typ text, returnnull boolean, INOUT n integer, OUT table_record) RETURNS SETOF record AS $$
if returnnull:
d = None
elif typ == 'dict':
d = {'first': n * 2, 'second': n * 3, 'extra': 'not important'}
elif typ == 'tuple':
d = (n * 2, n * 3)
elif typ == 'obj':
class d: pass
d.first = n * 2
d.second = n * 3
for i in range(n):
yield (i, d)
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_composite(2);
n | column2
---+---------
2 | (4,6)
(1 row)
SELECT * FROM multiout_table_type_setof('dict', 'f', 3);
n | column2
---+---------
0 | (6,9)
1 | (6,9)
2 | (6,9)
(3 rows)
SELECT * FROM multiout_table_type_setof('tuple', 'f', 2);
n | column2
---+---------
0 | (4,6)
1 | (4,6)
(2 rows)
SELECT * FROM multiout_table_type_setof('obj', 'f', 4);
n | column2
---+---------
0 | (8,12)
1 | (8,12)
2 | (8,12)
3 | (8,12)
(4 rows)
SELECT * FROM multiout_table_type_setof('dict', 't', 3);
n | column2
---+---------
0 |
1 |
2 |
(3 rows)
-- check what happens if a type changes under us
CREATE TABLE changing (
i integer,
j integer
);
CREATE FUNCTION changing_test(OUT n integer, OUT changing) RETURNS SETOF record AS $$
return [(1, {'i': 1, 'j': 2}),
(1, (3, 4))]
$$ LANGUAGE plpythonu;
SELECT * FROM changing_test();
n | column2
---+---------
1 | (1,2)
1 | (3,4)
(2 rows)
ALTER TABLE changing DROP COLUMN j;
SELECT * FROM changing_test();
ERROR: length of returned sequence did not match number of columns in row
CONTEXT: while creating return value
PL/Python function "changing_test"
SELECT * FROM changing_test();
ERROR: length of returned sequence did not match number of columns in row
CONTEXT: while creating return value
PL/Python function "changing_test"
ALTER TABLE changing ADD COLUMN j integer;
SELECT * FROM changing_test();
n | column2
---+---------
1 | (1,2)
1 | (3,4)
(2 rows)
-- tables of composite types (not yet implemented)
CREATE FUNCTION composite_types_table(OUT tab table_record[], OUT typ type_record[] ) RETURNS SETOF record AS $$
yield {'tab': [['first', 1], ['second', 2]],
'typ': [{'first': 'third', 'second': 3},
{'first': 'fourth', 'second': 4}]}
yield {'tab': [['first', 1], ['second', 2]],
'typ': [{'first': 'third', 'second': 3},
{'first': 'fourth', 'second': 4}]}
yield {'tab': [['first', 1], ['second', 2]],
'typ': [{'first': 'third', 'second': 3},
{'first': 'fourth', 'second': 4}]}
$$ LANGUAGE plpythonu;
SELECT * FROM composite_types_table();
ERROR: PL/Python functions cannot return type table_record[]
DETAIL: PL/Python does not support conversion to arrays of row types.
CONTEXT: PL/Python function "composite_types_table"
-- check what happens if the output record descriptor changes
CREATE FUNCTION return_record(t text) RETURNS record AS $$
return {'t': t, 'val': 10}
$$ LANGUAGE plpythonu;
SELECT * FROM return_record('abc') AS r(t text, val integer);
t | val
-----+-----
abc | 10
(1 row)
SELECT * FROM return_record('abc') AS r(t text, val bigint);
t | val
-----+-----
abc | 10
(1 row)
SELECT * FROM return_record('abc') AS r(t text, val integer);
t | val
-----+-----
abc | 10
(1 row)
SELECT * FROM return_record('abc') AS r(t varchar(30), val integer);
t | val
-----+-----
abc | 10
(1 row)
SELECT * FROM return_record('abc') AS r(t varchar(100), val integer);
t | val
-----+-----
abc | 10
(1 row)
SELECT * FROM return_record('999') AS r(val text, t integer);
val | t
-----+-----
10 | 999
(1 row)
CREATE FUNCTION return_record_2(t text) RETURNS record AS $$
return {'v1':1,'v2':2,t:3}
$$ LANGUAGE plpythonu;
SELECT * FROM return_record_2('v3') AS (v3 int, v2 int, v1 int);
v3 | v2 | v1
----+----+----
3 | 2 | 1
(1 row)
SELECT * FROM return_record_2('v3') AS (v2 int, v3 int, v1 int);
v2 | v3 | v1
----+----+----
2 | 3 | 1
(1 row)
SELECT * FROM return_record_2('v4') AS (v1 int, v4 int, v2 int);
v1 | v4 | v2
----+----+----
1 | 3 | 2
(1 row)
SELECT * FROM return_record_2('v4') AS (v1 int, v4 int, v2 int);
v1 | v4 | v2
----+----+----
1 | 3 | 2
(1 row)
-- error
SELECT * FROM return_record_2('v4') AS (v1 int, v3 int, v2 int);
ERROR: key "v3" not found in mapping
HINT: To return null in a column, add the value None to the mapping with the key named after the column.
CONTEXT: while creating return value
PL/Python function "return_record_2"
-- works
SELECT * FROM return_record_2('v3') AS (v1 int, v3 int, v2 int);
v1 | v3 | v2
----+----+----
1 | 3 | 2
(1 row)
SELECT * FROM return_record_2('v3') AS (v1 int, v2 int, v3 int);
v1 | v2 | v3
----+----+----
1 | 2 | 3
(1 row)
......@@ -42,12 +42,10 @@ $$ LANGUAGE plpythonu;
CREATE FUNCTION test_in_out_params(first in text, second out text) AS $$
return first + '_in_to_out';
$$ LANGUAGE plpythonu;
-- this doesn't work yet :-(
CREATE FUNCTION test_in_out_params_multi(first in text,
second out text, third out text) AS $$
return first + '_record_in_to_out';
return (first + '_record_in_to_out_1', first + '_record_in_to_out_2');
$$ LANGUAGE plpythonu;
ERROR: PL/Python functions cannot return type record
CREATE FUNCTION test_inout_params(first inout text) AS $$
return first + '_inout';
$$ LANGUAGE plpythonu;
......@@ -298,12 +296,12 @@ SELECT * FROM test_in_out_params('test_in');
test_in_in_to_out
(1 row)
-- this doesn't work yet :-(
SELECT * FROM test_in_out_params_multi('test_in');
ERROR: function test_in_out_params_multi(unknown) does not exist
LINE 1: SELECT * FROM test_in_out_params_multi('test_in');
^
HINT: No function matches the given name and argument types. You might need to add explicit type casts.
second | third
----------------------------+----------------------------
test_in_record_in_to_out_1 | test_in_record_in_to_out_2
(1 row)
SELECT * FROM test_inout_params('test_in');
first
---------------
......
......@@ -549,3 +549,21 @@ SELECT * FROM pb;
b | 2010-10-13 21:57:29
(1 row)
-- triggers for tables with composite types
CREATE TABLE comp1 (i integer, j boolean);
CREATE TYPE comp2 AS (k integer, l boolean);
CREATE TABLE composite_trigger_test (f1 comp1, f2 comp2);
CREATE FUNCTION composite_trigger_f() RETURNS trigger AS $$
TD['new']['f1'] = (3, False)
TD['new']['f2'] = {'k': 7, 'l': 'yes', 'ignored': 10}
return 'MODIFY'
$$ LANGUAGE plpythonu;
CREATE TRIGGER composite_trigger BEFORE INSERT ON composite_trigger_test
FOR EACH ROW EXECUTE PROCEDURE composite_trigger_f();
INSERT INTO composite_trigger_test VALUES (NULL, NULL);
SELECT * FROM composite_trigger_test;
f1 | f2
-------+-------
(3,f) | (7,t)
(1 row)
This diff is collapsed.
CREATE FUNCTION multiout_simple(OUT i integer, OUT j integer) AS $$
return (1, 2)
$$ LANGUAGE plpythonu;
SELECT multiout_simple();
SELECT * FROM multiout_simple();
SELECT i, j + 2 FROM multiout_simple();
SELECT (multiout_simple()).j + 3;
CREATE FUNCTION multiout_simple_setof(n integer = 1, OUT integer, OUT integer) RETURNS SETOF record AS $$
return [(1, 2)] * n
$$ LANGUAGE plpythonu;
SELECT multiout_simple_setof();
SELECT * FROM multiout_simple_setof();
SELECT * FROM multiout_simple_setof(3);
CREATE FUNCTION multiout_record_as(typ text,
first text, OUT first text,
second integer, OUT second integer,
retnull boolean) RETURNS record AS $$
if retnull:
return None
if typ == 'dict':
return { 'first': first, 'second': second, 'additionalfield': 'must not cause trouble' }
elif typ == 'tuple':
return ( first, second )
elif typ == 'list':
return [ first, second ]
elif typ == 'obj':
class type_record: pass
type_record.first = first
type_record.second = second
return type_record
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_record_as('dict', 'foo', 1, 'f');
SELECT multiout_record_as('dict', 'foo', 1, 'f');
SELECT *, s IS NULL AS snull FROM multiout_record_as('tuple', 'xxx', NULL, 'f') AS f(f, s);
SELECT *, f IS NULL AS fnull, s IS NULL AS snull FROM multiout_record_as('tuple', 'xxx', 1, 't') AS f(f, s);
SELECT * FROM multiout_record_as('obj', NULL, 10, 'f');
CREATE FUNCTION multiout_setof(n integer,
OUT power_of_2 integer,
OUT length integer) RETURNS SETOF record AS $$
for i in range(n):
power = 2 ** i
length = plpy.execute("select length('%d')" % power)[0]['length']
yield power, length
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_setof(3);
SELECT multiout_setof(5);
CREATE FUNCTION multiout_return_table() RETURNS TABLE (x integer, y text) AS $$
return [{'x': 4, 'y' :'four'},
{'x': 7, 'y' :'seven'},
{'x': 0, 'y' :'zero'}]
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_return_table();
CREATE FUNCTION multiout_array(OUT integer[], OUT text) RETURNS SETOF record AS $$
yield [[1], 'a']
yield [[1,2], 'b']
yield [[1,2,3], None]
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_array();
CREATE FUNCTION singleout_composite(OUT type_record) AS $$
return {'first': 1, 'second': 2}
$$ LANGUAGE plpythonu;
CREATE FUNCTION multiout_composite(OUT type_record) RETURNS SETOF type_record AS $$
return [{'first': 1, 'second': 2},
{'first': 3, 'second': 4 }]
$$ LANGUAGE plpythonu;
SELECT * FROM singleout_composite();
SELECT * FROM multiout_composite();
-- composite OUT parameters in functions returning RECORD not supported yet
CREATE FUNCTION multiout_composite(INOUT n integer, OUT type_record) AS $$
return (n, (n * 2, n * 3))
$$ LANGUAGE plpythonu;
CREATE FUNCTION multiout_table_type_setof(typ text, returnnull boolean, INOUT n integer, OUT table_record) RETURNS SETOF record AS $$
if returnnull:
d = None
elif typ == 'dict':
d = {'first': n * 2, 'second': n * 3, 'extra': 'not important'}
elif typ == 'tuple':
d = (n * 2, n * 3)
elif typ == 'obj':
class d: pass
d.first = n * 2
d.second = n * 3
for i in range(n):
yield (i, d)
$$ LANGUAGE plpythonu;
SELECT * FROM multiout_composite(2);
SELECT * FROM multiout_table_type_setof('dict', 'f', 3);
SELECT * FROM multiout_table_type_setof('tuple', 'f', 2);
SELECT * FROM multiout_table_type_setof('obj', 'f', 4);
SELECT * FROM multiout_table_type_setof('dict', 't', 3);
-- check what happens if a type changes under us
CREATE TABLE changing (
i integer,
j integer
);
CREATE FUNCTION changing_test(OUT n integer, OUT changing) RETURNS SETOF record AS $$
return [(1, {'i': 1, 'j': 2}),
(1, (3, 4))]
$$ LANGUAGE plpythonu;
SELECT * FROM changing_test();
ALTER TABLE changing DROP COLUMN j;
SELECT * FROM changing_test();
SELECT * FROM changing_test();
ALTER TABLE changing ADD COLUMN j integer;
SELECT * FROM changing_test();
-- tables of composite types (not yet implemented)
CREATE FUNCTION composite_types_table(OUT tab table_record[], OUT typ type_record[] ) RETURNS SETOF record AS $$
yield {'tab': [['first', 1], ['second', 2]],
'typ': [{'first': 'third', 'second': 3},
{'first': 'fourth', 'second': 4}]}
yield {'tab': [['first', 1], ['second', 2]],
'typ': [{'first': 'third', 'second': 3},
{'first': 'fourth', 'second': 4}]}
yield {'tab': [['first', 1], ['second', 2]],
'typ': [{'first': 'third', 'second': 3},
{'first': 'fourth', 'second': 4}]}
$$ LANGUAGE plpythonu;
SELECT * FROM composite_types_table();
-- check what happens if the output record descriptor changes
CREATE FUNCTION return_record(t text) RETURNS record AS $$
return {'t': t, 'val': 10}
$$ LANGUAGE plpythonu;
SELECT * FROM return_record('abc') AS r(t text, val integer);
SELECT * FROM return_record('abc') AS r(t text, val bigint);
SELECT * FROM return_record('abc') AS r(t text, val integer);
SELECT * FROM return_record('abc') AS r(t varchar(30), val integer);
SELECT * FROM return_record('abc') AS r(t varchar(100), val integer);
SELECT * FROM return_record('999') AS r(val text, t integer);
CREATE FUNCTION return_record_2(t text) RETURNS record AS $$
return {'v1':1,'v2':2,t:3}
$$ LANGUAGE plpythonu;
SELECT * FROM return_record_2('v3') AS (v3 int, v2 int, v1 int);
SELECT * FROM return_record_2('v3') AS (v2 int, v3 int, v1 int);
SELECT * FROM return_record_2('v4') AS (v1 int, v4 int, v2 int);
SELECT * FROM return_record_2('v4') AS (v1 int, v4 int, v2 int);
-- error
SELECT * FROM return_record_2('v4') AS (v1 int, v3 int, v2 int);
-- works
SELECT * FROM return_record_2('v3') AS (v1 int, v3 int, v2 int);
SELECT * FROM return_record_2('v3') AS (v1 int, v2 int, v3 int);
......@@ -49,10 +49,9 @@ CREATE FUNCTION test_in_out_params(first in text, second out text) AS $$
return first + '_in_to_out';
$$ LANGUAGE plpythonu;
-- this doesn't work yet :-(
CREATE FUNCTION test_in_out_params_multi(first in text,
second out text, third out text) AS $$
return first + '_record_in_to_out';
return (first + '_record_in_to_out_1', first + '_record_in_to_out_2');
$$ LANGUAGE plpythonu;
CREATE FUNCTION test_inout_params(first inout text) AS $$
......@@ -110,7 +109,6 @@ SELECT * FROM test_type_record_as('obj', 'three', 3, false);
SELECT * FROM test_type_record_as('obj', null, null, true);
SELECT * FROM test_in_out_params('test_in');
-- this doesn't work yet :-(
SELECT * FROM test_in_out_params_multi('test_in');
SELECT * FROM test_inout_params('test_in');
......
......@@ -326,3 +326,23 @@ INSERT INTO pb VALUES ('a', '2010-10-09 21:57:33.930486');
SELECT * FROM pb;
UPDATE pb SET a = 'b';
SELECT * FROM pb;
-- triggers for tables with composite types
CREATE TABLE comp1 (i integer, j boolean);
CREATE TYPE comp2 AS (k integer, l boolean);
CREATE TABLE composite_trigger_test (f1 comp1, f2 comp2);
CREATE FUNCTION composite_trigger_f() RETURNS trigger AS $$
TD['new']['f1'] = (3, False)
TD['new']['f2'] = {'k': 7, 'l': 'yes', 'ignored': 10}
return 'MODIFY'
$$ LANGUAGE plpythonu;
CREATE TRIGGER composite_trigger BEFORE INSERT ON composite_trigger_test
FOR EACH ROW EXECUTE PROCEDURE composite_trigger_f();
INSERT INTO composite_trigger_test VALUES (NULL, NULL);
SELECT * FROM composite_trigger_test;
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