├── .gitignore ├── fb ├── bad-data.sql ├── data.sql └── schema.sql ├── LICENSE ├── demo.sql ├── README.md └── graphql.sql /.gitignore: -------------------------------------------------------------------------------- 1 | .DS_Store 2 | abuja* 3 | pg_data 4 | -------------------------------------------------------------------------------- /fb/bad-data.sql: -------------------------------------------------------------------------------- 1 | --- Should error out. 2 | INSERT INTO friendship (first, second) VALUES 3 | ('f3411edc-e1d0-452a-bc19-b42c0d5a0e36', 4 | '606fa027-a577-4018-952e-3c8469372829'); 5 | -------------------------------------------------------------------------------- /fb/data.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | INSERT INTO "user" (id, full_name) VALUES 4 | ('606fa027-a577-4018-952e-3c8469372829', 'Curly'), 5 | ('f3411edc-e1d0-452a-bc19-b42c0d5a0e36', 'Larry'), 6 | ('05ed1b59-090e-40af-8f0e-68a1129b55b4', 'Mo'); 7 | 8 | --- Should succeed because friendships are symmetrical. 9 | INSERT INTO friendship (first, second) VALUES 10 | ('f3411edc-e1d0-452a-bc19-b42c0d5a0e36', 11 | '05ed1b59-090e-40af-8f0e-68a1129b55b4'), 12 | ('05ed1b59-090e-40af-8f0e-68a1129b55b4', 13 | 'f3411edc-e1d0-452a-bc19-b42c0d5a0e36'); 14 | 15 | END; 16 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Let this software be licensed under the PostgreSQL license. 2 | 3 | Copyright (c) 2015, Jason Dusek (jason.dusek@gmail.com), hereafter "AUTHOR" 4 | 5 | Permission to use, copy, modify, and distribute this software and its 6 | documentation for any purpose, without fee, and without a written agreement is 7 | hereby granted, provided that the above copyright notice and this paragraph and 8 | the following two paragraphs appear in all copies. 9 | 10 | IN NO EVENT SHALL AUTHOR BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, 11 | INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF 12 | THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF AUTHOR HAS BEEN ADVISED 13 | OF THE POSSIBILITY OF SUCH DAMAGE. 14 | 15 | AUTHOR SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, 16 | THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. 17 | THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND AUTHOR HAS NO 18 | OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR 19 | MODIFICATIONS. 20 | -------------------------------------------------------------------------------- /demo.sql: -------------------------------------------------------------------------------- 1 | \set QUIET true 2 | \set ON_ERROR_ROLLBACK 1 3 | \set ON_ERROR_STOP true 4 | 5 | \include_relative graphql.sql 6 | \include_relative fb/schema.sql 7 | \include_relative fb/data.sql 8 | 9 | \x auto 10 | 11 | \C Users: 12 | SELECT * FROM "user"; 13 | 14 | \C Friendships: 15 | SELECT friendship.*, l._||' -> '||r._ AS who FROM friendship, 16 | LATERAL (SELECT full_name FROM "user" WHERE first = id) AS l(_), 17 | LATERAL (SELECT full_name FROM "user" WHERE second = id) AS r(_); 18 | 19 | --- Remove the table label. 20 | \C 21 | 22 | DO $$ 23 | DECLARE 24 | graphql_q text = E'user("f3411edc-e1d0-452a-bc19-b42c0d5a0e36") {\n' 25 | ' full_name,\n' 26 | ' friendship\n' 27 | '}'; 28 | --graphql_q text = E'user("f3411edc-e1d0-452a-bc19-b42c0d5a0e36") {\n' 29 | -- ' full_name,\n' 30 | -- ' friendship { full_name }\n' 31 | -- '}'; 32 | sql_q text; 33 | result json; 34 | msg text; 35 | BEGIN 36 | RAISE INFO E'GraphQL to parse:\n%\n', graphql_q; 37 | SELECT * INTO STRICT sql_q FROM graphql.to_sql(graphql_q); 38 | RAISE INFO E'SQL that will be run:\n%\n', sql_q; 39 | result := graphql.run(graphql_q); 40 | RAISE INFO E'Result:\n%\n', result; 41 | END 42 | $$; 43 | 44 | BEGIN; 45 | SET LOCAL client_min_messages TO ERROR; 46 | DROP SCHEMA graphql CASCADE; 47 | DROP SCHEMA fb CASCADE; 48 | END; 49 | -------------------------------------------------------------------------------- /fb/schema.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | DROP SCHEMA IF EXISTS fb CASCADE; 4 | CREATE SCHEMA fb; 5 | SET search_path TO fb,"$user",public; 6 | CREATE EXTENSION "uuid-ossp"; 7 | 8 | 9 | CREATE TABLE "user" ( 10 | id uuid PRIMARY KEY DEFAULT uuid_generate_v4(), 11 | created timestamptz NOT NULL DEFAULT now(), 12 | full_name text NOT NULL DEFAULT '' 13 | ); 14 | 15 | 16 | CREATE TABLE post ( 17 | id uuid PRIMARY KEY DEFAULT uuid_generate_v4(), 18 | created timestamptz NOT NULL DEFAULT now(), 19 | content text NOT NULL DEFAULT '', 20 | "user" uuid REFERENCES "user" NOT NULL 21 | ); 22 | 23 | 24 | CREATE TABLE friendship ( 25 | first uuid REFERENCES "user" NOT NULL, 26 | second uuid REFERENCES "user" NOT NULL, 27 | created timestamptz NOT NULL DEFAULT now(), 28 | UNIQUE (first, second) 29 | ); 30 | 31 | CREATE FUNCTION check_friendship_symmetry() RETURNS TRIGGER AS $$ 32 | DECLARE 33 | link friendship; 34 | BEGIN 35 | SELECT * INTO link FROM friendship 36 | WHERE second = NEW.first AND first = NEW.second; 37 | IF NOT FOUND THEN 38 | RAISE EXCEPTION 'Friendships must be INSERTed as pairs.'; 39 | END IF; 40 | RETURN NEW; 41 | END 42 | $$ LANGUAGE plpgsql 43 | SET search_path FROM CURRENT; 44 | 45 | CREATE CONSTRAINT TRIGGER friendship_symmetry 46 | AFTER INSERT ON friendship 47 | DEFERRABLE INITIALLY DEFERRED 48 | FOR EACH ROW 49 | EXECUTE PROCEDURE check_friendship_symmetry(); 50 | 51 | END; 52 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # GraphQL + PostGIS 2 | 3 | Experiment with GraphQL, PostGIS, and OSM data 4 | 5 | Very much based on Jason Dusek's Graphpostgresql 6 | 7 | ## Install Prerequisites 8 | 9 | Install PostGIS and Osm2pgsql. On my machine, I had to install osm2pgsql with 10 | a special parameter to include protocol buffers. 11 | 12 | Download an OSM PBF file (find some at Metro Extracts) 13 | 14 | ## Set up Database 15 | 16 | Import an OSM PBF extract file into PostGIS database named "osm": 17 | 18 | ```bash 19 | initdb pg_data 20 | postgres -D pg_data & 21 | createdb osm 22 | psql -d osm -c "CREATE EXTENSION postgis;" 23 | psql -d osm -c "CREATE EXTENSION postgis_topology;" 24 | osm2pgsql -s -d osm import.osm.pbf 25 | ``` 26 | 27 | You need to have primary keys in your data to use GraphQL. OSM2PGSQL doesn't do this automatically, because 28 | a few items will have repeated invalid, negative osm_ids. Remove them before setting the primary key. 29 | 30 | ```bash 31 | psql -d osm 32 | DELETE FROM planet_osm_point WHERE osm_id < 0; 33 | ALTER TABLE planet_osm_point ADD PRIMARY KEY (osm_id); 34 | DELETE FROM planet_osm_line WHERE osm_id < 0; 35 | ALTER TABLE planet_osm_line ADD PRIMARY KEY (osm_id); 36 | DELETE FROM planet_osm_polygon WHERE osm_id < 0; 37 | ALTER TABLE planet_osm_polygon ADD PRIMARY KEY (osm_id); 38 | DELETE FROM planet_osm_roads WHERE osm_id < 0; 39 | ALTER TABLE planet_osm_roads ADD PRIMARY KEY (osm_id); 40 | ``` 41 | 42 | Load the graphql schema file: 43 | 44 | ```bash 45 | psql -d osm -c "\i graphql.sql" 46 | ``` 47 | 48 | ## Make queries 49 | 50 | Here's a sample query looking up the id of all points: 51 | 52 | ```sql 53 | SELECT graphql.run($$ 54 | planet_osm_point { id } 55 | $$); 56 | ``` 57 | 58 | Now to show the usefulness of GraphQL: 59 | 60 | When the user clicks on a restaurant and I know the OSM id is 560983277, then I can query the database 61 | for the tags which are relevant to a restaurant in OSM data: 62 | 63 | ```sql 64 | SELECT graphql.run($$ 65 | planet_osm_point("560983277") { 66 | amenity, 67 | cuisine, 68 | internet_access, 69 | website, 70 | opening_hours 71 | } 72 | $$); 73 | ``` 74 | 75 | If your OSM data extract didn't have some of these tags, it might not have the columns and fail. Just 76 | remove them from the query! 77 | 78 | Thanks to PostGIS, you should be able to return the GeoJSON of a field: 79 | 80 | ```sql 81 | SELECT graphql.run($$ 82 | planet_osm_point("560983277") { 83 | name, 84 | ST_AsGeoJSON(way) 85 | } 86 | $$); 87 | ``` 88 | 89 | This returns one JSON record, with the name, and the GeoJSON escaped in the "st_asgeojson" field: 90 | 91 | ``` 92 | {"name":"Bukkateen","st_asgeojson":"{\"type\":\"Point\",\"coordinates\":[831049.01,1010592.89]}"} 93 | ``` 94 | 95 | Most PostGIS functions with two arguments are accepted in the modified GraphQL set. 96 | 97 | Not all of them make sense in the current state - this ST_Buffer query returns PostGIS geometry and not GeoJSON: 98 | 99 | ```sql 100 | SELECT graphql.run($$ 101 | planet_osm_polygon("213537579") { 102 | operator, 103 | ST_Buffer(way, 10.11) 104 | } 105 | $$); 106 | ``` 107 | 108 | If you are using non-OSM PostGIS data, you could compare multiple fields in this record, for example you could 109 | return a calculated distance: 110 | 111 | ```sql 112 | SELECT graphql.run($$ 113 | geos("geo_id") { 114 | field, 115 | ST_Distance(startpt, endpt) 116 | } 117 | $$); 118 | ``` 119 | 120 | I'm trying to get this example working, but the parser is concerned about POLYGON(()) 121 | 122 | ```sql 123 | SELECT graphql.run($$ 124 | planet_osm_polygon("213537579") { 125 | operator, 126 | ST_Within(way, ST_GeomFromText('POLYGON((806850.5 1004992.93, 809346.74 1006557.97, 807892.59 1005245.2, 806850.5 1004992.93))')) 127 | } 128 | $$); 129 | ``` 130 | 131 | ## Debug queries 132 | 133 | For any query, use to_sql to see the SQL which you would be running: 134 | 135 | ```sql 136 | SELECT graphql.to_sql($$ 137 | planet_osm_point { 138 | name, 139 | amenity 140 | } 141 | $$); 142 | ``` 143 | 144 | Responds with: 145 | 146 | ```sql 147 | to_sql | SELECT json_agg("sub/1") AS planet_osm_point 148 | | FROM planet_osm_point, 149 | | LATERAL ( 150 | | SELECT planet_osm_point.id 151 | | ) AS "sub/1" 152 | ``` 153 | 154 | ## License 155 | 156 | GraphpostgresQL and this repo use the open source PostgresQL license. 157 | -------------------------------------------------------------------------------- /graphql.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | DROP SCHEMA IF EXISTS graphql CASCADE; 4 | CREATE SCHEMA graphql; 5 | 6 | /* * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * // 7 | 8 | # Syntax 9 | 10 | The form of a GraphQL query is either a simple selector or a selector with 11 | nested selectors or GraphQL queries. 12 | 13 | = 14 | | { * } 15 | 16 | Selectors are of three kinds: 17 | 18 | * "table selectors" that specify a datatype or collection and an ID. For 19 | example: `user('606fa027-a577-4018-952e-3c8469372829')`. More formally, the 20 | syntax of a table selector is: 21 | 22 | = '(' ')' 23 | 24 | Maybe someday, we'll extend the `` portion to encompass predicates, to 25 | allow for queries like: 26 | 27 | user(created <= '2011-10-01') 28 | 29 | * "column selectors" that specify a field name. Like: `full_name`. 30 | 31 | * A "curious blend" of field and table selectors that perform JOINs, in a 32 | (hopefully) intuitive way. For example: 33 | 34 | user('606fa027-a577-4018-952e-3c8469372829') { 35 | friendship { // Uses the friendship table to find users 36 | id, 37 | full_name 38 | } 39 | post { // Uses the post table to find posts 40 | title 41 | } 42 | } 43 | 44 | # Semantics 45 | 46 | At the root of the query, there must be a table selector. Sub-queries are 47 | taken relative to the super query. 48 | 49 | Queries over collections (tables) are implicitly array-valued. 50 | 51 | Nested selection is allowed for columns of JSON type, HStore type and of row 52 | type. 53 | 54 | 55 | // * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * */ 56 | 57 | 58 | SET LOCAL search_path TO graphql; -- Ensure defs are created in this schema 59 | --- However, we still qualify references between functions -- as when `to_sql` 60 | --- calls `parse_many` -- because the search_path will be different when the 61 | --- code is run by the application/user. 62 | 63 | 64 | /* * * * * * * * * * * * * Table inspection utilities * * * * * * * * * * * */ 65 | /* These are up here because the types defined by the VIEWs are used further 66 | * down. 67 | */ 68 | 69 | CREATE VIEW pk AS 70 | SELECT attrelid::regclass AS tab, 71 | array_agg(attname)::name[] AS cols 72 | FROM pg_attribute 73 | JOIN pg_index ON (attrelid = indrelid AND attnum = ANY (indkey)) 74 | WHERE indisprimary 75 | GROUP BY attrelid; 76 | 77 | CREATE VIEW cols AS 78 | SELECT attrelid::regclass AS tab, 79 | attname::name AS col, 80 | atttypid::regtype AS typ, 81 | attnum AS num 82 | FROM pg_attribute 83 | WHERE attnum > 0 84 | ORDER BY attrelid, attnum; 85 | 86 | CREATE VIEW fk AS 87 | SELECT conrelid::regclass AS tab, 88 | names.cols, 89 | confrelid::regclass AS other, 90 | names.refs 91 | FROM pg_constraint, 92 | LATERAL (SELECT array_agg(cols.attname) AS cols, 93 | array_agg(cols.attnum) AS nums, 94 | array_agg(refs.attname) AS refs 95 | FROM unnest(conkey, confkey) AS _(col, ref), 96 | LATERAL (SELECT * FROM pg_attribute 97 | WHERE attrelid = conrelid AND attnum = col) 98 | AS cols, 99 | LATERAL (SELECT * FROM pg_attribute 100 | WHERE attrelid = confrelid AND attnum = ref) 101 | AS refs) 102 | AS names 103 | WHERE confrelid != 0 104 | ORDER BY (conrelid, names.nums); -- Returned in column index order 105 | 106 | CREATE FUNCTION ns(tab regclass) RETURNS name AS $$ 107 | SELECT nspname 108 | FROM pg_class JOIN pg_namespace ON (pg_namespace.oid = relnamespace) 109 | WHERE pg_class.oid = tab 110 | $$ LANGUAGE sql STABLE STRICT; 111 | 112 | CREATE FUNCTION pk(t regclass) RETURNS name[] AS $$ 113 | SELECT cols FROM graphql.pk WHERE graphql.pk.tab = t; 114 | $$ LANGUAGE sql STABLE STRICT; 115 | 116 | CREATE FUNCTION cols(t regclass) 117 | RETURNS TABLE (num smallint, col name, typ regtype) AS $$ 118 | SELECT num, col, typ FROM graphql.cols WHERE graphql.cols.tab = t; 119 | $$ LANGUAGE sql STABLE STRICT; 120 | 121 | CREATE FUNCTION fk(t regclass) 122 | RETURNS TABLE (cols name[], other regclass, refs name[]) AS $$ 123 | SELECT cols, other, refs FROM graphql.fk WHERE graphql.fk.tab = t; 124 | $$ LANGUAGE sql STABLE STRICT; 125 | 126 | 127 | /* * * * * * * * * * * * * * * Begin main program * * * * * * * * * * * * * */ 128 | 129 | CREATE FUNCTION run(expr text) 130 | RETURNS json AS $$ 131 | DECLARE 132 | intermediate json; 133 | result json[] = ARRAY[]::json[]; 134 | n integer = 0; 135 | q text; 136 | BEGIN 137 | FOR q IN SELECT graphql.to_sql(expr) LOOP 138 | n := n + 1; 139 | BEGIN 140 | EXECUTE q INTO STRICT intermediate; 141 | EXCEPTION 142 | WHEN NO_DATA_FOUND THEN CONTINUE; 143 | END; 144 | result := result || intermediate; 145 | END LOOP; 146 | --- Maybe there is a better way to approach query cardinality? For example, 147 | --- by insisting that there be a root query (perhaps with no predicate?) or 148 | --- returning TABLE (result json). 149 | IF n = 1 THEN 150 | RETURN result[1]; 151 | ELSE 152 | RETURN to_json(result); 153 | END IF; 154 | END 155 | $$ LANGUAGE plpgsql STABLE STRICT; 156 | 157 | CREATE FUNCTION to_sql(expr text) 158 | RETURNS TABLE (query text) AS $$ 159 | BEGIN 160 | RETURN QUERY SELECT graphql.to_sql(selector, predicate, body) 161 | FROM graphql.parse_many(expr); 162 | END 163 | $$ LANGUAGE plpgsql STABLE STRICT; 164 | 165 | --- Base case (and entry point): looking up a row from a table. 166 | CREATE FUNCTION to_sql(selector regclass, 167 | predicate text, 168 | body text, 169 | label name DEFAULT NULL) 170 | RETURNS text AS $$ 171 | DECLARE 172 | q text = ''; 173 | tab regclass = selector; -- For clarity 174 | cols text[] = ARRAY[]::text[]; 175 | col name; 176 | sub record; 177 | pk text[] = NULL; 178 | fks graphql.fk[]; 179 | subselects text[] = ARRAY[]::text[]; 180 | predicates text[] = ARRAY[]::text[]; 181 | BEGIN 182 | body := btrim(body, '{}'); 183 | IF predicate IS NOT NULL THEN 184 | SELECT array_agg(_) INTO STRICT pk 185 | FROM jsonb_array_elements_text(jsonb('['||predicate||']')) AS __(_); 186 | predicates := predicates 187 | || graphql.format_comparison(tab, graphql.pk(tab), pk); 188 | END IF; 189 | FOR sub IN SELECT * FROM graphql.parse_many(body) LOOP 190 | IF sub.predicate IS NOT NULL THEN 191 | IF sub.selector NOT IN ('ST_AsGeoJSON', 'ST_Buffer', 'ST_Distance', 'ST_Equals', 'ST_Disjoint', 'ST_Intersects', 'ST_Touches', 'ST_Crosses', 'ST_Within', 'ST_Overlaps', 'ST_Contains', 'ST_Covers', 'ST_CoveredBy', 'ST_Intersects', 'ST_Centroid', 'ST_Area', 'ST_Length', 'ST_PointOnSurface', 'ST_ConvexHull', 'ST_Intersection', 'ST_Shift_Longitude', 'ST_SymDifference', 'ST_Difference', 'ST_Union', 'ST_AsText', 'ST_AsBinary', 'ST_SRID', 'ST_Dimension', 'ST_Envelope', 'ST_IsEmpty', 'ST_IsSimple', 'ST_IsClosed', 'ST_IsRing', 'ST_NumGeometries', 'ST_GeometryN', 'ST_NumPoints', 'ST_ExteriorRing', 'ST_NumInteriorRings', 'ST_NumInteriorRing', 'ST_InteriorRingN', 'ST_EndPoint', 'ST_StartPoint', 'GeometryType', 'ST_Geometry_Type', 'ST_X', 'ST_Y', 'ST_Z', 'ST_M') THEN 192 | RAISE EXCEPTION 'Unhandled nested selector %(%)', 193 | sub.selector, sub.predicate; 194 | ELSE 195 | sub.modifier = sub.selector; 196 | sub.selector = split_part(sub.predicate, ',', 1); 197 | END IF; 198 | END IF; 199 | SELECT cols.col INTO col 200 | FROM graphql.cols(tab) WHERE cols.col = sub.selector; 201 | CASE 202 | WHEN FOUND AND sub.body IS NULL THEN -- A simple column reference 203 | SELECT array_agg(fk) INTO STRICT fks 204 | FROM graphql.fk(tab) 205 | WHERE cardinality(fk.cols) = 1 AND fk.cols[1] = col; 206 | IF cardinality(fks) > 0 THEN 207 | IF cardinality(fks) > 1 THEN 208 | RAISE EXCEPTION 'More than one candidate foreign keys for %(%)', 209 | tab, col; 210 | END IF; 211 | subselects := subselects 212 | || format(E'SELECT to_json(%1$s) AS %4$I FROM %1$s\n' 213 | ' WHERE %1$s.%2$I = %3$s.%4$I', 214 | fks[1].other, fks[1].refs[1], tab, col); 215 | cols := cols || format('%I.%I', 'sub/'||cardinality(subselects), col); 216 | ELSE 217 | IF sub.modifier IS NULL THEN 218 | cols := cols || format('%s.%I', tab, col); 219 | ELSE 220 | IF split_part(sub.predicate, ',', 2) != '' THEN 221 | cols := cols || format('%s(%s.%I, %s)', sub.modifier, tab, col, SUBSTR(sub.predicate, 2 + CHAR_LENGTH(sub.selector))); 222 | ELSE 223 | cols := cols || format('%s(%s.%I)', sub.modifier, tab, col); 224 | END IF; 225 | END IF; 226 | END IF; 227 | WHEN FOUND AND sub.body IS NOT NULL THEN -- Index into a column 228 | subselects := subselects || graphql.to_sql(sub.selector, 229 | sub.predicate, 230 | sub.body, 231 | tab); 232 | cols := cols || format('%I.%I', 'sub/'||cardinality(subselects), col); 233 | WHEN NOT FOUND THEN -- It might be a reference to another table 234 | subselects := subselects || graphql.to_sql(regclass(sub.selector), 235 | sub.predicate, 236 | sub.body, 237 | tab, 238 | pk); 239 | cols := cols 240 | || format('%I.%I', 'sub/'||cardinality(subselects), sub.selector); 241 | ELSE 242 | RAISE EXCEPTION 'Not able to interpret this selector: %', sub.selector; 243 | END CASE; 244 | END LOOP; 245 | DECLARE 246 | column_expression text; 247 | BEGIN 248 | IF cols > ARRAY[]::text[] THEN 249 | --- We want a temporary record type to to pass to json_agg or to_json as 250 | --- a single parameter so that column names are preserved. So we select 251 | --- all the columns into a subselect with LATERAL and then reference the 252 | --- subselect. This subselect should always be the last one in the 253 | --- sequence, since it needs to reference "columns" created in the other 254 | --- subselects. 255 | subselects := subselects 256 | || format('SELECT %s', array_to_string(cols, ', ')); 257 | column_expression := format('%I', 'sub/'||cardinality(subselects)); 258 | ELSE 259 | column_expression := format('%s', tab); 260 | END IF; 261 | IF pk IS NOT NULL THEN -- Implies single result 262 | q := 'SELECT to_json(' || column_expression || ')' || q; 263 | ELSE 264 | q := 'SELECT json_agg(' || column_expression || ')' || q; 265 | END IF; 266 | IF label IS NOT NULL THEN 267 | q := q || format(' AS %I', label); 268 | ELSE 269 | q := q || format(' AS %s', tab); 270 | END IF; 271 | END; 272 | q := q || format(E'\n FROM %s', tab); 273 | FOR i IN 1..cardinality(subselects) LOOP 274 | q := q || array_to_string(ARRAY[ 275 | ',', 276 | graphql.indent(7, 'LATERAL ('), -- 7 to line up with SELECT ... 277 | graphql.indent(9, subselects[i]), -- 9 to be 2 under LATERAL 278 | graphql.indent(7, ') AS ' || format('%I', 'sub/'||i)) 279 | ], E'\n'); 280 | --- TODO: Find an "indented text" abstraction so we don't split and 281 | --- recombine the same lines so many times. 282 | END LOOP; 283 | FOR i IN 1..cardinality(predicates) LOOP 284 | IF i = 1 THEN 285 | q := q || E'\n WHERE (' || predicates[i] || ')'; 286 | ELSE 287 | q := q || E'\n AND (' || predicates[i] || ')'; 288 | END IF; 289 | END LOOP; 290 | RETURN q; 291 | END 292 | $$ LANGUAGE plpgsql STABLE; 293 | 294 | --- Handling fancy columns: json, jsonb and hstore 295 | CREATE FUNCTION to_sql(selector text, predicate text, body text, tab regclass) 296 | RETURNS text AS $$ 297 | DECLARE 298 | q text = ''; 299 | col name; 300 | typ regtype; 301 | sub record; 302 | lookups text[] = ARRAY[]::text[]; 303 | labels text[] = ARRAY[]::text[]; 304 | BEGIN 305 | SELECT cols.col, cols.typ INTO col, typ 306 | FROM graphql.cols(tab) WHERE cols.col = selector; 307 | IF NOT FOUND THEN 308 | RAISE EXCEPTION 'Did not find column % on table %', col, tab; 309 | END IF; 310 | FOR sub IN SELECT * FROM graphql.parse_many(body) LOOP 311 | IF sub.predicate IS NOT NULL THEN 312 | RAISE EXCEPTION 'Not able to handle predicates when following lookups ' 313 | 'into columns (for field % under %.%)', 314 | sub.selector, tab, col; 315 | END IF; 316 | CASE typ 317 | WHEN regtype('jsonb'), regtype('json') THEN 318 | IF sub.body IS NOT NULL THEN -- TODO: Nested JSON lookups 319 | RAISE EXCEPTION 'Nested JSON lookup is as yet unimplemented'; 320 | END IF; 321 | lookups := lookups || format('%I->%L', selector, sub.selector); 322 | WHEN regtype('hstore') THEN 323 | IF sub.body IS NOT NULL THEN 324 | RAISE EXCEPTION 'No fields below this level (column % is hstore)', 325 | tab, col; 326 | END IF; 327 | lookups := lookups || format('%I->%L', selector, sub.selector); 328 | ELSE 329 | --- Treat it as a field lookup in a nested record (this could also end up 330 | --- being a function call, by the way). 331 | lookups := lookups || format('%I.%I', selector, sub.selector); 332 | END CASE; 333 | labels := labels || format('%I', sub.selector); 334 | END LOOP; 335 | q := format(E'SELECT to_json(_) AS %I\n' 336 | ' FROM (VALUES (%s)) AS _(%s)', 337 | col, 338 | array_to_string(lookups, ', '), 339 | array_to_string(labels, ', ')); 340 | RETURN q; 341 | END 342 | $$ LANGUAGE plpgsql STABLE; 343 | 344 | --- For tables with foreign keys that point at the target table. Mutually 345 | --- recursive with the base case. 346 | CREATE FUNCTION to_sql(selector regclass, 347 | predicate text, 348 | body text, 349 | tab regclass, 350 | keys text[]) 351 | RETURNS text AS $$ 352 | DECLARE 353 | q text = ''; 354 | txts text[]; 355 | ikey record; -- Key which REFERENCEs `tab` from `selector` 356 | --- If `selector` is a JOIN table, then `okey` is used to store a REFERENCE 357 | --- to the table with the actual data. 358 | okey record; 359 | BEGIN 360 | BEGIN 361 | SELECT * INTO STRICT ikey -- Find the first foreign key in column order 362 | FROM graphql.fk(selector) WHERE fk.other = tab LIMIT 1; 363 | EXCEPTION 364 | WHEN NO_DATA_FOUND THEN 365 | RAISE EXCEPTION 'No REFERENCE to table % from table %', tab, selector; 366 | END; 367 | PERFORM * FROM graphql.cols(selector) 368 | WHERE cols.col NOT IN (SELECT unnest(cols) FROM graphql.fk(selector)) 369 | AND cols.typ NOT IN (regtype('timestamp'), regtype('timestamptz')); 370 | --- If: 371 | --- * Thare are two and only two foreign keys for the other table, and 372 | --- * All the columns of the table participate in one or the other 373 | --- foreign key, or are timestamps, then 374 | --- * We can treat the table as a JOIN table and follow the keys. 375 | --- Otherwise: 376 | --- * We use the existence of the foreign key to look up the record in 377 | --- the table that JOINs with us. 378 | IF NOT FOUND AND (SELECT count(1) FROM graphql.fk(selector)) = 2 THEN 379 | SELECT * INTO STRICT okey FROM graphql.fk(selector) WHERE fk != ikey; 380 | q := graphql.to_sql(okey.other, NULL, body, name(selector)); 381 | --- Split at the first LATERAL and put the JOIN behind it, if there is a 382 | --- LATERAL. 383 | SELECT regexp_matches(q, '^(.+)(,[ \n\t]+LATERAL)(.+)$') INTO txts; 384 | IF FOUND THEN 385 | q := txts[1] 386 | || E'\n ' 387 | || graphql.format_join(okey.other, okey.refs, selector, okey.cols) 388 | || txts[2] 389 | || txts[3]; 390 | ELSE 391 | q := q 392 | || E'\n ' 393 | || graphql.format_join(okey.other, okey.refs, selector, okey.cols); 394 | END IF; 395 | ELSE 396 | q := graphql.to_sql(selector, NULL, body, name(selector)); 397 | END IF; 398 | q := q || E'\n WHERE ' 399 | || graphql.format_comparison(selector, ikey.cols, keys); 400 | RETURN q; 401 | END 402 | $$ LANGUAGE plpgsql STABLE; 403 | 404 | CREATE FUNCTION parse_many(expr text) 405 | RETURNS TABLE (selector text, predicate text, modifier text, body text) AS $$ 406 | DECLARE 407 | whitespace_and_commas text = E'^[ \t\n,]*'; 408 | BEGIN 409 | --- To parse many expressions: 410 | --- * Parse one expression. 411 | --- * Consume whitespace. 412 | --- * Consume a comma if present. 413 | --- * Consume whitespace. 414 | --- * Repeat until the input is empty. 415 | expr := regexp_replace(expr, whitespace_and_commas, ''); 416 | WHILE expr != '' LOOP 417 | SELECT * FROM graphql.parse_one(expr) INTO selector, predicate, body, expr; 418 | RETURN NEXT; 419 | expr := regexp_replace(expr, whitespace_and_commas, ''); 420 | END LOOP; 421 | END 422 | $$ LANGUAGE plpgsql IMMUTABLE STRICT; 423 | 424 | CREATE FUNCTION parse_one(expr text, 425 | OUT selector text, 426 | OUT predicate text, 427 | OUT body text, 428 | OUT remainder text) AS $$ 429 | DECLARE 430 | label text = '[a-zA-Z_][a-zA-Z0-9_]*'; 431 | selector_re text = '^(' || label || ')' || '([(]([^()]+)[)])?'; 432 | matches text[]; 433 | whitespace text = E' \t\n'; 434 | idx integer = 0; 435 | nesting integer = 0; 436 | brackety boolean = FALSE; 437 | c text; 438 | BEGIN 439 | --- To parse one expression: 440 | --- * Consume whitespace. 441 | --- * Find a selector. 442 | --- * Consume whitespace. 443 | --- * Find a left bracket or stop. 444 | --- * If there is a left bracket, balance brackets. 445 | --- * If there is something else, return. 446 | expr := ltrim(expr, whitespace); 447 | matches := regexp_matches(expr, selector_re); 448 | selector := matches[1]; 449 | predicate := matches[3]; 450 | IF selector IS NULL THEN 451 | RAISE EXCEPTION 'No selector (in "%")', 452 | graphql.excerpt(expr, 1, 50); 453 | END IF; 454 | expr := ltrim(regexp_replace(expr, selector_re, ''), whitespace); 455 | FOREACH c IN ARRAY string_to_array(expr, NULL) LOOP 456 | idx := idx + 1; 457 | CASE 458 | WHEN c = '{' THEN 459 | nesting := nesting + 1; 460 | brackety := TRUE; 461 | WHEN c = '}' AND brackety THEN 462 | nesting := nesting - 1; 463 | EXIT WHEN nesting = 0; 464 | WHEN nesting < 0 THEN 465 | RAISE EXCEPTION 'Brace nesting error (in "%")', 466 | graphql.excerpt(expr, idx, 50); 467 | ELSE 468 | EXIT WHEN NOT brackety; 469 | END CASE; 470 | END LOOP; 471 | IF brackety THEN 472 | body := substr(expr, 1, idx); 473 | END IF; 474 | remainder := substr(expr, idx+1); 475 | END 476 | $$ LANGUAGE plpgsql IMMUTABLE STRICT; 477 | 478 | 479 | /* * * * * * * * * * * * * * * * Text utilities * * * * * * * * * * * * * * */ 480 | 481 | CREATE FUNCTION excerpt(str text, start integer, length integer) 482 | RETURNS text AS $$ 483 | SELECT substr(regexp_replace(str, '[ \n\t]+', ' ', 'g'), start, length); 484 | $$ LANGUAGE sql IMMUTABLE STRICT; 485 | 486 | CREATE FUNCTION indent(level integer, str text) 487 | RETURNS text AS $$ 488 | SELECT array_to_string(array_agg(s), E'\n') 489 | FROM unnest(string_to_array(str, E'\n')) AS _(ln), 490 | LATERAL (SELECT repeat(' ', level)) 491 | AS spacer(spacer), 492 | LATERAL (SELECT CASE ln WHEN '' THEN ln ELSE spacer || ln END) 493 | AS indented(s) 494 | $$ LANGUAGE sql IMMUTABLE STRICT; 495 | 496 | CREATE FUNCTION format_comparison(x regclass, xs name[], y regclass, ys name[]) 497 | RETURNS text AS $$ 498 | WITH xs(col) AS (SELECT format('%s.%I', x, col) FROM unnest(xs) AS _(col)), 499 | ys(col) AS (SELECT format('%s.%I', y, col) FROM unnest(ys) AS _(col)) 500 | SELECT format('(%s) = (%s)', 501 | array_to_string((SELECT array_agg(col) FROM xs), ', '), 502 | array_to_string((SELECT array_agg(col) FROM ys), ', ')) 503 | $$ LANGUAGE sql STABLE STRICT; 504 | 505 | CREATE FUNCTION format_comparison(x name, xs name[], y regclass, ys name[]) 506 | RETURNS text AS $$ 507 | WITH xs(col) AS (SELECT format('%I.%I', x, col) FROM unnest(xs) AS _(col)), 508 | ys(col) AS (SELECT format('%s.%I', y, col) FROM unnest(ys) AS _(col)) 509 | SELECT format('(%s) = (%s)', 510 | array_to_string((SELECT array_agg(col) FROM xs), ', '), 511 | array_to_string((SELECT array_agg(col) FROM ys), ', ')) 512 | $$ LANGUAGE sql STABLE STRICT; 513 | 514 | CREATE FUNCTION format_comparison(x regclass, xs name[], y name, ys name[]) 515 | RETURNS text AS $$ 516 | WITH xs(col) AS (SELECT format('%s.%I', x, col) FROM unnest(xs) AS _(col)), 517 | ys(col) AS (SELECT format('%I.%I', y, col) FROM unnest(ys) AS _(col)) 518 | SELECT format('(%s) = (%s)', 519 | array_to_string((SELECT array_agg(col) FROM xs), ', '), 520 | array_to_string((SELECT array_agg(col) FROM ys), ', ')) 521 | $$ LANGUAGE sql STABLE STRICT; 522 | 523 | CREATE FUNCTION format_comparison(x name, xs name[], y name, ys name[]) 524 | RETURNS text AS $$ 525 | WITH xs(col) AS (SELECT format('%I.%I', x, col) FROM unnest(xs) AS _(col)), 526 | ys(col) AS (SELECT format('%I.%I', y, col) FROM unnest(ys) AS _(col)) 527 | SELECT format('(%s) = (%s)', 528 | array_to_string((SELECT array_agg(col) FROM xs), ', '), 529 | array_to_string((SELECT array_agg(col) FROM ys), ', ')) 530 | $$ LANGUAGE sql STABLE STRICT; 531 | 532 | CREATE FUNCTION format_comparison(x regclass, xs name[], ys text[]) 533 | RETURNS text AS $$ 534 | WITH xs(col) AS (SELECT format('%s.%I', x, col) FROM unnest(xs) AS _(col)), 535 | named(col, txt) AS (SELECT * FROM unnest(xs, ys)), 536 | casted(val) AS (SELECT format('CAST(%L AS %s)', txt, typ) 537 | FROM named JOIN graphql.cols(x) USING (col)) 538 | SELECT format('(%s) = (%s)', 539 | array_to_string((SELECT array_agg(col) FROM xs), ', '), 540 | array_to_string((SELECT array_agg(val) FROM casted), ', ')) 541 | $$ LANGUAGE sql STABLE STRICT; 542 | 543 | CREATE FUNCTION format_join(tab regclass, 544 | cols name[], 545 | other regclass, 546 | refs name[], 547 | label name DEFAULT NULL) 548 | RETURNS text AS $$ 549 | SELECT CASE WHEN label IS NULL THEN 550 | format('JOIN %s ON (%s)', 551 | other, 552 | graphql.format_comparison(tab, cols, other, refs)) 553 | ELSE 554 | format('JOIN %s AS %I ON (%s)', 555 | other, 556 | label, 557 | graphql.format_comparison(tab, cols, label, refs)) 558 | END 559 | $$ LANGUAGE sql STABLE; 560 | 561 | END; 562 | --------------------------------------------------------------------------------