PL/v8 ===== PL/v8 is a trusted procedural language that is safe to use, fast to run and easy to develop, powered by V8 JavaScript Engine. The PL/v8 project is maintained at [https://github.com/plv8/plv8](https://github.com/plv8/plv8). ## Table of Contents The documentation covers the following implemented features: - [Requirements](#requirements) - [Installing PL/v8](#installing-plv8) - [Install the PL/v8 Extensions on a Database](#install-the-plv8-extensions-on-a-database) - [Scalar function calls](#scalar-function-calls) - [Set returing function calls](#set-returning-function-calls) - [Trigger function calls](#trigger-function-calls) - [Inline statement calls](#inline-statement-calls) - [Auto mapping between JS and database built-in types](#auto-mapping-between-js-and-database-built-in-types) - [Database access via SPI including prepared statements and cursors](#database-access-via-spi-including-prepared-statements-and-cursors) - [Subtransaction](#subtransaction) - [Utility functions](#utility-functions) - [Window function API](#window-function-api) - [Typed array](#typed-array) - [ES6 Language Features](#es6-language-features) - [Runtime environment separation across users in the same session](#runtime-environment-separation-across-users-in-the-same-session) - [Start-up procedure](#start-up-procedure) - [Update procedure](#update-procedure) - [Dialects](#dialects) ## Requirements: PL/v8 is tested with: - PG: version 9.2, 9.3, 9.4 and 9.5 (maybe older/newer are allowed) - V8: version 4.4 to 5.4 - g++: version 4.8.2 - clang++ Also all tools that PostgreSQL and V8 require to be built are required if you are building those from source. ## Installing PL/v8 ### Build from source: Determine the [PL/v8 release](https://github.com/plv8/plv8/releases) you want to download and use it's version and path below. ```shell $ wget https://github.com/plv8/plv8/archive/v2.0.0.tar.gz $ tar -xvzf v2.0.0.tar.gz $ cd plv8-2.0.0 $ make static ``` This will build PL/v8 for you linking to Google's v8 as a static library by downloading the v8 source at a specific version and building it along with PL/v8. The build will be for the highest PostgreSQL version you have installed on the system. You can alternatively run just `make` and it will build PL/v8 dynamically linking to Google's `libv8` library on your system. There are some issues with this as several linux distros ship a very old version of `libv8`. The `3.x` versions of v8 will work with the `1.4.x` versions of PL/v8, but to build the later versions of PL/v8 you need a v8 minimum version of `4.4.63.31`, but can also use v8 version `5.1.281.14`. PGXN install will use the dynamically linked `libv8` library. If you would like to use `make` and you system does not have a new enough version of `libv8` installed, see the `.travis.yml` file in the repo to see how out CI test servers build v8 natively. > Note: If you have multiple versions of PostgreSQL installed like 9.5 and 9.6, PL/v8 will only be built for PostgreSQL 9.6. This is because `make static` calls `pg_config` to get the version number, which will always be the latest version installed. If you need to build PL/v8 for PostgreSQL 9.5 while you have 9.6 installed pass `make` the `PG_CONFIG` variable to your 9.5 version of `pg_config`. This works for `make`, `make static`, `make install`. For example in Ubuntu: ```shell $ make PG_CONFIG=/usr/lib/postgresql/9.5/bin/pg_config ``` > Note: You may run into problems with your C++ complier version. You can pass `make` the `CUSTOM_CC` variable to change the complier. For example, to use `g++` version 4.9: ```shell $ make CUSTOM_CC g++-4.9 ``` > Note: In `mingw64`, you may have difficulty in building PL/v8. If so, try to make the following changes in Makefile. For more detail, please refer to https://github.com/plv8/plv8/issues/29 ``` CUSTOM_CC = gcc SHLIB_LINK := $(SHLIB_LINK) -lv8 -Wl,-Bstatic -lstdc++ -Wl,-Bdynamic -lm ``` ### Test the Build PL/v8 supports installcheck test. Make sure to set `custom_variable_classes = 'plv8'` in your postgresql.conf (before 9.2) and run: ```shell $ make installcheck ``` ### Installing the build: After running `make` or `make static` the following files must be copied to the correct location for PostgreSQL to find them: #### PL/v8 JavaScript Extension: - `plv8.so` - `plv8.control` - `plv8--{plv8-build-version-here}.sql` The following files will also be build and can be optionally installed if you need the CoffeeScript or LiveScript versions: #### CoffeeScript Extension: - plcoffee.control - plcoffee--{plv8-build-version-here}.sql #### LiveScript Extension: - plls.control - plls--{plv8-build-version-here}.sql ### Automatically Install the Build You can install the build for your system by running: ```shell $ make install ``` > Note: You should do this a root/admin. `sudo make install` > Note: If you need to install PL/v8 for a different version of PostgreSQL, pass the `PG_CONFIG` variable. See above. ### Debian/Ubuntu 14.04 and 16.04: You can install PL/v8 using `apt-get`, but it will be version `v1.4.8` (As of 2016-12-16). ```shell $ apt-get install postgresql-{your-postgresql-version-here}-plv8 # e.g. $ apt-get install postgresql-9.1-plv8 # OR up to $ apt-get install postgresql-9.6-plv8 ``` ### Redhat/CentOS: TODO - PL/v8 supports Redhat/CentOS. A Pull Request for installation steps is greatly appreciated. ### MacOS: ```shell $ brew install plv8 ``` TODO - PL/v8 supports MacOS. A Pull Request for installation steps is greatly appreciated ### Windows: TODO - PL/v8 supports Windows. A Pull Request for installation steps is greatly appreciated ## Install the PL/v8 Extensions on a Database: Once the PL/v8 extensions have been added to the server, you should restart the PostgreSQL service. Then you can connect to the server and install the extensions on a database by running the following SQL queries in PostgreSQL version 9.1 or later: ```sql CREATE EXTENSION plv8; CREATE EXTENSION plls; CREATE EXTENSION plcoffee; ``` Make sure to set `custom_variable_classes = 'plv8'` in your `postgresql.conf` file for PostgreSQL versions before 9.2. In the versions prior to 9.1 run the following to create database objects: ```shell $ psql -f plv8.sql ``` ### Testing PL/v8 on a database: Below are some example queries to test if the extension is working: ```sql DO $$ plv8.elog(WARNING, 'plv8.version = ' + plv8.version); -- Will output the PL/v8 installed as a PostgreSQL `WARNING`. $$ LANGUAGE plv8; ``` As of 2.0.0, there is a function to determine which version of PL/v8 you have installed: ```sql SELECT plv8_version(); ``` #### JavaScript Example ```sql CREATE OR REPLACE FUNCTION plv8_test(keys text[], vals text[]) RETURNS text AS $$ var o = {}; for(var i=0; i o[key] = vals[idx]; return o), {}), {}) $$ LANGUAGE plcoffee IMMUTABLE STRICT; SELECT plcoffee_test(ARRAY['name', 'age'], ARRAY['Tom', '29']); plcoffee_test --------------------------- {"name":"Tom","age":"29"} (1 row) ``` #### LiveScript Example ```sql CREATE OR REPLACE FUNCTION plls_test(keys text[], vals text[]) RETURNS text AS $$ return JSON.stringify { [key, vals[idx]] for key, idx in keys } $$ LANGUAGE plls IMMUTABLE STRICT; SELECT plls_test(ARRAY['name', 'age'], ARRAY['Tom', '29']); plls_test --------------------------- {"name":"Tom","age":"29"} (1 row) ``` ## Scalar function calls In PL/v8, you can write your SQL invoked function in JavaScript. Use usual CREATE FUNCTION statement with a JS function body. Here is an example of a scalar function call. ```sql CREATE FUNCTION plv8_test(keys text[], vals text[]) RETURNS text AS $$ var o = {}; for(var i=0; i= 9.2)` - `jsonb (>= 9.4)` and the JS value looks compatible, then the conversion succeeds. Otherwise, PL/v8 tries to convert them via cstring representation. An array type is supported only if the dimention is one. A JS object will be mapped to a tuple when applicable. In addition to these types, PL/v8 supports polymorphic types such like anyelement and anyarray. Conversion of bytea is a little different story. See TypedArray section. ## Database access via SPI including prepared statements and cursors ### `plv8.execute( sql [, args] )` Executes SQL statements and retrieve the result. The `args` is an optional argument that replaces $n placeholders in `sql`. For SELECT queries, the returned value is an array of objects. Each hash represents each record. Column names are mapped to object properties. For non-SELECT commands, the returned value is an integer that represents number of affected rows. ```sql var json_result = plv8.execute( 'SELECT * FROM tbl' ); var num_affected = plv8.execute( 'DELETE FROM tbl WHERE price > $1', [ 1000 ] ); ``` Note this function and similar are not allowed outside of transaction. ### `plv8.prepare( sql, [, typenames] )` Opens a prepared statement. The `typename` parameter is an array where each element is a string to indicate database type name for bind parameters. Returned value is an object of PreparedPlan. This object must be freed by plan.free() before leaving the function. ```sql var plan = plv8.prepare( 'SELECT * FROM tbl WHERE col = $1', ['int'] ); var rows = plan.execute( [1] ); var sum = 0; for (var i = 0; i < rows.length; i++) { sum += rows[i].num; } plan.free(); return sum; ``` ### `PreparedPlan.execute( [args] )` Executes the prepared statement. The `args` parameter is as plv8.execute(), and can be omitted if the statement does not have parameters at all. The result of this method is also as described in plv8.execute(). ### `PreparedPlan.cursor( [args] )` Opens a cursor from the prepared statement. The `args` parameter is as `plv8.execute()`, and can be omitted if the statement does not have parameters at all. The returned object is of Cursor. This must be closed by `Cursor.close()` before leaving the function. ```sql var plan = plv8.prepare( 'SELECT * FROM tbl WHERE col = $1', ['int'] ); var cursor = plan.cursor( [1] ); var sum = 0, row; while (row = cursor.fetch()) { sum += row.num; } cursor.close(); plan.free(); return sum; ``` ### `PreparedPlan.free()` Frees the prepared statement. ### `Cursor.fetch( [nrows] )` When `nrows` parameter is omitted, fetches a row from the cursor and return as an object (note: not an array.) If specified, fetches as many rows as the parameters up to exceeding, and returns an array of objects. A negative value for this parameter will fetch backwards. ### `Cursor.move( [nrows] )` Move the cursor `nrows` rows. A negative value will move backwards. ### `Cursor.close()` Closes the cursor. ## Subtransaction ### `plv8.subtransaction( func )` `plv8.execute()` creates a subtransaction every time. If you need an atomic operation, you will need to call `plv8.subtransaction()` to create a subtransaction block. ```sql try{ plv8.subtransaction(function(){ plv8.execute("INSERT INTO tbl VALUES(1)"); -- should be rolled back! plv8.execute("INSERT INTO tbl VALUES(1/0)"); -- occurs an exception }); } catch(e) { ... do fall back plan ... } ``` If one of the SQL execution in the subtransaction block fails, all of operation within the block is rolled back. If the process in the block throws JS exception, it is transported to the outside. So use try ... catch block to capture it and do alternative operations when it happens. ## Utility functions PL/v8 provides the following utility built-in functions. - `plv8.elog(elevel, msg1[, msg2, ...])` - `plv8.quote_literal(str)` - `plv8.nullable(str)` - `plv8.quote_ident(str)` plv8.elog emits message to the client or the log file. The elevel is one of - `DEBUG5` - `DEBUG4` - `DEBUG3` - `DEBUG2` - `DEBUG1` - `LOG` - `INFO` - `NOTICE` - `WARNING` - `ERROR` See the PostgreSQL manual for each error level. Each functionality for quote family is identical to the built-in SQL function with the same name. In addition, PL/v8 provides a function to access other plv8 functions that have been registered in the database. ```sql CREATE FUNCTION callee(a int) RETURNS int AS $$ return a * a $$ LANGUAGE plv8; CREATE FUNCTION caller(a int, t int) RETURNS int AS $$ var func = plv8.find_function("callee"); return func(a); $$ LANGUAGE plv8; ``` With `plv8.find_function()`, you can look up other plv8 functions. If they are not the plv8 function, it errors out. The function signature parameter to `plv8.find_function()` is either of regproc (function name only) or regprocedure (function name with argument types). You can make use of internal type for arguments and void type for return type for the pure JavaScript function to make sure any invocation from SQL statement should not happen. The plv8 object provides version string as `plv8.version`. This string corresponds to plv8 module version. Note this is not the extension version. ## Window function API You can define user-defined window functions with PL/v8. It wraps C-level window function API to support full functionality. To create one, first obtain window object by `plv8.get_window_object()`, which provides interfaces as follows. ### `WindowObject.get_current_position()` Returns the current position in the partition, starting from 0. ### `WindowObject.get_partition_row_count()` Returns the number of rows in the partition. ### `WindowObject.set_mark_position( pos )` Set mark at the specified row. Rows above this position will be gone and not be accessible later. ### `WindowObject.rows_are_peers( pos1, pos2 )` Returns true if the rows at `pos1` and `pos2` are peers. ### `WindowObject.get_func_arg_in_partition( argno, relpos, seektype, mark_pos )` ### `WindowObject.get_func_arg_in_frame( argno, relpos, seektype, mark_pos )` Returns the value of the argument in `argno` (starting from 0) to this function at the `relpos` row from `seektype` in the current partition or frame. `seektype` can be either of `WindowObject.SEEK_HEAD`, `WindowObject.SEEK_CURRENT`, or `WindowObject.SEEK_TAIL`. If `mark_pos` is true, the row the argument is fetched from is marked. If the specified row is out of the partition/frame, the returned value will be `undefined`. ### `WindowObject.get_func_arg_in_current( argno )` Returns the value of the argument in `argno` (starting from 0) to this function at the current row. Note that the returned value will be the same as the argument variable of the function. ### `WindowObject.get_partition_local( [size] )` Returns partition-local value, which is released at the end of the current partition. If nothing is stored, `undefined` is returned. `size` argument (default 1000) is the byte size of the allocated memory in the first call. Once the memory allocated, the size will not change. ### `WindowObject.set_partition_local( obj )` Stores the partition-local value, which you can retrieve later by `get_partition_local()`. This function internally uses JSON.stringify to serialize the object, so if you pass value that is not able to be serialized may end up being unexpected value. If the size of serialized value is more than the allocated memory, it will throw an exception. You can also learn more on how to use these API in sql/window.sql regression test, which implements most of the native window functions. For the general information of the user-defined window function, see the `CREATE FUNCTION` page of the PostgreSQL manual. ## Typed array The typed array is something v8 provides to allow fast access to native memory, mainly for the purpose of their canvas support in browsers. PL/v8 uses this to map bytea and various array types to JavaScript array. In case of bytea, you can access each byte as an array of unsigned bytes. For `int2`/`int4`/`float4`/`float8` array type, PL/v8 provides direct access to each element by using PL/v8 domain types. - `plv8_int2array` maps `int2[]` - `plv8_int4array` maps `int4[]` - `plv8_float4array` maps `float4[]` - `plv8_float8array` maps `float8[]` These are only annotations that tell PL/v8 to use fast access method instead of regular one. For these typed arrays, only 1-dimensional array without `NULL` element. Also, there is currently no way to create such typed array inside PL/v8 functions. Only arguments can be typed array. You can modify the element and return the value. An example for these types are as follows. ```sql CREATE FUNCTION int4sum(ary plv8_int4array) RETURNS int8 AS $$ var sum = 0; for (var i = 0; i < ary.length; i++) { sum += ary[i]; } return sum; $$ LANGUAGE plv8 IMMUTABLE STRICT; SELECT int4sum(ARRAY[1, 2, 3, 4, 5]); int4sum --------- 15 (1 row) ``` ## ES6 Language Features PL/v8 enables all shipping feature of the used V8 version. So with V8 4.1+ many ES6 features, like block scoping, collections, generators and string templates, are enabled by default. Additional features can be enabled by setting the GUC plv8.v8_flags (e.g. `SET plv8.v8_flags = '--es_staging';`). These flags are honoured once per user session when the V8 runtime is initialized. Compared to dialects (see below), which can be set on a per function base, the V8 flags cannot be changed once the runtime is initialized. So normally this setting should rather be set per database, and not per session. ## Runtime environment separation across users in the same session In PL/v8, each session has one global JS runtime context. This enables function invocations at low cost, and sharing common object among the functions. However, for the security reasons, if the user switches to another with `SET ROLE` command, a new JS runtime context is initialized and used separately. This prevents unexpected information leak risk. Each plv8 function is invoked as if the function is the property of other object. This means `this` in each function is a JS object that is created every time the function is executed in a query. In other words, the life time and the visibility of `this` object in a function is only a series of function calls in a query. If you need to share some value among different functions, keep it in `plv8` object because each function invocation has different `this` object. ## Start-up procedure PL/v8 provides a start up facility, which allows to call initialization plv8 function specified in the `GUC` variable. ```sql SET plv8.start_proc = 'plv8_init'; SELECT plv8_test(10); ``` If this variable is set when the runtime is initialized, before the function call of `plv8_test()` another plv8 function `plv8_init()` is invoked. In such initialization function, you can add any properties to `plv8` object to expose common values or assign them to `this` property. In the initialization function, the receiver `this` is specially pointing to the global object, so the variables that is assigned to `this` property in this initialization are visible from any subsequent function as global variables. Remember `CREATE FUNCTION` also starts the plv8 runtime environment, so make sure to `SET` this `GUC` before any plv8 actions including `CREATE FUNCTION`. ## Update procedure Updating PL/v8 is usually straightforward as it is a small and stable extension - it only contains a handful of objects that need to be added to PostgreSQL when installing the extension. The procedure that is responsible for invoking this installation script (generated during compile time based on `plv8.sql.common`), is controlled by PostgreSQL and runs when `CREATE EXTENSION` is executed only. After building, it takes the form of `plv8--.sql` and is usually located under `/usr/share/postgresql//extension`, depending on the OS. When this command is executed, PostgreSQL tracks which objects belong to the extension and conversely removes them upon uninstallation, i.e., whenever `DROP EXTENSION` is called. You can explore some of the objects that PL/v8 stores under PostgreSQL: ```sql SELECT lanname FROM pg_catalog.pg_language WHERE lanname = 'plv8'; SELECT proname FROM pg_proc p WHERE p.proname LIKE 'plv8%'; SELECT typname FROM pg_catalog.pg_type WHERE typname LIKE 'plv8%'; ``` __When__ and __if__ these objects change, extensions may provide upgrade scripts which contemplate different upgrade paths (e.g. going from 1.5 to 2.0 or from 1.5.0 to 1.5.1). This allows using the special `ALTER EXTENSION UPDATE [ TO ]` syntax instead of having to manually execute `DROP EXTENSION` followed by `CREATE EXTENSION`. This is particularly useful when a large number of user-owned objects depend on the extension, is it would mean dropping all of them and re-creating them after the extension is created again. Currently, PL/v8 does not ship with upgrade scripts as there haven't been updates to these objects since the early builds. This may change in 2.0.0 with the introduction of the `plv8_version` function, which was added as a function object as part of the extension install script. If there are no changes to these objects, there is no need to `DROP EXTENSION` / `CREATE EXTENSION` as PostgreSQL is able to automatically read the new the control file (`plv8.control`) and load the binary into memory (`plv8.so`) as soon as a new connection is established. Don't be fooled by `SELECT pg_available_extensions()` returning the new version as that function actually re-reads the extension directory and returns the version value of the new control file, which may not represent the current PL/v8 version in memory. Also note that running `DROP EXTENSION` / `CREATE EXTENSION` has no effect whatsoever on loading the new PL/v8 version, although new scripts will be picked up. The best way of finding out which PL/v8 version you're running is by executing: ```sql DO $$ plv8.elog(WARNING, plv8.version) $$ LANGUAGE plv8; ``` Even when using PL/v8 2.0.0, `SELECT plv8_version();` is only indicative of the upgrade scripts being ran, as mentioned earlier, not of the current PL/v8 extension version in memory. In conclusion, for now it is safe to simply copy the new control and binary files to the correct paths. This can be either `make install` or by installing a newer package like `postgresql-9.5-plv8`. Then, make sure the new binary is loaded immediately by all users by forcing a server restart (a reload won't suffice) or simply prepare your code to deal with the fact that only newer connections will get access to the PL/v8 version. ## Dialects This module also contains some dialect supports. Currently, we have two dialects are supported. - CoffeeScript (plcoffee) - LiveScript (plls) With PostgreSQL 9.1 or above, you are able to load those dialects via `CREATE EXTENSION` command.