@@ -54,10 +54,77 @@ type.
54
54
55
55
// * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * */
56
56
57
- SET LOCAL search_path TO graphql; -- Definitions will be created in this schema
58
- -- - However, we must still qualify references between functions -- as when
59
- -- - to_sql calls parse_many -- because the search_path will be different when
60
- -- - the code is run by the application/user.
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 meta .pk WHERE meta .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 meta .cols WHERE meta .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 meta .fk WHERE meta .fk .tab = t;
124
+ $$ LANGUAGE sql STABLE STRICT;
125
+
126
+
127
+ /* * * * * * * * * * * * * * * Begin main program * * * * * * * * * * * * * */
61
128
62
129
CREATE FUNCTION to_sql (expr text )
63
130
RETURNS TABLE (query text ) AS $$
@@ -67,40 +134,40 @@ BEGIN
67
134
END
68
135
$$ LANGUAGE plpgsql STABLE STRICT;
69
136
70
- CREATE FUNCTION to_sql (selector text , predicate text , body text )
137
+ -- - Base case (and entry point): looking up a row from a table.
138
+ CREATE FUNCTION to_sql (selector regclass, predicate text , body text )
71
139
RETURNS text AS $$
72
140
DECLARE
73
141
q text ;
74
- tab regclass = selector::regclass ; -- We need a table, to select from
142
+ tab regclass = selector; -- For clarity
75
143
cols name[];
76
144
col name;
77
145
sub record;
78
146
pk text = NULL ;
79
- fks record [];
147
+ fks graphql . fk [];
80
148
subselects text [];
81
149
predicates text [];
82
150
BEGIN
83
151
body := substr(body, 2 , length(body)- 2 );
84
152
IF predicate IS NOT NULL THEN
85
- SELECT array_to_string(array_agg(format(' %I' , col)), ' , ' )
86
- FROM unnest(graphql .pk (tab)) INTO pk;
87
- predicates := predicates || format(' (%s) = (%s)' , pk, predicate);
88
- -- - Compound primary keys are okay, since we naively trust the input...
153
+ predicates := predicates || format_comparison(tab,
154
+ graphql .pk (tab),
155
+ jsonb(' [' || predicate|| ' ]' ));
89
156
END IF;
90
157
FOR sub IN SELECT * FROM graphql .parse_many (body) LOOP
91
158
IF sub .predicate IS NOT NULL THEN
92
159
RAISE EXCEPTION ' Unhandled nested selector %(%)' ,
93
160
sub .selector , sub .predicate ;
94
161
END IF;
95
- SELECT col FROM cols(tab) WHERE cols .col = sub .selector INTO col ;
162
+ SELECT col INTO STRICT col FROM cols(tab) WHERE cols .col = sub .selector ;
96
163
CASE
97
164
WHEN FOUND AND sub .body IS NULL THEN -- A simple column reference
98
- SELECT * FROM graphql .fk (tab)
99
- WHERE cardinality(cols) = 1 AND cols[1 ] = col
100
- INTO fks;
165
+ SELECT array_agg(fk) INTO STRICT fks
166
+ FROM graphql .fk (tab) WHERE cardinality(cols) = 1 AND cols[1 ] = col;
101
167
IF FOUND THEN
102
168
IF cardinality(fks) > 1 THEN
103
- RAISE EXCEPTION ' Multiple candidate foreign keys for %(%)' , tab, col;
169
+ RAISE EXCEPTION ' More than one candidate foreign keys for %(%)' ,
170
+ tab, col;
104
171
END IF;
105
172
subselects := subselects
106
173
|| format(E' SELECT to_json(%1$I) AS %4$I FROM %1$I\n '
@@ -158,12 +225,14 @@ BEGIN
158
225
END
159
226
$$ LANGUAGE plpgsql STABLE STRICT;
160
227
228
+ -- - Handling fancy columns: json, jsonb and hstore
161
229
CREATE FUNCTION to_sql (selector text , predicate text , body text , tab regclass)
162
230
RETURNS text AS $$
163
231
DECLARE
164
232
q text ;
165
233
col name;
166
234
typ regtype;
235
+ sub record;
167
236
lookups text [];
168
237
labels text [];
169
238
BEGIN
@@ -192,63 +261,69 @@ BEGIN
192
261
END CASE;
193
262
lookups := lookups || format(' ->%L' , sub .selector );
194
263
labels := labels || format(' %I' , sub .selector );
195
- END IF ;
264
+ END LOOP ;
196
265
q := format(E' SELECT to_json(_) AS %I\n '
197
266
' FROM (VALUES (%s)) AS _(%s)' ,
198
267
col,
199
268
array_to_string(lookups, ' , ' ),
200
269
array_to_string(labels, ' , ' ));
270
+ RETURN q;
201
271
END
202
272
$$ LANGUAGE plpgsql STABLE STRICT;
203
273
204
- CREATE FUNCTION to_sql (selector text ,
274
+ -- - For tables with foreign keys that point at the target table. Mutually
275
+ -- - recursive with the base case.
276
+ CREATE FUNCTION to_sql (selector regclass,
205
277
predicate text ,
206
278
body text ,
207
- tab regclass,
208
- other regclass)
279
+ tab regclass)
209
280
RETURNS text AS $$
210
281
DECLARE
282
+ q text ;
283
+ ikey record; -- Key which REFERENCEs `tab` from `selector`
284
+ -- - If `selector` is a JOIN table, then `okey` is used to store a REFERENCE
285
+ -- - to the table with the actual data.
286
+ okey record;
287
+ fks graphql .fk []; -- Reuses the type defined by the VIEW, below
288
+ fk graphql .fk ;
211
289
BEGIN
290
+ BEGIN
291
+ SELECT * INTO STRICT ikey -- Find the first foreign key in column order
292
+ FROM graphql .fk (selector) WHERE fk .other = tab LIMIT 1 ;
293
+ EXCEPTION
294
+ WHEN NO_DATA_FOUND THEN
295
+ RAISE EXCEPTION ' No REFERENCE to table % from table %' , tab, selector;
296
+ END;
297
+ SELECT * FROM graphql .cols (selector)
298
+ WHERE cols .col != ANY (SELECT array_agg(cols) FROM graphql .fk (selector))
299
+ AND cols .typ NOT IN (regtype(' timestamp' ), regtype(' timestamptz' ));
300
+ -- - If:
301
+ -- - * Thare are two and only two foreign keys for the other table, and
302
+ -- - * All the columns of the table participate in one or the other
303
+ -- - foreign key, or are timestamps, then
304
+ -- - * We can treat the table as a JOIN table and follow the keys.
305
+ -- - Otherwise:
306
+ -- - * We use the existence of the foreign key to look up the record in
307
+ -- - the table that JOINs with us.
308
+ IF NOT FOUND AND (SELECT count (1 ) FROM graphql .fk (selector)) = 2 THEN
309
+ SELECT * INTO STRICT okey FROM graphql .fk (selector) WHERE fk != ikey;
310
+ q := graphql .to_sql (okey .other , NULL , body);
311
+ fks := fks || (okey .other , okey .refs , selector, okey .cols )::graphql .fk ;
312
+ fks := fks || (selector, ikey .cols , tab, ikey .refs )::graphql .fk ;
313
+ ELSE
314
+ q := graphql .to_sql (selector, NULL , body);
315
+ fks := fks || (selector, ikey .cols , tab, ikey .refs )::graphql .fk ;
316
+ END IF;
317
+ FOREACH fk IN ARRAY fks LOOP
318
+ -- - Because there is no predicate, `q` will not have a WHERE clause; so we
319
+ -- - can concatenate the JOINs to it.
320
+ q := q || E' \n '
321
+ || graphql .format_join (fk .tab , fk .cols , fk .other , fk .refs );
322
+ END LOOP;
323
+ RETURN q;
212
324
END
213
325
$$ LANGUAGE plpgsql STABLE STRICT;
214
326
215
- SELECT fk.*
216
- FROM graphql .fk (sub .selector ),
217
- LATERAL (SELECT num FROM graphql .cols (tab)
218
- WHERE col = fk .cols [1 ]) AS _
219
- WHERE cardinality(fk .cols ) = 1 AND fk .tab = to_sql .tab
220
- ORDER BY _ .num LIMIT 1 INTO fk;
221
- IF NOT FOUND THEN
222
- RAISE EXCEPTION ' Not able to construct a JOIN for missing column: %' ,
223
- sub .selector ;
224
- END IF;
225
- -- - If:
226
- -- - * Thare are two and only two foreign keys for the other table, and
227
- -- - * All the columns of the table participate in one or the other
228
- -- - foreign key, then
229
- -- - * We can treat the table as a JOIN table and follow the keys.
230
- -- - Otherwise:
231
- -- - * We use the existence of the foreign key to look up the record in
232
- -- - the table that JOINs with us.
233
- -- -
234
- -- - Whenever we are looking at a table that REFERENCES us, we assume it
235
- -- - is a many-to-one relationship; and expect to return an array-valued
236
- -- - result. However, it should be possible to recognize a one-to-one
237
- -- - relationship via the presence of a UNIQUE constraint, in which case
238
- -- - we ought to return a scalar result.
239
- IF FALSE THEN
240
- subselects := subselects || graphql .to_sql (sub.* , tab);
241
- SELECT json_agg(other.* )
242
- FROM tab
243
- JOIN sub .selector ON (pk) = (fk .cols )
244
- JOIN fks[2 ].tab ON (fk2 .cols ) = (pk(fks[2 ].tab));
245
- -- - Recursion happens in here
246
- ELSE
247
- subselects := subselects || graphql .to_sql (sub.* , tab, fk .others );
248
- -- - Recursion happens in here
249
- subquery := subquery
250
- || graphql .to_sql (sub .selector , sub .predicate , sub .body );
251
- END IF;
252
327
CREATE FUNCTION parse_many (expr text )
253
328
RETURNS TABLE (selector text , predicate text , body text ) AS $$
254
329
DECLARE
@@ -337,66 +412,41 @@ CREATE FUNCTION indent(level integer, str text)
337
412
RETURNS text AS $$
338
413
SELECT array_to_string(array_agg(s), E' \n ' )
339
414
FROM unnest(string_to_array(str, E' \n ' )) AS _(ln),
340
- LATERAL (SELECT CASE ln WHEN ' ' THEN ln ELSE repeat(' ' , level) || ln)
415
+ LATERAL (SELECT repeat(' ' , level))
416
+ AS spacer(spacer),
417
+ LATERAL (SELECT CASE ln WHEN ' ' THEN ln ELSE spacer || ln END)
341
418
AS indented(s)
342
419
$$ LANGUAGE sql IMMUTABLE STRICT;
343
420
344
-
345
- /* * * * * * * * * * * * * Table inspection functions * * * * * * * * * * * */
346
-
347
- CREATE VIEW pk AS
348
- SELECT attrelid::regclass AS tab,
349
- array_agg(attname)::name[] AS cols
350
- FROM pg_attribute
351
- JOIN pg_index ON (attrelid = indrelid AND attnum = ANY (indkey))
352
- WHERE indisprimary
353
- GROUP BY attrelid;
354
-
355
- CREATE VIEW cols AS
356
- SELECT attrelid::regclass AS tab,
357
- attname::name AS col,
358
- atttypid::regtype AS typ,
359
- attnum AS num
360
- FROM pg_attribute
361
- WHERE attnum > 0
362
- ORDER BY attrelid, attnum;
363
-
364
- CREATE VIEW fk AS
365
- SELECT conrelid::regclass AS tab,
366
- names .cols ,
367
- confrelid::regclass AS other,
368
- names .refs
369
- FROM pg_constraint,
370
- LATERAL (SELECT array_agg(cols .attname ) AS cols,
371
- array_agg(refs .attname ) AS refs
372
- FROM unnest(conkey, confkey) AS _(col, ref),
373
- LATERAL (SELECT * FROM pg_attribute
374
- WHERE attrelid = conrelid AND attnum = col)
375
- AS cols,
376
- LATERAL (SELECT * FROM pg_attribute
377
- WHERE attrelid = confrelid AND attnum = ref)
378
- AS refs)
379
- AS names
380
- WHERE confrelid != 0 ;
381
-
382
- CREATE FUNCTION ns (tab regclass) RETURNS name AS $$
383
- SELECT nspname
384
- FROM pg_class JOIN pg_namespace ON (pg_namespace .oid = relnamespace)
385
- WHERE pg_class .oid = tab
386
- $$ LANGUAGE sql STABLE STRICT;
387
-
388
- CREATE FUNCTION pk (t regclass) RETURNS name[] AS $$
389
- SELECT cols FROM meta .pk WHERE meta .pk .tab = t;
421
+ CREATE FUNCTION format_comparison (x regclass, xs name[], y regclass, ys name[])
422
+ RETURNS text AS $$
423
+ WITH xs(col) AS (SELECT format(' %I.%I' , x, col) FROM unnest(xs) AS _(col)),
424
+ ys(col) AS (SELECT format(' %I.%I' , y, col) FROM unnest(ys) AS _(col))
425
+ SELECT format(' (%s) = (%s)' ,
426
+ array_to_string((SELECT array_agg(col) FROM xs), ' , ' ),
427
+ array_to_string((SELECT array_agg(col) FROM ys), ' , ' ))
390
428
$$ LANGUAGE sql STABLE STRICT;
391
429
392
- CREATE FUNCTION cols (t regclass)
393
- RETURNS TABLE (num smallint , col name, typ regtype) AS $$
394
- SELECT num, col, typ FROM meta .cols WHERE meta .cols .tab = t;
430
+ CREATE FUNCTION format_comparison (x regclass, xs name[], ys jsonb)
431
+ RETURNS text AS $$
432
+ WITH xs(col) AS (SELECT format(' %I.%I' , x, col) FROM unnest(xs) AS _(col)),
433
+ named(col, txt) AS
434
+ (SELECT * FROM ROWS FROM (unnest(xs), jsonb_array_elements_text(ys))),
435
+ casted(val) AS (SELECT format(' %L::%I' , txt, typ)
436
+ FROM named JOIN graphql .cols (x) USING (col))
437
+ SELECT format(' (%s) = (%s)' ,
438
+ array_to_string((SELECT array_agg(col) FROM xs), ' , ' ),
439
+ array_to_string((SELECT array_agg(val) FROM casted), ' , ' ))
395
440
$$ LANGUAGE sql STABLE STRICT;
396
441
397
- CREATE FUNCTION fk (t regclass)
398
- RETURNS TABLE (cols name[], other regclass, refs name[]) AS $$
399
- SELECT cols, other, refs FROM meta .fk WHERE meta .fk .tab = t;
442
+ CREATE FUNCTION format_join (tab regclass,
443
+ cols name[],
444
+ other regclass,
445
+ refs name[])
446
+ RETURNS text AS $$
447
+ SELECT format(' JOIN %I ON (%s)' ,
448
+ other,
449
+ graphql .format_comparison (tab, cols, other, refs))
400
450
$$ LANGUAGE sql STABLE STRICT;
401
451
402
452
COMMIT ;
0 commit comments