Project

General

Profile

Documentation » History » Version 14

Álvaro Herrera, 12/20/2005 10:07 AM
Update to current SRF status.

1 6 Álvaro Herrera
= PL/php - PHP Procedural Language for PostgreSQL =
2 1 bford -
3 4 Álvaro Herrera
[[PageOutline(2-3,Contents,inline)]]
4 1 bford -
5 6 Álvaro Herrera
== What is PL/php? ==
6 1 bford -
7 6 Álvaro Herrera
PL/php is a procedural language with hooks into the PostgreSQL
8 8 Álvaro Herrera
database sytem, intended to allow writing of PHP functions for
9
use as functions inside the PostgreSQL database.
10
It was written by Command Prompt, Inc. and has since
11 1 bford -
been open sourced and licensed under the PHP and PostgreSQL (BSD)
12
licenses.
13
14
== Download and Installation ==
15 3 Álvaro Herrera
16 8 Álvaro Herrera
Please see [wiki:InstallDocs10 the installation documentation] for instructions on
17
how to install PL/php 1.0.  To install the new code, which only works with PostgreSQL
18
8.0 and 8.1 and is currently in development, see [wiki:InstallDocs this page instead].
19 7 Álvaro Herrera
20 1 bford -
== Creating the PL/php language ==
21 7 Álvaro Herrera
22 8 Álvaro Herrera
Please see the documentation on [wiki:CreateLang80 how to create the language in a database]
23
once the library is installed.  If you are using PostgreSQL 8.1 you must follow
24
[wiki:CreateLang these other instructions] instead.
25 7 Álvaro Herrera
26 2 Álvaro Herrera
== Functions and Arguments ==
27 3 Álvaro Herrera
28 1 bford -
To create a function, use the standard syntax:
29
30
31
{{{
32 6 Álvaro Herrera
CREATE FUNCTION funcname (argument-types) RETURNS return-type AS $$
33 1 bford -
   # plphp function body here
34 6 Álvaro Herrera
$$ LANGUAGE 'plphp';
35 1 bford -
}}}
36
37
38
Arguments are passed in the $args array and the result value is returned
39
with the 'return' statement.
40
41 2 Álvaro Herrera
42 1 bford -
{{{
43 6 Álvaro Herrera
CREATE FUNCTION plphp_max(integer, integer) RETURNS integer AS $$
44 1 bford -
   if ($args[0] > $args[1]) {
45
      return $args[0];
46
   } else {
47
      return $args[1];
48
   }     
49 6 Álvaro Herrera
$$ STRICT LANGUAGE 'plphp'
50 1 bford -
}}}
51
52 2 Álvaro Herrera
53 1 bford -
NOTE: The use of the STRICT clause saves us from having to
54
think about NULL input values to our function.  If a NULL value is
55 2 Álvaro Herrera
passed, the function will not be run at all, but will rather just
56 1 bford -
return a NULL result automatically.
57
58
In a non-strict function, if the actual value of an argument is NULL,
59
the corresponding $args[n-1] variable will be set to an empty string
60
(unset).
61
62
63
== Data Types and Returns ==
64
65 9 Álvaro Herrera
The arguments passed into your PL/php function are converted to text
66 3 Álvaro Herrera
so you can manipulate them with the loose typing enjoyed in typical
67 1 bford -
PHP scripts.  Conversely, the return command will accept any string
68
that is acceptable input format for the function's declared return
69
type.
70
71
72 3 Álvaro Herrera
== Global Shared Variable ==
73 1 bford -
74
There is a global variable that can be used to store data between
75
function calls, called $_SHARED.
76
77
{{{
78 6 Álvaro Herrera
CREATE FUNCTION set_var(text) RETURNS text AS $$
79 1 bford -
   global $_SHARED;
80 6 Álvaro Herrera
   $_SHARED['first']=$args[0];
81
   return 'ok';
82
$$ LANGUAGE 'plphp';
83 1 bford -
84 6 Álvaro Herrera
CREATE FUNCTION get_var() RETURNS text AS $$
85 1 bford -
   global $_SHARED;
86 6 Álvaro Herrera
   return $_SHARED['first'];
87
$$ LANGUAGE 'plphp';
88 1 bford -
89
SELECT set_var('hello plphp');
90
SELECT get_var(); -- will return 'hello plphp'
91
}}}
92
93
NOTE: The shared global variable is connection-specific.  This is
94
useful for passing information around a single script execution,
95 2 Álvaro Herrera
but it is wiped when the connection is closed.
96
97
98 3 Álvaro Herrera
== PostgreSQL Array Support ==
99 1 bford -
100
There is support for multi-dimensional arrays.
101
102
For example:
103
104
{{{
105 6 Álvaro Herrera
CREATE FUNCTION php_array() RETURNS text[][] AS $$
106 1 bford -
   $return = array(array("Steven", "Klassen"),
107
                   array("Jonathan", "Daugherty"));
108
109
   return $return;
110 6 Álvaro Herrera
$$ LANGUAGE 'plphp';
111 1 bford -
}}}
112
113
114
{{{
115
sklassen=# select php_array();
116
                php_array                
117
-----------------------------------------
118
 {{Steven,Klassen},{Jonathan,Daugherty}}
119
(1 row)
120
}}}
121
122
123 3 Álvaro Herrera
== Polymorphic Arguments and Return Types ==
124 1 bford -
125
Functions may be declared to accept and return the polymorphic types
126
'anyelement', 'anyarray', and 'anyrecord'.  See the PostgreSQL
127
documentation section 33.2.5 for a more detailed explanation of
128
polymorphic functions.
129
130
For example,
131
132
{{{
133
CREATE FUNCTION array_three_values(anyelement, anyelement, anyelement) RETURNS anyarray AS '
134
   $ret[0] = $args[0];
135
   $ret[1] = $args[1];
136
   $ret[2] = $args[2];
137
   return $ret;
138
' LANGUAGE 'plphp';
139
140
SELECT array_three_values(3,2,1);
141
 array_three_values
142
--------------------
143
 {3,2,1}
144
(1 row)
145
146
CREATE OR REPLACE FUNCTION php_row(integer) RETURNS record AS '
147
   $ret[f1]=$args[0];
148
   $ret[f2]="hello";
149
   $ret[f3]="world";
150
   return $ret;
151
' LANGUAGE 'plphp';
152
153
select * FROM php_row(1) AS (f1 integer, f2 text, f3 text);
154
}}}
155
156
157
== Database Access (SPI) ==
158
159 12 Álvaro Herrera
Some functions are provided for database access.
160 1 bford -
161 12 Álvaro Herrera
 1. spi_exec - Execute a query with optional limit.
162 1 bford -
{{{
163 12 Álvaro Herrera
resource spi_exec(string query[, int limit])
164 1 bford -
}}}
165
 1. spi_fetch_row - Return an associative array of the row's results.
166
{{{
167
array spi_fetch_row(resource result)
168
}}}
169 12 Álvaro Herrera
 1. spi_status - Return the status of a previous query.  If this is SPI_OK_SELECT you can obtain tuples from the result using spi_fetch_row.
170
{{{
171
string spi_status(resource result)
172
}}}
173
 1. spi_processed - Return the number of tuples in a result.
174
{{{
175
int spi_processed(resource result)
176
}}}
177
 1. spi_rewind - Put the row cursor at the beginning of the result, so spi_fetch_row will continue fetching tuples from the beginning of the result.
178
{{{
179
void spi_rewind(resource result)
180
}}}
181 1 bford -
182
For example:
183
184
This isn't a particularly useful function, but it will illustrate the
185
above-described access functions.  You provide an integer id and it
186
returns the username text field.
187
188
{{{
189 12 Álvaro Herrera
CREATE FUNCTION get_username(integer) RETURNS text AS $$
190 1 bford -
   # Assign the query to a variable.
191
   $query = "SELECT username FROM users WHERE id = " .$args[0];
192
193
   # Run the query and get the $result object.
194
   $result = spi_exec_query($query);
195
196
   # Fetch the row from the $result.
197
   $row = spi_fetch_row($result);
198
199 12 Álvaro Herrera
   return $row['username'];
200
$$ LANGUAGE 'plphp';
201 1 bford -
202
sklassen=# select get_username(1);
203
 get_username 
204
--------------
205
 sklassen
206
(1 row)
207
}}}
208
209 14 Álvaro Herrera
Note that results from spi_exec_query are allocated in RAM as a whole, so if you need to process huge result sets, you need to use a cursor.  This is not possible with the current interface however, so if you need to do this, bug the developers.
210
211 1 bford -
== Triggers ==
212 4 Álvaro Herrera
213 1 bford -
When a function is being used to return a trigger, the associative
214
array $_TD contains trigger-related values.
215
216 4 Álvaro Herrera
 $_TD["new"]::
217 1 bford -
   An associative array containing the values of the new table row for
218
   INSERT/UPDATE actions, or empty for DELETE.  The array is indexed
219
   by field name.  Important note: Fields that are NULL will not
220
   appear in the array!
221 4 Álvaro Herrera
 $_TD["old"]::
222 1 bford -
   An associative array containing the values of the old table row for
223 9 Álvaro Herrera
   UPDATE/DELETE actions, or empty for INSERT.  The array is indexed
224 1 bford -
   by field name.  Important note: Fields that are NULL will not
225
   appear in the array!
226 9 Álvaro Herrera
 $_TD["name"]::
227 1 bford -
   Contains the trigger name itself.
228 4 Álvaro Herrera
 $_TD["event"]::
229 9 Álvaro Herrera
   Contains one of the values: "INSERT", "UPDATE", "DELETE".
230 1 bford -
 $_TD["when"]::
231 4 Álvaro Herrera
   Contains one of the values: "BEFORE", "AFTER".
232 1 bford -
 $_TD["level"]::
233
   Contains one of the values: "ROW", "STATEMENT".
234
 $_TD["relid"]::
235
   Contains the relation ID of the table on which the trigger occured.
236 4 Álvaro Herrera
 $_TD["relname"]::
237 1 bford -
   Contains the relation name.
238 10 Álvaro Herrera
 $_TD["args"]::
239 1 bford -
   An array of arguments passed to the trigger, if any.  They can be
240 12 Álvaro Herrera
   accessed as $_TD["args"][idx].  For example, $_TD["args"]![0].
241 1 bford -
 $_TD["argc"]::
242 12 Álvaro Herrera
  The number of arguments passed to the trigger, 0 if none.
243 4 Álvaro Herrera
244 1 bford -
=== Example of an AFTER INSERT trigger ===
245 2 Álvaro Herrera
246 1 bford -
Suppose you have a users table with the typical columns and an
247 3 Álvaro Herrera
activity table that you're using to track page accesses.  On row
248 1 bford -
249
INSERT to the activity table, you want to update the last_seen field
250
of the appropriate user's record.
251
252
Consider the following table definitions:
253
254
{{{
255
CREATE TABLE users (
256
    id serial PRIMARY KEY NOT NULL,
257
    username text NOT NULL,
258
    email text,
259
    last_seen timestamp without time zone,
260
    active boolean DEFAULT true NOT NULL
261
);
262
263
CREATE TABLE activity (
264
    id serial PRIMARY KEY NOT NULL,
265
    users_id integer NOT NULL,
266
    file_accessed text NOT NULL,
267
    stamp timestamp without time zone DEFAULT now() NOT NULL,
268
    CONSTRAINT users_id_exists FOREIGN KEY (users_id) REFERENCES users(id)
269
);
270
271 13 Álvaro Herrera
CREATE FUNCTION update_lastseen() RETURNS trigger AS $$
272
    $new =& $_TD['new'];
273 1 bford -
274 13 Álvaro Herrera
    if (isset($new['users_id']) && isset($new['stamp'])) {
275
        $query = "UPDATE users SET last_seen = '" .$new['stamp'].
276
                 "' WHERE id = " .$new['users_id'];
277 1 bford -
278 13 Álvaro Herrera
        $rv = spi_exec($query);
279 1 bford -
    }
280
281
    return;
282 13 Álvaro Herrera
$$ LANGUAGE 'plphp';
283 1 bford -
284
CREATE TRIGGER after_update_lastseen_trigger
285
    AFTER INSERT ON activity FOR EACH ROW EXECUTE PROCEDURE update_lastseen();
286
287
}}}
288
289
'''1. We'll insert a new user row.'''
290
291
292
{{{
293
sklassen=# insert into users (username, email) values ('sklassen','sklassen@commandprompt.com');
294
INSERT 1
295
296
sklassen=# select * from users where username = 'sklassen';
297
298
 id | username |           email            | last_seen | active 
299
----+----------+----------------------------+-----------+--------
300
  1 | sklassen | sklassen@commandprompt.com |           | t
301
(1 row)
302
}}}
303
304
305
'''2. Insert a new row into the activity table.'''
306
307
308
{{{
309
sklassen=# insert into activity (users_id, file_accessed) values (1,'index.html');
310
INSERT 1
311
}}}
312
313
'''3. Check and make sure our trigger fired as expected.'''
314
315
{{{
316
sklassen=# select * from users where username = 'sklassen';
317
 id | username |           email            |         last_seen          | active 
318
----+----------+----------------------------+----------------------------+--------
319
  1 | sklassen | sklassen@commandprompt.com | 2005-01-10 09:48:57.191595 | t
320
(1 row)
321
}}}
322
323
=== Example of a BEFORE INSERT OR UPDATE trigger ===
324
325
Let's say we have a user named admin that we want to prevent the
326 12 Álvaro Herrera
application from modifying.  We'll create a BEFORE DELETE trigger that
327 1 bford -
prevents them from deleting the row and a BEFORE UPDATE trigger that
328
prevents them modifying the username on which the previous trigger
329
depends.
330
331
{{{
332 12 Álvaro Herrera
CREATE TABLE users (username text, email text);
333
INSERT INTO users VALUES ('admin', 'admin@commandprompt.com');
334
INSERT INTO users VALUES ('darcy', 'darcy@example.com');
335
336
CREATE OR REPLACE FUNCTION immortal() RETURNS trigger AS $$
337 1 bford -
   # The record may not be deleted if the username is "admin".
338 12 Álvaro Herrera
   if ($_TD['old']['username'] == 'admin') {
339
      pg_raise('notice', "You cannot delete the admin user");
340
      return 'SKIP';
341
   }
342
   return;
343
$$ LANGUAGE 'plphp';
344 1 bford -
345
CREATE TRIGGER before_delete_immortal_trigger BEFORE DELETE ON users
346
FOR EACH ROW EXECUTE PROCEDURE immortal();
347
348 12 Álvaro Herrera
CREATE OR REPLACE FUNCTION protect_admin() RETURNS trigger AS $$
349 1 bford -
   # Do not let them modify the username of the admin account.
350 12 Álvaro Herrera
   $oldUsername = $_TD['old']['username'];
351
   $newUsername = $_TD['new']['username'];
352 1 bford -
353 12 Álvaro Herrera
   if ($oldUsername == 'admin' && ($oldUsername != $newUsername)) {
354
      pg_raise('notice', "You cannot change the admin username.");
355
      return 'SKIP';
356 1 bford -
   } else {
357 12 Álvaro Herrera
      return;
358 1 bford -
   }
359 12 Álvaro Herrera
$$ LANGUAGE 'plphp';
360 1 bford -
361
CREATE TRIGGER before_update_protect_admin_trigger BEFORE UPDATE ON
362
users FOR EACH ROW EXECUTE PROCEDURE protect_admin();
363 12 Álvaro Herrera
}}}
364 1 bford -
365 12 Álvaro Herrera
Now the user admin cannot be deleted, nor its username can be changed:
366
367
{{{
368
pl_regression=# select * from users;
369
 username |          email          
370
----------+-------------------------
371
 admin    | admin@commandprompt.com
372
 darcy    | darcy@example.com
373 1 bford -
(2 rows)
374
375 12 Álvaro Herrera
pl_regression=# update users set username = 'foobar';
376
NOTICE:  plphp: You cannot change the admin username.
377
UPDATE 1
378 1 bford -
379 12 Álvaro Herrera
pl_regression=# select * from users;
380
 username |          email          
381
----------+-------------------------
382
 admin    | admin@commandprompt.com
383
 foobar   | darcy@example.com
384
(2 rows)
385 1 bford -
386 12 Álvaro Herrera
pl_regression=# delete from users;
387
NOTICE:  plphp: You cannot delete the admin user
388
DELETE 1
389
390
pl_regression=# select * from users;
391
 username |          email          
392
----------+-------------------------
393
 admin    | admin@commandprompt.com
394
(1 row)
395 1 bford -
}}}
396
397
398
== Trusted vs. Untrusted ==
399
400
Normally, PL/php is installed as a "trusted" procedural language named
401
'plphp'.  In this configuration, PHP will run in "safe mode".  Read
402
more about the restrictions here:
403
404
http://www.php.net/manual/en/features.safe-mode.functions.php
405
406
In general, the operations that are restricted are those that interact
407
with the environment.  This includes file operations, require, and use
408
(for external modules).
409
410
Since there is no way to gain access to the internals of the database
411
backend process or the operating system itself, any unprivileged
412
database user may use functions written in this language.
413
414
An example of a NON-working function due to security constraints:
415
416
{{{
417
CREATE FUNCTION read_passwd_file() RETURNS text AS '
418
   readfile("/etc/passwd");
419
   return 0;
420
' LANGUAGE 'plphp';
421
}}}
422
423
It will appear to execute, but depending on your log level, you'll may
424
see something like the following:
425
426
{{{
427
Warning: readfile(): SAFE MODE Restriction in effect. The script
428
whose uid is 500 is not allowed to access /etc/passwd owned by uid 0
429
in Command line code on line 3
430
431
Warning: readfile(/etc/passwd): failed to open stream: Success in
432 4 Álvaro Herrera
plphp function source on line 3
433
}}}
434 1 bford -
435
Sometimes it is desirable to write PHP functions that are not
436
restricted.  In this case, you can create the language as 'plphpu' to
437
enable the previously unavailable functions.
438
  
439
{{{
440 12 Álvaro Herrera
 CREATE LANGUAGE plphpu;
441 1 bford -
}}}
442 4 Álvaro Herrera
443 1 bford -
444
== Composite Type Arguments ==
445
446
Composite-type arguments are passed to the function as associative
447
array. The keys of the array are the attribute names of
448
the composite type. Here is an example:
449
450
{{{
451
CREATE TABLE employee (
452
   name text,
453
   basesalary integer,
454
   bonus integer
455
);
456
457
CREATE FUNCTION empcomp(employee) RETURNS integer AS '
458
   return $args[0][''basesalary''] + $args[0][''bonus''];
459
' LANGUAGE 'plphp';
460
461 12 Álvaro Herrera
INSERT INTO employee values ('Josh', 1000, 10);
462
INSERT INTO employee values ('Darcy', 500, 20);
463
464 1 bford -
SELECT name, empcomp(employee) FROM employee;
465 12 Álvaro Herrera
}}}
466 1 bford -
467 12 Álvaro Herrera
This example results in the following output:
468
469
{{{
470
 name  | empcomp 
471
-------+---------
472
 Josh  |    1010
473
 Darcy |     520
474
(2 rows)
475 1 bford -
}}}
476
477
== Returning A Row (composite type) ==
478
479
To return a row or composite-type value from a PL/php-language
480
function, you can use an indexed array:
481
482
{{{
483 12 Álvaro Herrera
CREATE TYPE php_row AS (f1 integer, f2 text, f3 text);
484 1 bford -
485 12 Álvaro Herrera
CREATE OR REPLACE FUNCTION php_row(integer) RETURNS php_row AS $$
486
   $ret['f1'] = $args[0];
487
   $ret['f3'] = "world";
488
   $ret['f2'] = "hello";
489 1 bford -
   return $ret;
490 12 Álvaro Herrera
$$ LANGUAGE 'plphp';
491 1 bford -
492 12 Álvaro Herrera
SELECT * FROM php_row(1);
493
}}}
494 6 Álvaro Herrera
495 1 bford -
Will return:
496 12 Álvaro Herrera
{{{
497 6 Álvaro Herrera
 f1 |  f2   |  f3
498 2 Álvaro Herrera
----+-------+-------
499 1 bford -
  1 | hello | world
500
}}}
501
502
503
== Returning multiple rows (SRF functions) ==
504
505
SRF stands for "set-returning functions".  This means you can return
506 2 Álvaro Herrera
multiple rows, like in the following example:
507 1 bford -
508
{{{
509 14 Álvaro Herrera
CREATE TYPE phprow AS (f1 integer, f2 text, f3 text);
510 1 bford -
511 14 Álvaro Herrera
CREATE OR REPLACE FUNCTION php_set(integer) RETURNS SETOF phprow AS $$
512
   $ret['f1'] = $args[0];
513
   $ret['f2'] = "hello";
514
   $ret['f3'] = "world";
515
   return_next($ret);
516 1 bford -
517 14 Álvaro Herrera
   $ret['f1'] = 2 * $args[0];
518
   $ret['f2'] = "hello";
519
   $ret['f3'] = "postgres";
520
   return_next($ret);
521 1 bford -
522 14 Álvaro Herrera
   $ret['f1'] = 3 * $args[0];
523
   $ret['f2'] = "hello";
524
   $ret['f3'] = "plphp";
525
   return_next($ret);
526
$$ LANGUAGE 'plphp';
527
}}}
528 1 bford -
529 14 Álvaro Herrera
This will result in:
530
{{{
531
pl_regression=# SELECT * FROM php_set(1);
532 1 bford -
 f1 |  f2   |    f3
533
----+-------+----------
534
  1 | hello | world
535 3 Álvaro Herrera
  2 | hello | postgres
536 1 bford -
  3 | hello | plphp
537 14 Álvaro Herrera
(3 rows)
538 1 bford -
}}}
539 3 Álvaro Herrera
540 14 Álvaro Herrera
The important thing to notice here is the `return_next()` function.  This function must be called with a single parameter, which must be an array with one element per attribute of the return type.  Note that currently the names of the array elements are ignored; the elements are assigned to attributes in order.  If you must return a null value, asign a null value to an array element.  This may be fixed in a future release.
541
542
Finishing a SRF is done by either calling `return` or by falling off the end of the function.  At that point the entire results are delivered back to the outer query, be it directly to the user or to be joined to other tables/SRFs/etc.
543
544
The return tuples are written to a Postgres "tuplestore", which is disk-backed, and thus do not need to fit entirely in RAM.
545
546 12 Álvaro Herrera
== Limitations ==
547 1 bford -
548
PL/php functions cannot call each other directly because their names
549
are mangled.
550 14 Álvaro Herrera
551
SPI calls have the whole results allocated in memory, so processing huge results may be problematic.  Also it's not possible to use cursors with SPI.