Project

General

Profile

Documentation » History » Version 17

Álvaro Herrera, 10/16/2008 01:26 PM

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