I wanted to drop in google's open location code javascript implementation into PostgreSQL (using the plv8 extension) and make it available to encode/decode from PostGIS geometry/geography data types.
While I was successful, I wasn't able to work out how to only create a single function for the https://github.com/google/open-location-code/blob/master/js/src/openlocationcode.js file and I ended up putting a copy of that function into each function where I needed to encode/decode plus codes. When I attempted to pull it out into its own function, I could either get a string containing javascript or a string of [Object],[object] rather than a callable function.
Is this possible with the plv8 extension in PostgreSQL?
Incomplete code snippet example (full version here):
DROP FUNCTION IF EXISTS olc.encode(float,float,integer);
CREATE OR REPLACE FUNCTION olc.encode(
p_latitude double precision,
p_longitude double precision,
p_code_length integer DEFAULT 10
)
RETURNS text AS
$BODY$
var f = function () {
var OpenLocationCode = {};
/**
* Provides a normal precision code, approximately 14x14 meters.
* @const {number}
*/
OpenLocationCode.CODE_PRECISION_NORMAL = 10;
/**
* Provides an extra precision code, approximately 2x3 meters.
* @const {number}
*/
OpenLocationCode.CODE_PRECISION_EXTRA = 11;
// A separator used to break the code into two parts to aid memorability.
var SEPARATOR_ = '+';
// The number of characters to place before the separator.
var SEPARATOR_POSITION_ = 8;
// The character used to pad codes.
var PADDING_CHARACTER_ = '0';
You have two options.
Store the source code of the function in a special database table and load it using select
and eval()
. Read about details in this answer: Can plv8 JavaScript language extension call 3rd party libraries?
Place the function in an initialization module and set this module using configuration parameter plv8.start_proc
so it is executed automatically on start-up. You can find details in the PL/v8 documentation.
The second option is really handy and does not need an additional table, but may seem a bit tricky. A simple example: we want to have a function square_of_sum(a, b)
predefined in all our plv8 functions. First, create the initialization function:
create or replace function plv8_init()
returns void language plv8 as $$
square_of_sum = function(a, b) {
return (a+ b)* (a+ b)
}
$$;
set the initialization function for the database:
alter database my_database set plv8.start_proc to plv8_init;
and close the current connection.
In all subsequent sessions the function square_of_sum(a, b)
is known in every other plv8 function, e.g.:
create or replace function js_test()
returns int language plv8 as $$
return square_of_sum(3, 2)
$$;
select js_test();
js_test
---------
25
(1 row)