|
| 1 | +--complain if script is sourced in psql, rather than via CREATE EXTENSION |
| 2 | +\echo Use "CREATE EXTENSION supascript CASCADE" to load this file. \quit |
| 3 | + |
| 4 | +/* the alter database line below needs to be run ONCE on your database */ |
| 5 | +SET PLV8.START_PROC = 'supascript_init'; |
| 6 | +ALTER DATABASE POSTGRES SET PLV8.START_PROC TO 'supascript_init'; |
| 7 | + |
| 8 | +CREATE TABLE IF NOT EXISTS supascript_log |
| 9 | +( |
| 10 | + id uuid primary key default uuid_generate_v4(), |
| 11 | + created timestamp with time zone DEFAULT CURRENT_TIMESTAMP, |
| 12 | + _catalog text DEFAULT CURRENT_CATALOG, |
| 13 | + _user text DEFAULT CURRENT_USER, |
| 14 | + _schema text DEFAULT CURRENT_SCHEMA, |
| 15 | + _schemas name[] DEFAULT CURRENT_SCHEMAS(true), |
| 16 | + _pid int DEFAULT PG_BACKEND_PID(), |
| 17 | + log_type text, |
| 18 | + query text, |
| 19 | + content jsonb |
| 20 | +); |
| 21 | + |
| 22 | +CREATE TABLE IF NOT EXISTS supascript_js_modules (module text UNIQUE PRIMARY KEY, |
| 23 | +autoload BOOL DEFAULT FALSE, |
| 24 | +source text); |
| 25 | + |
| 26 | +CREATE OR REPLACE FUNCTION supascript_init() RETURNS VOID |
| 27 | +AS $$ |
| 28 | + |
| 29 | + this.moduleCache = {}; |
| 30 | + |
| 31 | + // this handles "TypeError: Do not know how to serialize a BigInt" |
| 32 | + function toJson(data) { |
| 33 | + if (data !== undefined) { |
| 34 | + return JSON.stringify(data, (_, v) => typeof v === 'bigint' ? `${v}#bigint` : v) |
| 35 | + .replace(/"(-?\d+)#bigint"/g, (_, a) => a); |
| 36 | + } |
| 37 | + } |
| 38 | + |
| 39 | + this.console = { |
| 40 | + timers:{}, |
| 41 | + write_to_log: function() { |
| 42 | + const arr = []; |
| 43 | + for (let i=0; i < arguments.length; i++) { |
| 44 | + if (!(i === 1 && arguments[0] === 'ASSERT')) { |
| 45 | + const arg = JSON.parse(toJson(arguments[i])); // required to handle bigint |
| 46 | + arr.push(arg); |
| 47 | + } |
| 48 | + } |
| 49 | + let query = ''; |
| 50 | + try { |
| 51 | + query = JSON.stringify(sql('select current_query()')[0].current_query); |
| 52 | + if (query.length > 23 && query.substr(0,23).toLowerCase() === '"with pgrst_source as (') { |
| 53 | + query = query.substr(23); |
| 54 | + let index = query.indexOf('AS pgrst_scalar'); |
| 55 | + if (index < 0) { index = 999; }; |
| 56 | + query = query.substr(0,index); |
| 57 | + query = query.replace(new RegExp(String.fromCharCode(92, 92, 34), 'g'), String.fromCharCode(34)); |
| 58 | + } |
| 59 | + } catch (queryParseError) { |
| 60 | + query = 'query parse error'; |
| 61 | + } |
| 62 | + const log_type = arr.shift(); |
| 63 | + sql(`insert into supascript_log (content, log_type, query) values ($1, $2, $3)`,[arr, log_type, query]); |
| 64 | + }, |
| 65 | + log: function() { |
| 66 | + console.write_to_log('LOG', ...arguments); |
| 67 | + }, |
| 68 | + info: function() { |
| 69 | + console.write_to_log('INFO', ...arguments); |
| 70 | + }, |
| 71 | + warn: function() { |
| 72 | + console.write_to_log('WARN', ...arguments); |
| 73 | + }, |
| 74 | + assert: function() { |
| 75 | + if (arguments[0] === false) { |
| 76 | + // arguments.shift(); // remove assert expression |
| 77 | + console.write_to_log('ASSERT', ...arguments); // log rest of arguments (1 to n) |
| 78 | + } |
| 79 | + }, |
| 80 | + error: function() { |
| 81 | + console.write_to_log('ERROR', ...arguments); |
| 82 | + }, |
| 83 | + time: function(label = 'DEFAULT_TIMER') { |
| 84 | + this.timers[label] = +new Date(); |
| 85 | + }, |
| 86 | + timeEnd: function(label = 'DEFAULT_TIMER') { |
| 87 | + console.write_to_log('TIMER',label,+new Date() - this.timers[label]); |
| 88 | + delete this.timers[label]; |
| 89 | + } |
| 90 | + |
| 91 | + }; |
| 92 | + |
| 93 | + |
| 94 | + // execute a Postgresql function |
| 95 | + // i.e. exec('my_function',['parm1', 123, {"item_name": "test json object"}]) |
| 96 | + this.exec = function(function_name, parms) { |
| 97 | + var func = plv8.find_function(function_name); |
| 98 | + return func(...parms); |
| 99 | + } |
| 100 | + |
| 101 | + this.load = function(key, source) { |
| 102 | + var module = {exports: {}}; |
| 103 | + try { |
| 104 | + eval("(function(module, exports) {" + source + "; })")(module, module.exports); |
| 105 | + } catch (err) { |
| 106 | + plv8.elog(ERROR, `eval error in source: ${err} (SOURCE): ${source}`); |
| 107 | + } |
| 108 | + |
| 109 | + // store in cache |
| 110 | + moduleCache[key] = module.exports; |
| 111 | + return module.exports; |
| 112 | + }; |
| 113 | + |
| 114 | + // execute a sql statement against the Postgresql database with optional args |
| 115 | + // i.e. sql('select * from people where first_name = $1 and last_name = $2', ['John', 'Smith']) |
| 116 | + this.sql = function(sql_statement, args) { |
| 117 | + if (args) { |
| 118 | + return plv8.execute(sql_statement, args); |
| 119 | + } else { |
| 120 | + return plv8.execute(sql_statement); |
| 121 | + } |
| 122 | + }; |
| 123 | + |
| 124 | + // emulate node.js "require", with automatic download from the internet via CDN sites |
| 125 | + // optional autoload (boolean) parameter allows the module to be preloaded later |
| 126 | + // i.e. var myModule = require('https://some.cdn.com/module_content.js', true) |
| 127 | + this.require = function(module, autoload) { |
| 128 | + if (module === 'http' || module === 'https') { |
| 129 | + // emulate NodeJS require('http') |
| 130 | + module = 'https://raw.githubusercontent.com/burggraf/SupaScript/main/modules/http.js'; |
| 131 | + } |
| 132 | + if(moduleCache[module]) |
| 133 | + return moduleCache[module]; |
| 134 | + var rows = plv8.execute( |
| 135 | + 'select source from supascript_js_modules where module = $1', |
| 136 | + [module] |
| 137 | + ); |
| 138 | + |
| 139 | + if (rows.length === 0 && module.substr(0,4) === 'http') { |
| 140 | + try { |
| 141 | + source = plv8.execute(`SELECT content FROM http_get('${module}');`)[0].content; |
| 142 | + } catch (err) { |
| 143 | + plv8.elog(ERROR, `Could not load module through http: ${module}`, JSON.stringify(err)); |
| 144 | + } |
| 145 | + try { |
| 146 | + /* the line below is written purely for esthetic reasons, so as not to mess up the online source editor */ |
| 147 | + /* when using standard regExp expressions, the single-quote char messes up the code highlighting */ |
| 148 | + /* in the editor and everything looks funky */ |
| 149 | + const quotedSource = source.replace(new RegExp(String.fromCharCode(39), 'g'), String.fromCharCode(39, 39)); |
| 150 | + |
| 151 | + plv8.execute(`insert into supascript_js_modules (module, autoload, source) values ('${module}', ${autoload ? true : false}, '${quotedSource}')`); |
| 152 | + } catch (err) { |
| 153 | + plv8.elog(ERROR, `Error inserting module into supascript_js_modules: ${err} ${module}, ${autoload ? true : false}, '${plv8.quote_literal(source)}'`); |
| 154 | + } |
| 155 | + return load(module, source); |
| 156 | + } else if(rows.length === 0) { |
| 157 | + plv8.elog(NOTICE, `Could not load module: ${module}`); |
| 158 | + return null; |
| 159 | + } else { |
| 160 | + return load(module, rows[0].source); |
| 161 | + } |
| 162 | + |
| 163 | + }; |
| 164 | + |
| 165 | + // Grab modules worth auto-loading at context start and let them cache |
| 166 | + var query = `select module, source from supascript_js_modules where autoload = true`; |
| 167 | + plv8.execute(query).forEach(function(row) { |
| 168 | + this.load(row.module, row.source); |
| 169 | + }); |
| 170 | +$$ LANGUAGE PLV8; |
| 171 | +ALTER TABLE supascript_log ENABLE ROW LEVEL SECURITY; |
| 172 | +ALTER TABLE supascript_js_modules ENABLE ROW LEVEL SECURITY; |
| 173 | +ALTER PUBLICATION supabase_realtime ADD TABLE supascript_log; |
| 174 | + |
| 175 | + |
0 commit comments