Project

General

Profile

Documentation » History » Version 4

Álvaro Herrera, 11/01/2005 05:04 AM

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