1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
|
/*
* SQL Information Schema
* as defined in ISO 9075-2:1999 chapter 20
*
* Copyright 2002, PostgreSQL Global Development Group
*
* $Id: information_schema.sql,v 1.1 2002/12/14 00:24:24 petere Exp $
*/
/*
* 20.2
* INFORMATION_SCHEMA schema
*/
CREATE SCHEMA information_schema;
GRANT USAGE ON SCHEMA information_schema TO PUBLIC;
SET search_path TO information_schema, public;
-- Note: 20.3 follows later. Some genius screwed up the order in the standard.
/*
* 20.4
* CARDINAL_NUMBER domain
*/
CREATE DOMAIN cardinal_number AS integer
CONSTRAINT cardinal_number_domain_check CHECK (value >= 0);
/*
* 20.5
* CHARACTER_DATA domain
*/
CREATE DOMAIN character_data AS character varying;
/*
* 20.6
* SQL_IDENTIFIER domain
*/
CREATE DOMAIN sql_identifier AS character varying;
/*
* 20.3
* INFORMATION_SCHEMA_CATALOG_NAME view
*/
CREATE VIEW information_schema_catalog_name AS
SELECT CAST(current_database() AS sql_identifier) AS catalog_name;
GRANT SELECT ON information_schema_catalog_name TO PUBLIC;
/*
* 20.7
* TIME_STAMP domain
*/
CREATE DOMAIN time_stamp AS timestamp(2)
DEFAULT current_timestamp(2);
/*
* 20.13
* CHECK_CONSTRAINTS view
*/
CREATE VIEW check_constraints AS
SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog,
CAST(rs.nspname AS sql_identifier) AS constraint_schema,
CAST(con.conname AS sql_identifier) AS constraint_name,
CAST(con.consrc AS character_data) AS check_clause
FROM pg_namespace rs, pg_class c, pg_constraint con, pg_user u
WHERE rs.oid = c.relnamespace AND c.oid = con.conrelid
AND c.relowner = u.usesysid AND u.usename = current_user
AND con.contype = 'c';
GRANT SELECT ON check_constraints TO PUBLIC;
/*
* 20.15
* COLUMN_DOMAIN_USAGE view
*/
CREATE VIEW column_domain_usage AS
SELECT CAST(current_database() AS sql_identifier) AS domain_catalog,
CAST(nt.nspname AS sql_identifier) AS domain_schema,
CAST(t.typname AS sql_identifier) AS domain_name,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nc.nspname AS sql_identifier) AS table_schema,
CAST(c.relname AS sql_identifier) AS table_name,
CAST(a.attname AS sql_identifier) AS column_name
FROM pg_type t, pg_namespace nt, pg_class c, pg_namespace nc,
pg_attribute a, pg_user u
WHERE t.typnamespace = nt.oid AND t.typtype = 'd'
AND c.relnamespace = nc.oid AND a.attrelid = c.oid
AND a.atttypid = t.oid AND t.typowner = u.usesysid
AND u.usename = current_user;
GRANT SELECT ON column_domain_usage TO PUBLIC;
/*
* 20.16
* COLUMN_PRIVILEGES
*/
-- PostgreSQL does not have column privileges, so this view is empty.
-- (Table privileges do not also count as column privileges.)
CREATE VIEW column_privileges AS
SELECT CAST(null AS sql_identifier) AS grantor,
CAST(null AS sql_identifier) AS grantee,
CAST(null AS sql_identifier) AS table_catalog,
CAST(null AS sql_identifier) AS table_schema,
CAST(null AS sql_identifier) AS table_name,
CAST(null AS sql_identifier) AS column_name,
CAST(null AS character_data) AS privilege_type,
CAST(null AS character_data) AS is_grantable
WHERE false;
GRANT SELECT ON column_privileges TO PUBLIC;
/*
* 20.18
* COLUMNS view
*/
CREATE VIEW columns AS
SELECT CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nc.nspname AS sql_identifier) AS table_schema,
CAST(c.relname AS sql_identifier) AS table_name,
CAST(a.attname AS sql_identifier) AS column_name,
CAST(a.attnum AS cardinal_number) AS ordinal_position,
CAST(
CASE WHEN u.usename = current_user THEN a.adsrc ELSE null END
AS character_data)
AS column_default,
CAST(CASE WHEN a.attnotnull THEN 'NO' ELSE 'YES' END
AS character_data)
AS is_nullable,
CAST(format_type(a.atttypid, null) AS character_data)
AS data_type,
CAST(
CASE WHEN a.atttypid IN (25, 1042, 1043, 1560, 1562) AND a.atttypmod <> -1
THEN a.atttypmod - 4
ELSE null END
AS cardinal_number)
AS character_maximum_length,
CAST(
CASE WHEN a.atttypid IN (25, 1042, 1043) THEN 2^30 ELSE null END
AS cardinal_number)
AS character_octet_length,
CAST(
CASE WHEN a.atttypid IN (1700) THEN ((a.atttypmod - 4) >> 16) & 65535 ELSE null END
AS cardinal_number)
AS numeric_precision,
CAST(
CASE WHEN a.atttypid IN (1700) THEN 10 ELSE null END
AS cardinal_number)
AS numeric_precision_radix,
CAST(
CASE WHEN a.atttypid IN (1700) THEN (a.atttypmod - 4) & 65535 ELSE null END
AS cardinal_number)
AS numeric_scale,
CAST(
CASE WHEN a.atttypid IN (1083, 1114, 1184, 1266)
THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod ELSE null END)
WHEN a.atttypid IN (1186)
THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod & 65535 ELSE null END)
ELSE null END
AS cardinal_number)
AS datetime_precision,
CAST(null AS character_data) AS interval_type, -- XXX
CAST(null AS character_data) AS interval_precision, -- XXX
CAST(null AS sql_identifier) AS character_set_catalog,
CAST(null AS sql_identifier) AS character_set_schema,
CAST(null AS sql_identifier) AS character_set_name,
CAST(null AS sql_identifier) AS collation_catalog,
CAST(null AS sql_identifier) AS collation_schema,
CAST(null AS sql_identifier) AS collation_name,
CAST(CASE WHEN t.typbasetype <> 0 THEN current_database() ELSE null END
AS sql_identifier) AS domain_catalog,
CAST(CASE WHEN t.typbasetype <> 0 THEN nt.nspname ELSE null END
AS sql_identifier) AS domain_schema,
CAST(CASE WHEN t.typbasetype <> 0 THEN t.typname ELSE null END
AS sql_identifier) AS domain_name,
CAST(CASE WHEN t.typbasetype = 0 THEN current_database() ELSE null END
AS sql_identifier) AS udt_catalog,
CAST(CASE WHEN t.typbasetype = 0 THEN nt.nspname ELSE null END
AS sql_identifier) AS udt_schema,
CAST(CASE WHEN t.typbasetype = 0 THEN t.typname ELSE null END
AS sql_identifier) AS udt_name,
CAST(null AS sql_identifier) AS scope_catalog,
CAST(null AS sql_identifier) AS scope_schema,
CAST(null AS sql_identifier) AS scope_name,
CAST(null AS cardinal_number) AS maximum_cardinality,
CAST(null AS sql_identifier) AS dtd_identifier,
CAST('NO' AS character_data) AS is_self_referencing
FROM (pg_attribute LEFT JOIN pg_attrdef ON attrelid = adrelid AND attnum = adnum) AS a,
pg_class c, pg_namespace nc, pg_type t, pg_namespace nt, pg_user u
WHERE a.attrelid = c.oid
AND a.atttypid = t.oid
AND u.usesysid = c.relowner
AND nc.oid = c.relnamespace
AND nt.oid = t.typnamespace
AND u.usename = current_user
AND a.attnum > 0 AND NOT a.attisdropped AND c.relkind in ('r', 'v');
GRANT SELECT ON columns TO PUBLIC;
/*
* 20.35
* REFERENTIAL_CONSTRAINTS view
*/
CREATE VIEW referential_constraints AS
SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog,
CAST(ncon.nspname AS sql_identifier) AS constraint_schema,
CAST(con.conname AS sql_identifier) AS constraint_name,
CAST(current_database() AS sql_identifier) AS unique_constraint_catalog,
CAST(null AS sql_identifier) AS unique_constraint_schema, -- XXX
CAST(null AS sql_identifier) AS unique_constraint_name, -- XXX
CAST(
CASE con.confmatchtype WHEN 'f' THEN 'FULL'
WHEN 'p' THEN 'PARTIAL'
WHEN 'u' THEN 'NONE' END
AS character_data) AS match_option,
CAST(
CASE con.confupdtype WHEN 'c' THEN 'CASCADE'
WHEN 'n' THEN 'SET NULL'
WHEN 'd' THEN 'SET DEFAULT'
WHEN 'r' THEN 'RESTRICT'
WHEN 'a' THEN 'NOACTION' END
AS character_data) AS update_rule,
CAST(
CASE con.confdeltype WHEN 'c' THEN 'CASCADE'
WHEN 'n' THEN 'SET NULL'
WHEN 'd' THEN 'SET DEFAULT'
WHEN 'r' THEN 'RESTRICT'
WHEN 'a' THEN 'NOACTION' END
AS character_data) AS delete_rule
FROM pg_namespace ncon,
pg_constraint con,
pg_class r,
pg_user u
WHERE ncon.oid = con.connamespace
AND con.conrelid = r.oid AND r.relowner = u.usesysid
AND u.usename = current_user;
GRANT SELECT ON referential_constraints TO PUBLIC;
/*
* 20.46
* SCHEMATA view
*/
CREATE VIEW schemata AS
SELECT CAST(current_database() AS sql_identifier) AS catalog_name,
CAST(n.nspname AS sql_identifier) AS schema_name,
CAST(u.usename AS sql_identifier) AS schema_owner,
CAST(null AS sql_identifier) AS default_character_set_catalog,
CAST(null AS sql_identifier) AS default_character_set_schema,
CAST(null AS sql_identifier) AS default_character_set_name,
CAST(null AS character_data) AS sql_path
FROM pg_namespace n, pg_user u
WHERE n.nspowner = u.usesysid AND u.usename = current_user;
GRANT SELECT ON schemata TO PUBLIC;
/*
* 20.47
* SQL_FEATURES table
*/
CREATE TABLE sql_features (
feature_id character_data,
feature_name character_data,
sub_feature_id character_data,
sub_feature_name character_data,
feature_subfeature_package_code character_data,
is_supported character_data,
is_verified_by character_data,
comments character_data
);
-- FIXME: Fill this in using the information in User's Guide Appendix
-- C, and then figure out a way to generate the documentation from this
-- table.
GRANT SELECT ON sql_features TO PUBLIC;
/*
* 20.49
* SQL_LANGUAGES table
*/
CREATE TABLE sql_languages (
sql_language_source character_data,
sql_language_year character_data,
sql_language_conformance character_data,
sql_language_integrity character_data,
sql_language_implementation character_data,
sql_language_binding_style character_data,
sql_language_programming_language character_data
);
INSERT INTO sql_languages VALUES ('ISO 9075', '1999', 'CORE', NULL, NULL, 'DIRECT', NULL);
INSERT INTO sql_languages VALUES ('ISO 9075', '1999', 'CORE', NULL, NULL, 'EMBEDDED', 'C');
GRANT SELECT ON sql_languages TO PUBLIC;
/*
* 20.53
* TABLE_CONSTRAINTS view
*/
CREATE VIEW table_constraints AS
SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog,
CAST(nc.nspname AS sql_identifier) AS constraint_schema,
CAST(c.conname AS sql_identifier) AS constraint_name,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nr.nspname AS sql_identifier) AS table_schema,
CAST(r.relname AS sql_identifier) AS table_name,
CAST(
CASE c.contype WHEN 'c' THEN 'CHECK'
WHEN 'f' THEN 'FOREIGN KEY'
WHEN 'p' THEN 'PRIMARY KEY'
WHEN 'u' THEN 'UNIQUE' END
AS character_data) AS constraint_type,
CAST(CASE WHEN c.condeferrable THEN 'YES' ELSE 'NO' END AS character_data)
AS is_deferrable,
CAST(CASE WHEN c.condeferred THEN 'YES' ELSE 'NO' END AS character_data)
AS initially_deferred
FROM pg_namespace nc,
pg_namespace nr,
pg_constraint c,
pg_class r,
pg_user u
WHERE nc.oid = c.connamespace AND nr.oid = r.relnamespace
AND c.conrelid = r.oid AND r.relowner = u.usesysid
AND u.usename = current_user;
-- FIMXE: Not-null constraints are missing here.
GRANT SELECT ON table_constraints TO PUBLIC;
/*
* 20.55
* TABLE_PRIVILEGES view
*/
CREATE VIEW table_privileges AS
SELECT CAST(u_owner.usename AS sql_identifier) AS grantor,
CAST(u_grantee.usename AS sql_identifier) AS grantee,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nc.nspname AS sql_identifier) AS table_schema,
CAST(c.relname AS sql_identifier) AS table_name,
CAST(pr.type AS character_data) AS privilege_type,
CAST('NO' AS character_data) AS is_grantable,
CAST('NO' AS character_data) AS with_hierarchy
FROM pg_user u_owner,
pg_user u_grantee,
pg_namespace nc,
pg_class c,
(SELECT 'SELECT' UNION SELECT 'DELETE' UNION SELECT 'INSERT' UNION SELECT 'UPDATE'
UNION SELECT 'REFERENCES' UNION SELECT 'TRIGGER') AS pr (type)
WHERE u_owner.usesysid = c.relowner
AND c.relnamespace = nc.oid
AND has_table_privilege(u_grantee.usename, c.oid, pr.type)
AND (u_owner.usename = current_user OR u_grantee.usename = current_user);
GRANT SELECT ON table_privileges TO PUBLIC;
/*
* 20.56
* TABLES view
*/
CREATE VIEW tables AS
SELECT CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nc.nspname AS sql_identifier) AS table_schema,
CAST(c.relname AS sql_identifier) AS table_name,
CAST(
CASE WHEN nc.nspname LIKE 'pg!_temp!_%' ESCAPE '!' THEN 'LOCAL TEMPORARY'
WHEN c.relkind = 'r' THEN 'BASE TABLE'
WHEN c.relkind = 'v' THEN 'VIEW'
ELSE null END
AS character_data) AS table_type,
CAST(null AS sql_identifier) AS self_referencing_column_name,
CAST(null AS character_data) AS reference_generation,
CAST(null AS sql_identifier) AS user_defined_type_catalog,
CAST(null AS sql_identifier) AS user_defined_type_schema,
CAST(null AS sql_identifier) AS user_defined_name
FROM pg_namespace nc, pg_class c, pg_user u
WHERE c.relnamespace = nc.oid AND u.usesysid = c.relowner
AND (u.usename = current_user
OR EXISTS(SELECT 1 FROM information_schema.table_privileges tp
WHERE tp.table_schema = nc.nspname
AND tp.table_name = c.relname
AND tp.grantee = current_user))
AND c.relkind IN ('r', 'v');
GRANT SELECT ON tables TO PUBLIC;
/*
* 20.63
* USAGE_PRIVILEGES view
*/
-- Of the things currently implemented in PostgreSQL, usage privileges
-- apply only to domains. Since domains have no real privileges, we
-- represent all domains with implicit usage privilege here.
CREATE VIEW usage_privileges AS
SELECT CAST(u.usename AS sql_identifier) AS grantor,
CAST('PUBLIC' AS sql_identifier) AS grantee,
CAST(current_database() AS sql_identifier) AS object_catalog,
CAST(n.nspname AS sql_identifier) AS object_schema,
CAST(t.typname AS sql_identifier) AS object_name,
CAST('DOMAIN' AS character_data) AS object_type,
CAST('USAGE' AS character_data) AS privilege_type,
CAST('NO' AS character_data) AS is_grantable
FROM pg_user u,
pg_namespace n,
pg_type t
WHERE u.usesysid = t.typowner
AND t.typnamespace = n.oid
AND t.typtype = 'd';
GRANT SELECT ON usage_privileges TO PUBLIC;
/*
* 20.68
* VIEWS view
*/
CREATE VIEW views AS
SELECT CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nc.nspname AS sql_identifier) AS table_schema,
CAST(c.relname AS sql_identifier) AS table_name,
CAST(
CASE WHEN u.usename = current_user THEN pg_get_viewdef(c.oid)
ELSE null END
AS character_data) AS view_definition,
CAST('NONE' AS character_data) AS check_option,
CAST(null AS character_data) AS is_updatable, -- FIXME
CAST(null AS character_data) AS is_insertable_into -- FIXME
FROM pg_namespace nc, pg_class c, pg_user u
WHERE c.relnamespace = nc.oid AND u.usesysid = c.relowner
AND (u.usename = current_user
OR EXISTS(SELECT 1 FROM information_schema.table_privileges tp
WHERE tp.table_schema = nc.nspname
AND tp.table_name = c.relname
AND tp.grantee = current_user))
AND c.relkind = 'v';
GRANT SELECT ON views TO PUBLIC;
|