1
+ BEGIN ;
2
+
3
+ DROP SCHEMA IF EXISTS graphql CASCADE;
1
4
CREATE SCHEMA graphql ;
2
5
3
6
/* * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * //
@@ -51,26 +54,36 @@ type.
51
54
52
55
// * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * * */
53
56
54
- CREATE FUNCTION graphql .to_sql(expr text )
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.
61
+
62
+ CREATE FUNCTION to_sql (expr text )
55
63
RETURNS TABLE (query text ) AS $$
56
64
BEGIN
57
65
RETURN QUERY SELECT graphql .to_sql (selector, predicate, body)
58
66
FROM graphql .parse_many (expr);
59
67
END
60
68
$$ LANGUAGE plpgsql STABLE STRICT;
61
69
62
- CREATE FUNCTION graphql . to_sql(selector text , predicate text , body text )
70
+ CREATE FUNCTION to_sql (selector text , predicate text , body text )
63
71
RETURNS text AS $$
64
72
DECLARE
65
73
q text ;
66
74
tab regclass = selector::regclass; -- Without a parent, we need a table
67
75
cols text [];
76
+ col text ;
68
77
sub record;
69
- pk text ;
78
+ pk text = NULL ;
79
+ fk record;
80
+ subselects text [];
70
81
BEGIN
71
82
q := ' FROM ' || tab; -- Regclass is auto-escaped
72
83
body := substr(body, 2 , length(body)- 2 );
73
84
IF predicate IS NOT NULL THEN
85
+ SELECT array_to_string(array_agg(format(' %I' , col)), ' , ' )
86
+ FROM unnest(graphql .pk (tab)) INTO pk;
74
87
SELECT array_to_string(array_agg(format(' %I' , col)), ' , ' )
75
88
FROM graphql .pk (tab) INTO pk;
76
89
q := q || E' \n WHERE (' || pk || ' ) = (' || predicate || ' )' ;
@@ -81,20 +94,74 @@ BEGIN
81
94
RAISE EXCEPTION ' Unhandled nested selector %(%)' ,
82
95
sub .selector , sub .predicate ;
83
96
END IF;
84
- -- - TODO: Handle nested lookup into JSON, HStore, RECORD
85
- -- - TODO: Introduce foreign key magicks
86
- cols := cols || format(' %I' , sub .selector );
97
+ SELECT col FROM cols(tab) WHERE col = sub .selector INTO col;
98
+ CASE
99
+ WHEN FOUND AND sub .body IS NULL THEN -- A simple column reference
100
+ SELECT * FROM graphql .fk (tab)
101
+ WHERE cols[1 ] = col AND cardinality(cols) = 1
102
+ INTO fk; -- TODO: If there's more than one, emit a clear message.
103
+ IF FOUND THEN
104
+ subselects := subselects
105
+ || format(E' SELECT to_json(%1$I) AS %4$I FROM %1$I\n '
106
+ ' WHERE %1$I.%2$I = %3$I.%4$I' ,
107
+ fk .other , fk .refs [1 ], tab, col);
108
+ cols := cols || format(' %I.%I' , ' sub/' || cardinality(subselects), col);
109
+ ELSE
110
+ cols := cols || format(' %I' , col);
111
+ END IF;
112
+ WHEN FOUND AND sub .body IS NOT NULL THEN -- Index into a column
113
+ -- - TODO: Handle nested lookup into JSON, HStore, RECORD
114
+ -- - TODO: If col REFERENCES something, push lookup down to it
115
+ WHEN NOT FOUND THEN -- It might be a reference to another table
116
+ SELECT fk.*
117
+ FROM graphql .fk (sub .selector ),
118
+ LATERAL (SELECT num FROM graphql .cols (tab)
119
+ WHERE col = fk .cols [1 ]) AS _
120
+ WHERE cardinality(fk .cols ) = 1 AND fk .tab = to_sql .tab
121
+ ORDER BY _ .num LIMIT 1 INTO fk;
122
+ IF NOT FOUND THEN
123
+ RAISE EXCEPTION ' Not able to construct a JOIN for missing column: %' ,
124
+ sub .selector ;
125
+ END IF;
126
+ -- - If:
127
+ -- - * Thare are two and only two foreign keys for the other table, and
128
+ -- - * All the columns of the table participate in one or the other
129
+ -- - foreign key, then
130
+ -- - * We can treat the table as a JOIN table and follow the keys.
131
+ -- - Otherwise:
132
+ -- - * We use the existence of the foreign key to look up the record in
133
+ -- - the table that JOINs with us.
134
+ -- - Whenever we are looking at a table that REFERENCES us, we assume it
135
+ -- - is a many-to-one relationship; and expect to return an array-valued
136
+ -- - result.
137
+ IF FALSE THEN
138
+ -- - Recursion happens in here
139
+ ELSE
140
+ -- - Recursion happens in here
141
+ END IF;
142
+ ELSE
143
+ RAISE EXCEPTION ' Not able to interpret this selector: %' , sub .selector ;
144
+ END CASE;
87
145
END LOOP;
88
- IF cols > ARRAY[]::text [] THEN
89
- q := ' SELECT ' || array_to_string(cols, ' , ' ) || E' \n ' || q;
90
- ELSE
91
- q := ' SELECT *' || E' \n ' || q;
92
- END IF;
146
+ DECLARE
147
+ column_expression text ;
148
+ BEGIN
149
+ IF cols > ARRAY[]::text [] THEN
150
+ column_expression := array_to_string(cols, ' , ' );
151
+ ELSE
152
+ column_expression := format(' %I' , tab);
153
+ END IF;
154
+ IF pk IS NOT NULL THEN -- Implies single result
155
+ q := ' SELECT to_json(' || column_expression || E' )\n ' || q;
156
+ ELSE
157
+ q := ' SELECT json_agg(' || column_expression || E' )\n ' || q;
158
+ END IF;
159
+ END;
93
160
RETURN q;
94
161
END
95
162
$$ LANGUAGE plpgsql STABLE STRICT;
96
163
97
- CREATE FUNCTION graphql . parse_many(expr text )
164
+ CREATE FUNCTION parse_many (expr text )
98
165
RETURNS TABLE (selector text , predicate text , body text ) AS $$
99
166
DECLARE
100
167
whitespace text = E' \t\n ' ;
@@ -118,11 +185,11 @@ BEGIN
118
185
END
119
186
$$ LANGUAGE plpgsql IMMUTABLE STRICT;
120
187
121
- CREATE FUNCTION graphql . parse_one(expr text ,
122
- OUT selector text ,
123
- OUT predicate text ,
124
- OUT body text ,
125
- OUT remainder text ) AS $$
188
+ CREATE FUNCTION parse_one (expr text ,
189
+ OUT selector text ,
190
+ OUT predicate text ,
191
+ OUT body text ,
192
+ OUT remainder text ) AS $$
126
193
DECLARE
127
194
label text = ' [a-zA-Z_][a-zA-Z0-9_]*' ;
128
195
selector_re text = ' ^(' || label || ' )' || ' ([(]([^()]+)[)])?' ;
@@ -170,17 +237,67 @@ BEGIN
170
237
END
171
238
$$ LANGUAGE plpgsql IMMUTABLE STRICT;
172
239
173
- CREATE FUNCTION graphql .pk(tab regclass)
174
- RETURNS TABLE (col name, typ regtype) AS $$
175
- SELECT attname, atttypid::regtype
176
- FROM pg_index JOIN pg_attribute ON (attnum = ANY (indkey))
177
- WHERE indrelid = tab AND indisprimary AND attrelid = tab AND attnum > 0
178
- ORDER BY attnum
179
- $$ LANGUAGE sql STABLE STRICT;
180
- -- - NB: For SELECTs, it would be okay just to return the column numbers. One
181
- -- - could skip the JOIN with pg_attribute, resulting in a faster query.
182
-
183
- CREATE FUNCTION graphql .excerpt(str text , start integer , length integer )
240
+ CREATE FUNCTION excerpt (str text , start integer , length integer )
184
241
RETURNS text AS $$
185
242
SELECT substr(regexp_replace(str, ' [ \n\t ]+' , ' ' , ' g' ), start, length);
186
243
$$ LANGUAGE sql IMMUTABLE STRICT;
244
+
245
+
246
+ /* * * * * * * * * * * * * Table inspection functions * * * * * * * * * * * */
247
+
248
+ CREATE VIEW pk AS
249
+ SELECT attrelid::regclass AS tab,
250
+ array_agg(attname)::name[] AS cols
251
+ FROM pg_attribute
252
+ JOIN pg_index ON (attrelid = indrelid AND attnum = ANY (indkey))
253
+ WHERE indisprimary
254
+ GROUP BY attrelid;
255
+
256
+ CREATE VIEW cols AS
257
+ SELECT attrelid::regclass AS tab,
258
+ attname::name AS col,
259
+ atttypid::regtype AS typ,
260
+ attnum AS num
261
+ FROM pg_attribute
262
+ WHERE attnum > 0
263
+ ORDER BY attrelid, attnum;
264
+
265
+ CREATE VIEW fk AS
266
+ SELECT conrelid::regclass AS tab,
267
+ names .cols ,
268
+ confrelid::regclass AS other,
269
+ names .refs
270
+ FROM pg_constraint,
271
+ LATERAL (SELECT array_agg(cols .attname ) AS cols,
272
+ array_agg(refs .attname ) AS refs
273
+ FROM unnest(conkey, confkey) AS _(col, ref),
274
+ LATERAL (SELECT * FROM pg_attribute
275
+ WHERE attrelid = conrelid AND attnum = col)
276
+ AS cols,
277
+ LATERAL (SELECT * FROM pg_attribute
278
+ WHERE attrelid = confrelid AND attnum = ref)
279
+ AS refs)
280
+ AS names
281
+ WHERE confrelid != 0 ;
282
+
283
+ CREATE FUNCTION ns (tab regclass) RETURNS name AS $$
284
+ SELECT nspname
285
+ FROM pg_class JOIN pg_namespace ON (pg_namespace .oid = relnamespace)
286
+ WHERE pg_class .oid = tab
287
+ $$ LANGUAGE sql STABLE STRICT;
288
+
289
+ CREATE FUNCTION pk (t regclass) RETURNS name[] AS $$
290
+ SELECT cols FROM meta .pk WHERE meta .pk .tab = t;
291
+ $$ LANGUAGE sql STABLE STRICT;
292
+
293
+ CREATE FUNCTION cols (t regclass)
294
+ RETURNS TABLE (num smallint , col name, typ regtype) AS $$
295
+ SELECT num, col, typ FROM meta .cols WHERE meta .cols .tab = t;
296
+ $$ LANGUAGE sql STABLE STRICT;
297
+
298
+ CREATE FUNCTION fk (t regclass)
299
+ RETURNS TABLE (cols name[], other regclass, refs name[]) AS $$
300
+ SELECT cols, other, refs FROM meta .fk WHERE meta .fk .tab = t;
301
+ $$ LANGUAGE sql STABLE STRICT;
302
+
303
+ COMMIT ;
0 commit comments