Project

General

Profile

Documentation » History » Version 6

Álvaro Herrera, 11/01/2005 06:31 PM
More markup work

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