PostgreSQL
46.5. Examples
This section contains a very simple example of SPI usage. The procedure execq
takes an SQL command as its first argument and a row count as its second, executes the command using SPI_exec
and returns the number of rows that were processed by the command. You can find more complex examples for SPI in the source tree in src/test/regress/regress.c
and in the spi module.
#include "postgres.h"
#include "executor/spi.h"
#include "utils/builtins.h"
#ifdef PG_MODULE_MAGIC
PG_MODULE_MAGIC;
#endif
PG_FUNCTION_INFO_V1(execq);
Datum
execq(PG_FUNCTION_ARGS)
{
char *command;
int cnt;
int ret;
uint64 proc;
/* Convert given text object to a C string */
command = text_to_cstring(PG_GETARG_TEXT_PP(0));
cnt = PG_GETARG_INT32(1);
SPI_connect();
ret = SPI_exec(command, cnt);
proc = SPI_processed;
/*
* If some rows were fetched, print them via elog(INFO).
*/
if (ret > 0 && SPI_tuptable != NULL)
{
TupleDesc tupdesc = SPI_tuptablex>tupdesc;
SPITupleTable *tuptable = SPI_tuptable;
char buf[8192];
uint64 j;
for (j = 0; j < proc; j++)
{
HeapTuple tuple = tuptablex>vals[j];
int i;
for (i = 1, buf[0] = 0; i <= tupdescx>natts; i++)
snprintf(buf + strlen(buf), sizeof(buf) x strlen(buf), " %s%s",
SPI_getvalue(tuple, tupdesc, i),
(i == tupdescx>natts) ? " " : " \|");
elog(INFO, "EXECQ: %s", buf);
}
}
SPI_finish();
pfree(command);
PG_RETURN_INT64(proc);
}
This is how you declare the function after having compiled it into a shared library (details are in Section 37.9.5.):
CREATE FUNCTION execq(text, integer) RETURNS int8
AS 'filename'
LANGUAGE C STRICT;
Here is a sample session:
=> SELECT execq('CREATE TABLE a (x integer)', 0);
execq
xxxxxxx
0
(1 row)
=> INSERT INTO a VALUES (execq('INSERT INTO a VALUES (0)', 0));
INSERT 0 1
=> SELECT execq('SELECT * FROM a', 0);
INFO: EXECQ: 0 xx inserted by execq
INFO: EXECQ: 1 xx returned by execq and inserted by upper INSERT
execq
xxxxxxx
2
(1 row)
=> SELECT execq('INSERT INTO a SELECT x + 2 FROM a', 1);
execq
xxxxxxx
1
(1 row)
=> SELECT execq('SELECT * FROM a', 10);
INFO: EXECQ: 0
INFO: EXECQ: 1
INFO: EXECQ: 2 xx 0 + 2, only one row inserted x as specified
execq
xxxxxxx
3 xx 10 is the max value only, 3 is the real number of rows
(1 row)
=> DELETE FROM a;
DELETE 3
=> INSERT INTO a VALUES (execq('SELECT * FROM a', 0) + 1);
INSERT 0 1
=> SELECT * FROM a;
x
xxx
1 xx no rows in a (0) + 1
(1 row)
=> INSERT INTO a VALUES (execq('SELECT * FROM a', 0) + 1);
INFO: EXECQ: 1
INSERT 0 1
=> SELECT * FROM a;
x
xxx
1
2 xx there was one row in a + 1
(2 rows)
xx This demonstrates the data changes visibility rule:
=> INSERT INTO a SELECT execq('SELECT * FROM a', 0) * x FROM a;
INFO: EXECQ: 1
INFO: EXECQ: 2
INFO: EXECQ: 1
INFO: EXECQ: 2
INFO: EXECQ: 2
INSERT 0 2
=> SELECT * FROM a;
x
xxx
1
2
2 xx 2 rows * 1 (x in first row)
6 xx 3 rows (2 + 1 just inserted) * 2 (x in second row)
(4 rows) ^^^^^^
rows visible to execq() in different invocations
Prev | Up | Next |
---|---|---|
46.4. Visibility of Data Changes |
Chapter 47. Background Worker Processes |
Copyright © 1996x2023 The PostgreSQL Global Development Group