-<!-- $PostgreSQL: pgsql/doc/src/sgml/plpython.sgml,v 1.30 2006/05/26 19:23:09 adunstan Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plpython.sgml,v 1.31 2006/09/02 12:30:01 momjian Exp $ -->
<chapter id="plpython">
<title>PL/Python - Python Procedural Language</title>
<title>PL/Python Functions</title>
<para>
- Functions in PL/Python are declared via the usual <xref
+ Functions in PL/Python are declared via the standard <xref
linkend="sql-createfunction" endterm="sql-createfunction-title">
- syntax. For example:
+ syntax:
+
+<programlisting>
+CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-list</replaceable>)
+ RETURNS <replaceable>return-type</replaceable>
+AS $$
+ # PL/Python function body
+$$ LANGUAGE plpythonu;
+</programlisting>
+ </para>
+
+ <para>
+ The body of a function is simply a Python script. When the function
+ is called, all unnamed arguments are passed as elements to the array
+ <varname>args[]</varname> and named arguments as ordinary variables to the
+ Python script. The result is returned from the Python code in the usual way,
+ with <literal>return</literal> or <literal>yield</literal> (in case of
+ a resultset statement).
+ </para>
+
+ <para>
+ For example, a function to return the greater of two integers can be
+ defined as:
+
<programlisting>
-CREATE FUNCTION myfunc(text) RETURNS text
- AS 'return args[0]'
- LANGUAGE plpythonu;
+CREATE FUNCTION pymax (a integer, b integer)
+ RETURNS integer
+AS $$
+ if a > b:
+ return a
+ return b
+$$ LANGUAGE plpythonu;
</programlisting>
The Python code that is given as the body of the function definition
- gets transformed into a Python function.
- For example, the above results in
+ is transformed into a Python function. For example, the above results in
<programlisting>
-def __plpython_procedure_myfunc_23456():
- return args[0]
+def __plpython_procedure_pymax_23456():
+ if a > b:
+ return a
+ return b
</programlisting>
assuming that 23456 is the OID assigned to the function by
<productname>PostgreSQL</productname>.
</para>
+ <para>
+ The <productname>PostgreSQL</> function parameters are available in
+ the global <varname>args</varname> list. In the
+ <function>pymax</function> example, <varname>args[0]</varname> contains
+ whatever was passed in as the first argument and
+ <varname>args[1]</varname> contains the second argument's value. Alternatively,
+ one can use named parameters as shown in the example above. This greatly simplifies
+ the reading and writing of <application>PL/Python</application> code.
+ </para>
+
+ <para>
+ If an SQL null value<indexterm><primary>null value</primary><secondary
+ sortas="PL/Python">PL/Python</secondary></indexterm> is passed to a
+ function, the argument value will appear as <symbol>None</symbol> in
+ Python. The above function definition will return the wrong answer for null
+ inputs. We could add <literal>STRICT</literal> to the function definition
+ to make <productname>PostgreSQL</productname> do something more reasonable:
+ if a null value is passed, the function will not be called at all,
+ but will just return a null result automatically. Alternatively,
+ we could check for null inputs in the function body:
+
+<programlisting>
+CREATE FUNCTION pymax (a integer, b integer)
+ RETURNS integer
+AS $$
+ if (a is None) or (b is None):
+ return None
+ if a > b:
+ return a
+ return b
+$$ LANGUAGE plpythonu;
+</programlisting>
+
+ As shown above, to return an SQL null value from a PL/Python
+ function, return the value <symbol>None</symbol>. This can be done whether the
+ function is strict or not.
+ </para>
+
+ <para>
+ Composite-type arguments are passed to the function as Python mappings. The
+ element names of the mapping are the attribute names of the composite type.
+ If an attribute in the passed row has the null value, it has the value
+ <symbol>None</symbol> in the mapping. Here is an example:
+
+<programlisting>
+CREATE TABLE employee (
+ name text,
+ salary integer,
+ age integer
+);
+
+CREATE FUNCTION overpaid (e employee)
+ RETURNS boolean
+AS $$
+ if e["salary"] > 200000:
+ return True
+ if (e["age"] < 30) and (e["salary"] > 100000):
+ return True
+ return False
+$$ LANGUAGE plpythonu;
+</programlisting>
+ </para>
+
+ <para>
+ There are multiple ways to return row or composite types from a Python
+ scripts. In following examples we assume to have:
+
+<programlisting>
+CREATE TABLE named_value (
+ name text,
+ value integer
+);
+</programlisting>
+ or
+<programlisting>
+CREATE TYPE named_value AS (
+ name text,
+ value integer
+);
+</programlisting>
+
+ <variablelist>
+ <varlistentry>
+ <term>Sequence types (tuple or list), but not <literal>set</literal> (because
+ it is not indexable)</term>
+ <listitem>
+ <para>
+ Returned sequence objects must have the same number of items as
+ composite types have fields. Item with index 0 is assigned to the first field
+ of the composite type, 1 to second and so on. For example:
+
+<programlisting>
+CREATE FUNCTION make_pair (name text, value integer)
+ RETURNS named_value
+AS $$
+ return [ name, value ]
+ # or alternatively, as tuple: return ( name, value )
+$$ LANGUAGE plpythonu;
+</programlisting>
+
+ To return SQL null in any column, insert <symbol>None</symbol> at
+ the corresponding position.
+ </para>
+ </listitem>
+
+ <varlistentry>
+ <term>Mapping (dictionary)</term>
+ <listitem>
+ <para>
+ Value for a composite type's column is retrieved from the mapping with
+ the column name as key. Example:
+
+<programlisting>
+CREATE FUNCTION make_pair (name text, value integer)
+ RETURNS named_value
+AS $$
+ return { "name": name, "value": value }
+$$ LANGUAGE plpythonu;
+</programlisting>
+
+ Additional dictionary key/value pairs are ignored. Missing keys are
+ treated as errors, i.e. to return an SQL null value for any column, insert
+ <symbol>None</symbol> with the corresponding column name as the key.
+ </para>
+ </listitem>
+
+ <varlistentry>
+ <term>Object (any object providing method <literal>__getattr__</literal>)</term>
+ <listitem>
+ <para>
+ Example:
+
+<programlisting>
+CREATE FUNCTION make_pair (name text, value integer)
+ RETURNS named_value
+AS $$
+ class named_value:
+ def __init__ (self, n, v):
+ self.name = n
+ self.value = v
+ return named_value(name, value)
+
+ # or simply
+ class nv: pass
+ nv.name = name
+ nv.value = value
+ return nv
+$$ LANGUAGE plpythonu;
+</programlisting>
+ </para>
+ </listitem>
+ </varlistentry>
+ </variablelist>
+ </para>
+
<para>
If you do not provide a return value, Python returns the default
<symbol>None</symbol>. <application>PL/Python</application> translates
</para>
<para>
- The <productname>PostgreSQL</> function parameters are available in
- the global <varname>args</varname> list. In the
- <function>myfunc</function> example, <varname>args[0]</> contains
- whatever was passed in as the text argument. For
- <literal>myfunc2(text, integer)</literal>, <varname>args[0]</>
- would contain the <type>text</type> argument and
- <varname>args[1]</varname> the <type>integer</type> argument.
+ A <application>PL/Python</application> function can also return sets of
+ scalar or composite types. There are serveral ways to achieve this because
+ the returned object is internally turned into an iterator. For following
+ examples, let's assume to have composite type:
+
+<programlisting>
+CREATE TYPE greeting AS (
+ how text,
+ who text
+);
+</programlisting>
+
+ Currently known iterable types are:
+ <variablelist>
+ <varlistentry>
+ <term>Sequence types (tuple, list, set)</term>
+ <listitem>
+ <para>
+<programlisting>
+CREATE FUNCTION greet (how text)
+ RETURNS SETOF greeting
+AS $$
+ # return tuple containing lists as composite types
+ # all other combinations work also
+ return ( [ how, "World" ], [ how, "PostgreSQL" ], [ how, "PL/Python" ] )
+$$ LANGUAGE plpythonu;
+</programlisting>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term>Iterator (any object providing <symbol>__iter__</symbol> and
+ <symbol>next</symbol> methods)</term>
+ <listitem>
+ <para>
+<programlisting>
+CREATE FUNCTION greet (how text)
+ RETURNS SETOF greeting
+AS $$
+ class producer:
+ def __init__ (self, how, who):
+ self.how = how
+ self.who = who
+ self.ndx = -1
+
+ def __iter__ (self):
+ return self
+
+ def next (self):
+ self.ndx += 1
+ if self.ndx == len(self.who):
+ raise StopIteration
+ return ( self.how, self.who[self.ndx] )
+
+ return producer(how, [ "World", "PostgreSQL", "PL/Python" ])
+$$ LANGUAGE plpythonu;
+</programlisting>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term>Generator (<literal>yield</literal>)</term>
+ <listitem>
+ <para>
+<programlisting>
+CREATE FUNCTION greet (how text)
+ RETURNS SETOF greeting
+AS $$
+ for who in [ "World", "PostgreSQL", "PL/Python" ]:
+ yield ( how, who )
+$$ LANGUAGE plpythonu;
+</programlisting>
+
+ <warning>
+ <para>
+ Currently, due to Python
+ <ulink url="http://sourceforge.net/tracker/index.php?func=detail&aid=1483133&group_id=5470&atid=105470">bug #1483133</ulink>,
+ some debug versions of Python 2.4
+ (configured and compiled with option <literal>--with-pydebug</literal>)
+ are known to crash the <productname>PostgreSQL</productname> server.
+ Unpatched versions of Fedora 4 contain this bug.
+ It does not happen in production version of Python or on patched
+ versions of Fedora 4.
+ </para>
+ </warning>
+ </para>
+ </listitem>
+ </varlistentry>
+ </variablelist>
+
+ Whenever new iterable types are added to Python language,
+ <application>PL/Python</application> is ready to use it.
</para>
<para>
return "failed, that wasn''t supposed to happen"
return "succeeded, as expected"'
LANGUAGE plpythonu;
-CREATE FUNCTION import_test_one(text) RETURNS text
+CREATE FUNCTION import_test_one(p text) RETURNS text
AS
'import sha
-digest = sha.new(args[0])
+digest = sha.new(p)
return digest.hexdigest()'
LANGUAGE plpythonu;
-CREATE FUNCTION import_test_two(users) RETURNS text
+CREATE FUNCTION import_test_two(u users) RETURNS text
AS
'import sha
-plain = args[0]["fname"] + args[0]["lname"]
+plain = u["fname"] + u["lname"]
digest = sha.new(plain);
return "sha hash of " + plain + " is " + digest.hexdigest()'
LANGUAGE plpythonu;
-CREATE FUNCTION argument_test_one(users, text, text) RETURNS text
+CREATE FUNCTION argument_test_one(u users, a1 text, a2 text) RETURNS text
AS
-'keys = args[0].keys()
+'keys = u.keys()
keys.sort()
out = []
for key in keys:
- out.append("%s: %s" % (key, args[0][key]))
-words = args[1] + " " + args[2] + " => {" + ", ".join(out) + "}"
+ out.append("%s: %s" % (key, u[key]))
+words = a1 + " " + a2 + " => {" + ", ".join(out) + "}"
return words'
LANGUAGE plpythonu;
-- these triggers are dedicated to HPHC of RI who
DROP FUNCTION trigger_data();
-- nested calls
--
-CREATE FUNCTION nested_call_one(text) RETURNS text
+CREATE FUNCTION nested_call_one(a text) RETURNS text
AS
-'q = "SELECT nested_call_two(''%s'')" % args[0]
+'q = "SELECT nested_call_two(''%s'')" % a
r = plpy.execute(q)
return r[0]'
LANGUAGE plpythonu ;
-CREATE FUNCTION nested_call_two(text) RETURNS text
+CREATE FUNCTION nested_call_two(a text) RETURNS text
AS
-'q = "SELECT nested_call_three(''%s'')" % args[0]
+'q = "SELECT nested_call_three(''%s'')" % a
r = plpy.execute(q)
return r[0]'
LANGUAGE plpythonu ;
-CREATE FUNCTION nested_call_three(text) RETURNS text
+CREATE FUNCTION nested_call_three(a text) RETURNS text
AS
-'return args[0]'
+'return a'
LANGUAGE plpythonu ;
-- some spi stuff
-CREATE FUNCTION spi_prepared_plan_test_one(text) RETURNS text
+CREATE FUNCTION spi_prepared_plan_test_one(a text) RETURNS text
AS
'if not SD.has_key("myplan"):
q = "SELECT count(*) FROM users WHERE lname = $1"
SD["myplan"] = plpy.prepare(q, [ "text" ])
try:
- rv = plpy.execute(SD["myplan"], [args[0]])
- return "there are " + str(rv[0]["count"]) + " " + str(args[0]) + "s"
+ rv = plpy.execute(SD["myplan"], [a])
+ return "there are " + str(rv[0]["count"]) + " " + str(a) + "s"
except Exception, ex:
plpy.error(str(ex))
return None
'
LANGUAGE plpythonu;
-CREATE FUNCTION spi_prepared_plan_test_nested(text) RETURNS text
+CREATE FUNCTION spi_prepared_plan_test_nested(a text) RETURNS text
AS
'if not SD.has_key("myplan"):
- q = "SELECT spi_prepared_plan_test_one(''%s'') as count" % args[0]
+ q = "SELECT spi_prepared_plan_test_one(''%s'') as count" % a
SD["myplan"] = plpy.prepare(q)
try:
rv = plpy.execute(SD["myplan"])
CREATE FUNCTION stupid() RETURNS text AS 'return "zarkon"' LANGUAGE plpythonu;
/* a typo
*/
-CREATE FUNCTION invalid_type_uncaught(text) RETURNS text
+CREATE FUNCTION invalid_type_uncaught(a text) RETURNS text
AS
'if not SD.has_key("plan"):
q = "SELECT fname FROM users WHERE lname = $1"
SD["plan"] = plpy.prepare(q, [ "test" ])
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
/* for what it's worth catch the exception generated by
* the typo, and return None
*/
-CREATE FUNCTION invalid_type_caught(text) RETURNS text
+CREATE FUNCTION invalid_type_caught(a text) RETURNS text
AS
'if not SD.has_key("plan"):
q = "SELECT fname FROM users WHERE lname = $1"
except plpy.SPIError, ex:
plpy.notice(str(ex))
return None
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
/* for what it's worth catch the exception generated by
* the typo, and reraise it as a plain error
*/
-CREATE FUNCTION invalid_type_reraised(text) RETURNS text
+CREATE FUNCTION invalid_type_reraised(a text) RETURNS text
AS
'if not SD.has_key("plan"):
q = "SELECT fname FROM users WHERE lname = $1"
SD["plan"] = plpy.prepare(q, [ "test" ])
except plpy.SPIError, ex:
plpy.error(str(ex))
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
LANGUAGE plpythonu;
/* no typo no messing about
*/
-CREATE FUNCTION valid_type(text) RETURNS text
+CREATE FUNCTION valid_type(a text) RETURNS text
AS
'if not SD.has_key("plan"):
SD["plan"] = plpy.prepare("SELECT fname FROM users WHERE lname = $1", [ "text" ])
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
'rv = plpy.execute("SELECT test5(''foo'')")
return rv[0]'
LANGUAGE plpythonu;
-CREATE FUNCTION join_sequences(sequences) RETURNS text
+CREATE FUNCTION join_sequences(s sequences) RETURNS text
AS
-'if not args[0]["multipart"]:
- return args[0]["sequence"]
-q = "SELECT sequence FROM xsequences WHERE pid = ''%s''" % args[0]["pid"]
+'if not s["multipart"]:
+ return s["sequence"]
+q = "SELECT sequence FROM xsequences WHERE pid = ''%s''" % s["pid"]
rv = plpy.execute(q)
-seq = args[0]["sequence"]
+seq = s["sequence"]
for r in rv:
seq = seq + r["sequence"]
return seq
CREATE FUNCTION test_return_none() RETURNS int AS $$
None
$$ LANGUAGE plpythonu;
+--
+-- Test named parameters
+--
+CREATE FUNCTION test_param_names1(a0 integer, a1 text) RETURNS boolean AS $$
+assert a0 == args[0]
+assert a1 == args[1]
+return True
+$$ LANGUAGE plpythonu;
+CREATE FUNCTION test_param_names2(u users) RETURNS text AS $$
+assert u == args[0]
+return str(u)
+$$ LANGUAGE plpythonu;
+-- use deliberately wrong parameter names
+CREATE FUNCTION test_param_names3(a0 integer) RETURNS boolean AS $$
+try:
+ assert a1 == args[0]
+ return False
+except NameError, e:
+ assert e.args[0].find("a1") > -1
+ return True
+$$ LANGUAGE plpythonu;
+--
+-- Test returning SETOF
+--
+CREATE FUNCTION test_setof_as_list(count integer, content text) RETURNS SETOF text AS $$
+return [ content ]*count
+$$ LANGUAGE plpythonu;
+CREATE FUNCTION test_setof_as_tuple(count integer, content text) RETURNS SETOF text AS $$
+t = ()
+for i in xrange(count):
+ t += ( content, )
+return t
+$$ LANGUAGE plpythonu;
+CREATE FUNCTION test_setof_as_iterator(count integer, content text) RETURNS SETOF text AS $$
+class producer:
+ def __init__ (self, icount, icontent):
+ self.icontent = icontent
+ self.icount = icount
+ def __iter__ (self):
+ return self
+ def next (self):
+ if self.icount == 0:
+ raise StopIteration
+ self.icount -= 1
+ return self.icontent
+return producer(count, content)
+$$ LANGUAGE plpythonu;
+--
+-- Test returning tuples
+--
+CREATE FUNCTION test_table_record_as(typ text, first text, second integer, retnull boolean) RETURNS table_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;
+CREATE FUNCTION test_type_record_as(typ text, first text, second integer, retnull boolean) RETURNS type_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;
CREATE TABLE unicode_test (
testvalue text NOT NULL
);
+CREATE TABLE table_record (
+ first text,
+ second int4
+ ) ;
+CREATE TYPE type_record AS (
+ first text,
+ second int4
+ ) ;
| t
(1 row)
+-- Test for functions with named parameters
+SELECT test_param_names1(1,'text');
+ test_param_names1
+-------------------
+ t
+(1 row)
+
+SELECT test_param_names2(users) from users;
+ test_param_names2
+----------------------------------------------------------------------------
+ {'lname': 'doe', 'username': 'j_doe', 'userid': 1, 'fname': 'jane'}
+ {'lname': 'doe', 'username': 'johnd', 'userid': 2, 'fname': 'john'}
+ {'lname': 'doe', 'username': 'w_doe', 'userid': 3, 'fname': 'willem'}
+ {'lname': 'smith', 'username': 'slash', 'userid': 4, 'fname': 'rick'}
+ {'lname': 'smith', 'username': 'w_smith', 'userid': 5, 'fname': 'willem'}
+ {'lname': 'darwin', 'username': 'beagle', 'userid': 6, 'fname': 'charles'}
+(6 rows)
+
+SELECT test_param_names3(1);
+ test_param_names3
+-------------------
+ t
+(1 row)
+
+-- Test set returning functions
+SELECT test_setof_as_list(0, 'list');
+ test_setof_as_list
+--------------------
+(0 rows)
+
+SELECT test_setof_as_list(1, 'list');
+ test_setof_as_list
+--------------------
+ list
+(1 row)
+
+SELECT test_setof_as_list(2, 'list');
+ test_setof_as_list
+--------------------
+ list
+ list
+(2 rows)
+
+SELECT test_setof_as_list(2, null);
+ test_setof_as_list
+--------------------
+
+
+(2 rows)
+
+SELECT test_setof_as_tuple(0, 'tuple');
+ test_setof_as_tuple
+---------------------
+(0 rows)
+
+SELECT test_setof_as_tuple(1, 'tuple');
+ test_setof_as_tuple
+---------------------
+ tuple
+(1 row)
+
+SELECT test_setof_as_tuple(2, 'tuple');
+ test_setof_as_tuple
+---------------------
+ tuple
+ tuple
+(2 rows)
+
+SELECT test_setof_as_tuple(2, null);
+ test_setof_as_tuple
+---------------------
+
+
+(2 rows)
+
+SELECT test_setof_as_iterator(0, 'list');
+ test_setof_as_iterator
+------------------------
+(0 rows)
+
+SELECT test_setof_as_iterator(1, 'list');
+ test_setof_as_iterator
+------------------------
+ list
+(1 row)
+
+SELECT test_setof_as_iterator(2, 'list');
+ test_setof_as_iterator
+------------------------
+ list
+ list
+(2 rows)
+
+SELECT test_setof_as_iterator(2, null);
+ test_setof_as_iterator
+------------------------
+
+
+(2 rows)
+
+-- Test tuple returning functions
+SELECT * FROM test_table_record_as('dict', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('dict', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_table_record_as('dict', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_table_record_as('dict', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_table_record_as('dict', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('tuple', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('tuple', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_table_record_as('tuple', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_table_record_as('tuple', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_table_record_as('tuple', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('list', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('list', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_table_record_as('list', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_table_record_as('list', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_table_record_as('list', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('obj', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_table_record_as('obj', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_table_record_as('obj', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_table_record_as('obj', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_table_record_as('obj', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('dict', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('dict', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_type_record_as('dict', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_type_record_as('dict', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_type_record_as('dict', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('tuple', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('tuple', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_type_record_as('tuple', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_type_record_as('tuple', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_type_record_as('tuple', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('list', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('list', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_type_record_as('list', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_type_record_as('list', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_type_record_as('list', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('obj', null, null, false);
+ first | second
+-------+--------
+ |
+(1 row)
+
+SELECT * FROM test_type_record_as('obj', 'one', null, false);
+ first | second
+-------+--------
+ one |
+(1 row)
+
+SELECT * FROM test_type_record_as('obj', null, 2, false);
+ first | second
+-------+--------
+ | 2
+(1 row)
+
+SELECT * FROM test_type_record_as('obj', 'three', 3, false);
+ first | second
+-------+--------
+ three | 3
+(1 row)
+
+SELECT * FROM test_type_record_as('obj', null, null, true);
+ first | second
+-------+--------
+ |
+(1 row)
+
/**********************************************************************
* plpython.c - python as a procedural language for PostgreSQL
*
- * $PostgreSQL: pgsql/src/pl/plpython/plpython.c,v 1.86 2006/08/27 23:47:58 tgl Exp $
+ * $PostgreSQL: pgsql/src/pl/plpython/plpython.c,v 1.87 2006/09/02 12:30:01 momjian Exp $
*
*********************************************************************
*/
#include "catalog/pg_type.h"
#include "commands/trigger.h"
#include "executor/spi.h"
+#include "funcapi.h"
#include "fmgr.h"
#include "nodes/makefuncs.h"
#include "parser/parse_type.h"
bool fn_readonly;
PLyTypeInfo result; /* also used to store info for trigger tuple
* type */
+ bool is_setof; /* true, if procedure returns result set */
+ PyObject *setof; /* contents of result set. */
+ char **argnames; /* Argument names */
PLyTypeInfo args[FUNC_MAX_ARGS];
int nargs;
PyObject *code; /* compiled procedure code */
static HeapTuple PLy_trigger_handler(FunctionCallInfo fcinfo, PLyProcedure *);
static PyObject *PLy_function_build_args(FunctionCallInfo fcinfo, PLyProcedure *);
+static void PLy_function_delete_args(PLyProcedure *);
static PyObject *PLy_trigger_build_args(FunctionCallInfo fcinfo, PLyProcedure *,
HeapTuple *);
static HeapTuple PLy_modify_tuple(PLyProcedure *, PyObject *,
static PyObject *PLyLong_FromString(const char *);
static PyObject *PLyString_FromString(const char *);
+static HeapTuple PLyMapping_ToTuple(PLyTypeInfo *, PyObject *);
+static HeapTuple PLySequence_ToTuple(PLyTypeInfo *, PyObject *);
+static HeapTuple PLyObject_ToTuple(PLyTypeInfo *, PyObject *);
/*
* Currently active plpython function
PG_TRY();
{
- plargs = PLy_function_build_args(fcinfo, proc);
- plrv = PLy_procedure_call(proc, "args", plargs);
-
- Assert(plrv != NULL);
- Assert(!PLy_error_in_progress);
+ if (!proc->is_setof || proc->setof == NULL)
+ {
+ /* Simple type returning function or first time for SETOF function */
+ plargs = PLy_function_build_args(fcinfo, proc);
+ plrv = PLy_procedure_call(proc, "args", plargs);
+ if (!proc->is_setof)
+ /* SETOF function parameters will be deleted when last row is returned */
+ PLy_function_delete_args(proc);
+ Assert(plrv != NULL);
+ Assert(!PLy_error_in_progress);
+ }
/*
* Disconnect from SPI manager and then create the return values datum
if (SPI_finish() != SPI_OK_FINISH)
elog(ERROR, "SPI_finish failed");
+ if (proc->is_setof)
+ {
+ bool has_error = false;
+ ReturnSetInfo *rsi = (ReturnSetInfo *)fcinfo->resultinfo;
+
+ if (proc->setof == NULL)
+ {
+ /* first time -- do checks and setup */
+ if (!rsi || !IsA(rsi, ReturnSetInfo) ||
+ (rsi->allowedModes & SFRM_ValuePerCall) == 0)
+ {
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("only value per call is allowed")));
+ }
+ rsi->returnMode = SFRM_ValuePerCall;
+
+ /* Make iterator out of returned object */
+ proc->setof = PyObject_GetIter(plrv);
+ Py_DECREF(plrv);
+ plrv = NULL;
+
+ if (proc->setof == NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("returned object can not be iterated"),
+ errdetail("SETOF must be returned as iterable object")));
+ }
+
+ /* Fetch next from iterator */
+ plrv = PyIter_Next(proc->setof);
+ if (plrv)
+ rsi->isDone = ExprMultipleResult;
+ else
+ {
+ rsi->isDone = ExprEndResult;
+ has_error = PyErr_Occurred() != NULL;
+ }
+
+ if (rsi->isDone == ExprEndResult)
+ {
+ /* Iterator is exhausted or error happened */
+ Py_DECREF(proc->setof);
+ proc->setof = NULL;
+
+ Py_XDECREF(plargs);
+ Py_XDECREF(plrv);
+ Py_XDECREF(plrv_so);
+
+ PLy_function_delete_args(proc);
+
+ if (has_error)
+ ereport(ERROR,
+ (errcode(ERRCODE_DATA_EXCEPTION),
+ errmsg("error fetching next item from iterator")));
+
+ fcinfo->isnull = true;
+ return (Datum)NULL;
+ }
+ }
+
/*
* If the function is declared to return void, the Python
* return value must be None. For void-returning functions, we
else if (plrv == Py_None)
{
fcinfo->isnull = true;
- rv = InputFunctionCall(&proc->result.out.d.typfunc,
- NULL,
- proc->result.out.d.typioparam,
- -1);
+ if (proc->result.is_rowtype < 1)
+ rv = InputFunctionCall(&proc->result.out.d.typfunc,
+ NULL,
+ proc->result.out.d.typioparam,
+ -1);
+ else
+ /* Tuple as None */
+ rv = (Datum) NULL;
+ }
+ else if (proc->result.is_rowtype >= 1)
+ {
+ HeapTuple tuple = NULL;
+
+ if (PySequence_Check(plrv))
+ /* composite type as sequence (tuple, list etc) */
+ tuple = PLySequence_ToTuple(&proc->result, plrv);
+ else if (PyMapping_Check(plrv))
+ /* composite type as mapping (currently only dict) */
+ tuple = PLyMapping_ToTuple(&proc->result, plrv);
+ else
+ /* returned as smth, must provide method __getattr__(name) */
+ tuple = PLyObject_ToTuple(&proc->result, plrv);
+
+ if (tuple != NULL)
+ {
+ fcinfo->isnull = false;
+ rv = HeapTupleGetDatum(tuple);
+ }
+ else
+ {
+ fcinfo->isnull = true;
+ rv = (Datum) NULL;
+ }
}
else
{
arg = Py_None;
}
- /*
- * FIXME -- error check this
- */
- PyList_SetItem(args, i, arg);
+ if (PyList_SetItem(args, i, arg) == -1 ||
+ (proc->argnames &&
+ PyDict_SetItemString(proc->globals, proc->argnames[i], arg) == -1))
+ PLy_elog(ERROR, "problem setting up arguments for \"%s\"", proc->proname);
arg = NULL;
}
}
}
+static void
+PLy_function_delete_args(PLyProcedure *proc)
+{
+ int i;
+
+ if (!proc->argnames)
+ return;
+
+ for (i = 0; i < proc->nargs; i++)
+ PyDict_DelItemString(proc->globals, proc->argnames[i]);
+}
+
+
/*
* PLyProcedure functions
*/
bool isnull;
int i,
rv;
+ Datum argnames;
+ Datum *elems;
+ int nelems;
procStruct = (Form_pg_proc) GETSTRUCT(procTup);
proc->nargs = 0;
proc->code = proc->statics = NULL;
proc->globals = proc->me = NULL;
+ proc->is_setof = procStruct->proretset;
+ proc->setof = NULL;
+ proc->argnames = NULL;
PG_TRY();
{
}
if (rvTypeStruct->typtype == 'c')
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("plpython functions cannot return tuples yet")));
+ {
+ /* Tuple: set up later, during first call to PLy_function_handler */
+ proc->result.out.d.typoid = procStruct->prorettype;
+ proc->result.is_rowtype = 2;
+ }
else
PLy_output_datum_func(&proc->result, rvTypeTup);
* arguments.
*/
proc->nargs = fcinfo->nargs;
+ if (proc->nargs)
+ {
+ argnames = SysCacheGetAttr(PROCOID, procTup, Anum_pg_proc_proargnames, &isnull);
+ if (!isnull)
+ {
+ deconstruct_array(DatumGetArrayTypeP(argnames), TEXTOID, -1, false, 'i',
+ &elems, NULL, &nelems);
+ if (nelems != proc->nargs)
+ elog(ERROR,
+ "proargnames must have the same number of elements "
+ "as the function has arguments");
+ proc->argnames = (char **) PLy_malloc(sizeof(char *)*proc->nargs);
+ }
+ }
for (i = 0; i < fcinfo->nargs; i++)
{
HeapTuple argTypeTup;
proc->args[i].is_rowtype = 2; /* still need to set I/O funcs */
ReleaseSysCache(argTypeTup);
- }
+ /* Fetch argument name */
+ if (proc->argnames)
+ proc->argnames[i] = PLy_strdup(DatumGetCString(DirectFunctionCall1(textout, elems[i])));
+ }
/*
* get the text of the function.
if (proc->pyname)
PLy_free(proc->pyname);
for (i = 0; i < proc->nargs; i++)
+ {
if (proc->args[i].is_rowtype == 1)
{
if (proc->args[i].in.r.atts)
if (proc->args[i].out.r.atts)
PLy_free(proc->args[i].out.r.atts);
}
+ if (proc->argnames && proc->argnames[i])
+ PLy_free(proc->argnames[i]);
+ }
+ if (proc->argnames)
+ PLy_free(proc->argnames);
}
/* conversion functions. remember output from python is
return dict;
}
+
+static HeapTuple
+PLyMapping_ToTuple(PLyTypeInfo *info, PyObject *mapping)
+{
+ TupleDesc desc;
+ HeapTuple tuple;
+ Datum *values;
+ char *nulls;
+ int i;
+
+ Assert(PyMapping_Check(mapping));
+
+ desc = lookup_rowtype_tupdesc(info->out.d.typoid, -1);
+ if (info->is_rowtype == 2)
+ PLy_output_tuple_funcs(info, desc);
+ Assert(info->is_rowtype == 1);
+
+ /* Build tuple */
+ values = palloc(sizeof(Datum)*desc->natts);
+ nulls = palloc(sizeof(char)*desc->natts);
+ for (i = 0; i < desc->natts; ++i)
+ {
+ char *key;
+ PyObject *value,
+ *so;
+
+ key = NameStr(desc->attrs[i]->attname);
+ value = so = NULL;
+ PG_TRY();
+ {
+ value = PyMapping_GetItemString(mapping, key);
+ if (value == Py_None)
+ {
+ values[i] = (Datum) NULL;
+ nulls[i] = 'n';
+ }
+ else if (value)
+ {
+ char *valuestr;
+
+ so = PyObject_Str(value);
+ if (so == NULL)
+ PLy_elog(ERROR, "can't convert mapping type");
+ valuestr = PyString_AsString(so);
+
+ values[i] = InputFunctionCall(&info->out.r.atts[i].typfunc
+ , valuestr
+ , info->out.r.atts[i].typioparam
+ , -1);
+ Py_DECREF(so);
+ so = NULL;
+ nulls[i] = ' ';
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_COLUMN),
+ errmsg("no mapping found with key \"%s\"", key),
+ errhint("to return null in specific column, "
+ "add value None to map with key named after column")));
+
+ Py_XDECREF(value);
+ value = NULL;
+ }
+ PG_CATCH();
+ {
+ Py_XDECREF(so);
+ Py_XDECREF(value);
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+ }
+
+ tuple = heap_formtuple(desc, values, nulls);
+ ReleaseTupleDesc(desc);
+ pfree(values);
+ pfree(nulls);
+
+ return tuple;
+}
+
+
+static HeapTuple
+PLySequence_ToTuple(PLyTypeInfo *info, PyObject *sequence)
+{
+ TupleDesc desc;
+ HeapTuple tuple;
+ Datum *values;
+ char *nulls;
+ int i;
+
+ Assert(PySequence_Check(sequence));
+
+ /*
+ * Check that sequence length is exactly same as PG tuple's. We actually
+ * can ignore exceeding items or assume missing ones as null but to
+ * avoid plpython developer's errors we are strict here
+ */
+ desc = lookup_rowtype_tupdesc(info->out.d.typoid, -1);
+ if (PySequence_Length(sequence) != desc->natts)
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("returned sequence's length must be same as tuple's length")));
+
+ if (info->is_rowtype == 2)
+ PLy_output_tuple_funcs(info, desc);
+ Assert(info->is_rowtype == 1);
+
+ /* Build tuple */
+ values = palloc(sizeof(Datum)*desc->natts);
+ nulls = palloc(sizeof(char)*desc->natts);
+ for (i = 0; i < desc->natts; ++i)
+ {
+ PyObject *value,
+ *so;
+
+ value = so = NULL;
+ PG_TRY();
+ {
+ value = PySequence_GetItem(sequence, i);
+ Assert(value);
+ if (value == Py_None)
+ {
+ values[i] = (Datum) NULL;
+ nulls[i] = 'n';
+ }
+ else if (value)
+ {
+ char *valuestr;
+
+ so = PyObject_Str(value);
+ if (so == NULL)
+ PLy_elog(ERROR, "can't convert sequence type");
+ valuestr = PyString_AsString(so);
+ values[i] = InputFunctionCall(&info->out.r.atts[i].typfunc
+ , valuestr
+ , info->out.r.atts[i].typioparam
+ , -1);
+ Py_DECREF(so);
+ so = NULL;
+ nulls[i] = ' ';
+ }
+
+ Py_XDECREF(value);
+ value = NULL;
+ }
+ PG_CATCH();
+ {
+ Py_XDECREF(so);
+ Py_XDECREF(value);
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+ }
+
+ tuple = heap_formtuple(desc, values, nulls);
+ ReleaseTupleDesc(desc);
+ pfree(values);
+ pfree(nulls);
+
+ return tuple;
+}
+
+
+static HeapTuple
+PLyObject_ToTuple(PLyTypeInfo *info, PyObject *object)
+{
+ TupleDesc desc;
+ HeapTuple tuple;
+ Datum *values;
+ char *nulls;
+ int i;
+
+ desc = lookup_rowtype_tupdesc(info->out.d.typoid, -1);
+ if (info->is_rowtype == 2)
+ PLy_output_tuple_funcs(info, desc);
+ Assert(info->is_rowtype == 1);
+
+ /* Build tuple */
+ values = palloc(sizeof(Datum)*desc->natts);
+ nulls = palloc(sizeof(char)*desc->natts);
+ for (i = 0; i < desc->natts; ++i)
+ {
+ char *key;
+ PyObject *value,
+ *so;
+
+ key = NameStr(desc->attrs[i]->attname);
+ value = so = NULL;
+ PG_TRY();
+ {
+ value = PyObject_GetAttrString(object, key);
+ if (value == Py_None)
+ {
+ values[i] = (Datum) NULL;
+ nulls[i] = 'n';
+ }
+ else if (value)
+ {
+ char *valuestr;
+
+ so = PyObject_Str(value);
+ if (so == NULL)
+ PLy_elog(ERROR, "can't convert object type");
+ valuestr = PyString_AsString(so);
+ values[i] = InputFunctionCall(&info->out.r.atts[i].typfunc
+ , valuestr
+ , info->out.r.atts[i].typioparam
+ , -1);
+ Py_DECREF(so);
+ so = NULL;
+ nulls[i] = ' ';
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_COLUMN),
+ errmsg("no attribute named \"%s\"", key),
+ errhint("to return null in specific column, "
+ "let returned object to have attribute named "
+ "after column with value None")));
+
+ Py_XDECREF(value);
+ value = NULL;
+ }
+ PG_CATCH();
+ {
+ Py_XDECREF(so);
+ Py_XDECREF(value);
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+ }
+
+ tuple = heap_formtuple(desc, values, nulls);
+ ReleaseTupleDesc(desc);
+ pfree(values);
+ pfree(nulls);
+
+ return tuple;
+}
+
+
/* initialization, some python variables function declared here */
/* interface to postgresql elog */
return "succeeded, as expected"'
LANGUAGE plpythonu;
-CREATE FUNCTION import_test_one(text) RETURNS text
+CREATE FUNCTION import_test_one(p text) RETURNS text
AS
'import sha
-digest = sha.new(args[0])
+digest = sha.new(p)
return digest.hexdigest()'
LANGUAGE plpythonu;
-CREATE FUNCTION import_test_two(users) RETURNS text
+CREATE FUNCTION import_test_two(u users) RETURNS text
AS
'import sha
-plain = args[0]["fname"] + args[0]["lname"]
+plain = u["fname"] + u["lname"]
digest = sha.new(plain);
return "sha hash of " + plain + " is " + digest.hexdigest()'
LANGUAGE plpythonu;
-CREATE FUNCTION argument_test_one(users, text, text) RETURNS text
+CREATE FUNCTION argument_test_one(u users, a1 text, a2 text) RETURNS text
AS
-'keys = args[0].keys()
+'keys = u.keys()
keys.sort()
out = []
for key in keys:
- out.append("%s: %s" % (key, args[0][key]))
-words = args[1] + " " + args[2] + " => {" + ", ".join(out) + "}"
+ out.append("%s: %s" % (key, u[key]))
+words = a1 + " " + a2 + " => {" + ", ".join(out) + "}"
return words'
LANGUAGE plpythonu;
-- nested calls
--
-CREATE FUNCTION nested_call_one(text) RETURNS text
+CREATE FUNCTION nested_call_one(a text) RETURNS text
AS
-'q = "SELECT nested_call_two(''%s'')" % args[0]
+'q = "SELECT nested_call_two(''%s'')" % a
r = plpy.execute(q)
return r[0]'
LANGUAGE plpythonu ;
-CREATE FUNCTION nested_call_two(text) RETURNS text
+CREATE FUNCTION nested_call_two(a text) RETURNS text
AS
-'q = "SELECT nested_call_three(''%s'')" % args[0]
+'q = "SELECT nested_call_three(''%s'')" % a
r = plpy.execute(q)
return r[0]'
LANGUAGE plpythonu ;
-CREATE FUNCTION nested_call_three(text) RETURNS text
+CREATE FUNCTION nested_call_three(a text) RETURNS text
AS
-'return args[0]'
+'return a'
LANGUAGE plpythonu ;
-- some spi stuff
-CREATE FUNCTION spi_prepared_plan_test_one(text) RETURNS text
+CREATE FUNCTION spi_prepared_plan_test_one(a text) RETURNS text
AS
'if not SD.has_key("myplan"):
q = "SELECT count(*) FROM users WHERE lname = $1"
SD["myplan"] = plpy.prepare(q, [ "text" ])
try:
- rv = plpy.execute(SD["myplan"], [args[0]])
- return "there are " + str(rv[0]["count"]) + " " + str(args[0]) + "s"
+ rv = plpy.execute(SD["myplan"], [a])
+ return "there are " + str(rv[0]["count"]) + " " + str(a) + "s"
except Exception, ex:
plpy.error(str(ex))
return None
'
LANGUAGE plpythonu;
-CREATE FUNCTION spi_prepared_plan_test_nested(text) RETURNS text
+CREATE FUNCTION spi_prepared_plan_test_nested(a text) RETURNS text
AS
'if not SD.has_key("myplan"):
- q = "SELECT spi_prepared_plan_test_one(''%s'') as count" % args[0]
+ q = "SELECT spi_prepared_plan_test_one(''%s'') as count" % a
SD["myplan"] = plpy.prepare(q)
try:
rv = plpy.execute(SD["myplan"])
/* a typo
*/
-CREATE FUNCTION invalid_type_uncaught(text) RETURNS text
+CREATE FUNCTION invalid_type_uncaught(a text) RETURNS text
AS
'if not SD.has_key("plan"):
q = "SELECT fname FROM users WHERE lname = $1"
SD["plan"] = plpy.prepare(q, [ "test" ])
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
/* for what it's worth catch the exception generated by
* the typo, and return None
*/
-CREATE FUNCTION invalid_type_caught(text) RETURNS text
+CREATE FUNCTION invalid_type_caught(a text) RETURNS text
AS
'if not SD.has_key("plan"):
q = "SELECT fname FROM users WHERE lname = $1"
except plpy.SPIError, ex:
plpy.notice(str(ex))
return None
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
/* for what it's worth catch the exception generated by
* the typo, and reraise it as a plain error
*/
-CREATE FUNCTION invalid_type_reraised(text) RETURNS text
+CREATE FUNCTION invalid_type_reraised(a text) RETURNS text
AS
'if not SD.has_key("plan"):
q = "SELECT fname FROM users WHERE lname = $1"
SD["plan"] = plpy.prepare(q, [ "test" ])
except plpy.SPIError, ex:
plpy.error(str(ex))
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
/* no typo no messing about
*/
-CREATE FUNCTION valid_type(text) RETURNS text
+CREATE FUNCTION valid_type(a text) RETURNS text
AS
'if not SD.has_key("plan"):
SD["plan"] = plpy.prepare("SELECT fname FROM users WHERE lname = $1", [ "text" ])
-rv = plpy.execute(SD["plan"], [ args[0] ])
+rv = plpy.execute(SD["plan"], [ a ])
if len(rv):
return rv[0]["fname"]
return None
LANGUAGE plpythonu;
-CREATE FUNCTION join_sequences(sequences) RETURNS text
+CREATE FUNCTION join_sequences(s sequences) RETURNS text
AS
-'if not args[0]["multipart"]:
- return args[0]["sequence"]
-q = "SELECT sequence FROM xsequences WHERE pid = ''%s''" % args[0]["pid"]
+'if not s["multipart"]:
+ return s["sequence"]
+q = "SELECT sequence FROM xsequences WHERE pid = ''%s''" % s["pid"]
rv = plpy.execute(q)
-seq = args[0]["sequence"]
+seq = s["sequence"]
for r in rv:
seq = seq + r["sequence"]
return seq
CREATE FUNCTION test_return_none() RETURNS int AS $$
None
$$ LANGUAGE plpythonu;
+
+
+--
+-- Test named parameters
+--
+CREATE FUNCTION test_param_names1(a0 integer, a1 text) RETURNS boolean AS $$
+assert a0 == args[0]
+assert a1 == args[1]
+return True
+$$ LANGUAGE plpythonu;
+
+CREATE FUNCTION test_param_names2(u users) RETURNS text AS $$
+assert u == args[0]
+return str(u)
+$$ LANGUAGE plpythonu;
+
+-- use deliberately wrong parameter names
+CREATE FUNCTION test_param_names3(a0 integer) RETURNS boolean AS $$
+try:
+ assert a1 == args[0]
+ return False
+except NameError, e:
+ assert e.args[0].find("a1") > -1
+ return True
+$$ LANGUAGE plpythonu;
+
+
+--
+-- Test returning SETOF
+--
+CREATE FUNCTION test_setof_as_list(count integer, content text) RETURNS SETOF text AS $$
+return [ content ]*count
+$$ LANGUAGE plpythonu;
+
+CREATE FUNCTION test_setof_as_tuple(count integer, content text) RETURNS SETOF text AS $$
+t = ()
+for i in xrange(count):
+ t += ( content, )
+return t
+$$ LANGUAGE plpythonu;
+
+CREATE FUNCTION test_setof_as_iterator(count integer, content text) RETURNS SETOF text AS $$
+class producer:
+ def __init__ (self, icount, icontent):
+ self.icontent = icontent
+ self.icount = icount
+ def __iter__ (self):
+ return self
+ def next (self):
+ if self.icount == 0:
+ raise StopIteration
+ self.icount -= 1
+ return self.icontent
+return producer(count, content)
+$$ LANGUAGE plpythonu;
+
+
+--
+-- Test returning tuples
+--
+CREATE FUNCTION test_table_record_as(typ text, first text, second integer, retnull boolean) RETURNS table_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;
+
+CREATE FUNCTION test_type_record_as(typ text, first text, second integer, retnull boolean) RETURNS type_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;
+
CREATE TABLE unicode_test (
testvalue text NOT NULL
);
+
+CREATE TABLE table_record (
+ first text,
+ second int4
+ ) ;
+
+CREATE TYPE type_record AS (
+ first text,
+ second int4
+ ) ;
SELECT test_void_func1(), test_void_func1() IS NULL AS "is null";
SELECT test_void_func2(); -- should fail
SELECT test_return_none(), test_return_none() IS NULL AS "is null";
+
+-- Test for functions with named parameters
+SELECT test_param_names1(1,'text');
+SELECT test_param_names2(users) from users;
+SELECT test_param_names3(1);
+
+-- Test set returning functions
+SELECT test_setof_as_list(0, 'list');
+SELECT test_setof_as_list(1, 'list');
+SELECT test_setof_as_list(2, 'list');
+SELECT test_setof_as_list(2, null);
+
+SELECT test_setof_as_tuple(0, 'tuple');
+SELECT test_setof_as_tuple(1, 'tuple');
+SELECT test_setof_as_tuple(2, 'tuple');
+SELECT test_setof_as_tuple(2, null);
+
+SELECT test_setof_as_iterator(0, 'list');
+SELECT test_setof_as_iterator(1, 'list');
+SELECT test_setof_as_iterator(2, 'list');
+SELECT test_setof_as_iterator(2, null);
+
+-- Test tuple returning functions
+SELECT * FROM test_table_record_as('dict', null, null, false);
+SELECT * FROM test_table_record_as('dict', 'one', null, false);
+SELECT * FROM test_table_record_as('dict', null, 2, false);
+SELECT * FROM test_table_record_as('dict', 'three', 3, false);
+SELECT * FROM test_table_record_as('dict', null, null, true);
+
+SELECT * FROM test_table_record_as('tuple', null, null, false);
+SELECT * FROM test_table_record_as('tuple', 'one', null, false);
+SELECT * FROM test_table_record_as('tuple', null, 2, false);
+SELECT * FROM test_table_record_as('tuple', 'three', 3, false);
+SELECT * FROM test_table_record_as('tuple', null, null, true);
+
+SELECT * FROM test_table_record_as('list', null, null, false);
+SELECT * FROM test_table_record_as('list', 'one', null, false);
+SELECT * FROM test_table_record_as('list', null, 2, false);
+SELECT * FROM test_table_record_as('list', 'three', 3, false);
+SELECT * FROM test_table_record_as('list', null, null, true);
+
+SELECT * FROM test_table_record_as('obj', null, null, false);
+SELECT * FROM test_table_record_as('obj', 'one', null, false);
+SELECT * FROM test_table_record_as('obj', null, 2, false);
+SELECT * FROM test_table_record_as('obj', 'three', 3, false);
+SELECT * FROM test_table_record_as('obj', null, null, true);
+
+SELECT * FROM test_type_record_as('dict', null, null, false);
+SELECT * FROM test_type_record_as('dict', 'one', null, false);
+SELECT * FROM test_type_record_as('dict', null, 2, false);
+SELECT * FROM test_type_record_as('dict', 'three', 3, false);
+SELECT * FROM test_type_record_as('dict', null, null, true);
+
+SELECT * FROM test_type_record_as('tuple', null, null, false);
+SELECT * FROM test_type_record_as('tuple', 'one', null, false);
+SELECT * FROM test_type_record_as('tuple', null, 2, false);
+SELECT * FROM test_type_record_as('tuple', 'three', 3, false);
+SELECT * FROM test_type_record_as('tuple', null, null, true);
+
+SELECT * FROM test_type_record_as('list', null, null, false);
+SELECT * FROM test_type_record_as('list', 'one', null, false);
+SELECT * FROM test_type_record_as('list', null, 2, false);
+SELECT * FROM test_type_record_as('list', 'three', 3, false);
+SELECT * FROM test_type_record_as('list', null, null, true);
+
+SELECT * FROM test_type_record_as('obj', null, null, false);
+SELECT * FROM test_type_record_as('obj', 'one', null, false);
+SELECT * FROM test_type_record_as('obj', null, 2, false);
+SELECT * FROM test_type_record_as('obj', 'three', 3, false);
+SELECT * FROM test_type_record_as('obj', null, null, true);