PostgreSQL
PrevChapter 39. Server Programming InterfaceNext

Examples

This example of SPI usage demonstrates the visibility rule. There are more complex examples in in src/test/regress/regress.c and in contrib/spi.

This is a very simple example of SPI usage. The procedure execq accepts an SQL-query in its first argument and tcount in its second, executes the query using SPI_exec and returns the number of tuples for which the query executed:

#include "executor/spi.h"	/* this is what you need to work with SPI */

int execq(text *sql, int cnt);

int
execq(text *sql, int cnt)
{
	int ret;
	int proc = 0;
	
	SPI_connect();
	
	ret = SPI_exec(textout(sql), cnt);
	
	proc = SPI_processed;
	/*
	 * If this is SELECT and some tuple(s) fetched -
	 * returns tuples to the caller via elog (NOTICE).
	 */
	if ( ret == SPI_OK_SELECT && SPI_processed > 0 )
	{
		TupleDesc tupdesc = SPI_tuptable->tupdesc;
		SPITupleTable *tuptable = SPI_tuptable;
		char buf[8192];
		int i;
		
		for (ret = 0; ret < proc; ret++)
		{
			HeapTuple tuple = tuptable->vals[ret];
			
			for (i = 1, buf[0] = 0; i <= tupdesc->natts; i++)
				sprintf(buf + strlen (buf), " %s%s",
					SPI_getvalue(tuple, tupdesc, i),
					(i == tupdesc->natts) ? " " : " |");
			elog (NOTICE, "EXECQ: %s", buf);
		}
	}

	SPI_finish();

	return (proc);
}

Now, compile and create the function:

create function execq (text, int4) returns int4 as '...path_to_so' language 'c';
vac=> select execq('create table a (x int4)', 0);
execq
-----
    0
(1 row)

vac=> insert into a values (execq('insert into a values (0)',0));
INSERT 167631 1
vac=> select execq('select * from a',0);
NOTICE:EXECQ:  0 <<< inserted by execq

NOTICE:EXECQ:  1 <<< value returned by execq and inserted by upper INSERT

execq
-----
    2
(1 row)

vac=> select execq('insert into a select x + 2 from a',1);
execq
-----
    1
(1 row)

vac=> select execq('select * from a', 10);
NOTICE:EXECQ:  0 

NOTICE:EXECQ:  1 

NOTICE:EXECQ:  2 <<< 0 + 2, only one tuple inserted - as specified

execq
-----
    3            <<< 10 is max value only, 3 is real # of tuples
(1 row)

vac=> delete from a;
DELETE 3
vac=> insert into a values (execq('select * from a', 0) + 1);
INSERT 167712 1
vac=> select * from a;
x
-
1                <<< no tuples in a (0) + 1
(1 row)

vac=> insert into a values (execq('select * from a', 0) + 1);
NOTICE:EXECQ:  0 
INSERT 167713 1
vac=> select * from a;
x
-
1
2                <<< there was single tuple in a + 1
(2 rows)

--   This demonstrates data changes visibility rule:

vac=> insert into a select execq('select * from a', 0) * x from a;
NOTICE:EXECQ:  1 
NOTICE:EXECQ:  2 
NOTICE:EXECQ:  1 
NOTICE:EXECQ:  2 
NOTICE:EXECQ:  2 
INSERT 0 2
vac=> select * from a;
x
-
1
2
2                <<< 2 tuples * 1 (x in first tuple)
6                <<< 3 tuples (2 + 1 just inserted) * 2 (x in second tuple)
(4 rows)             ^^^^^^^^ 
                     tuples visible to execq() in different invocations


PrevHomeNext
Visibility of Data ChangesUplibpq