2020-12-08 17:22:31 +03:00
|
|
|
SELECT
|
2022-03-08 16:02:13 +03:00
|
|
|
"table".table_schema,
|
|
|
|
"table".table_name,
|
2020-12-08 17:22:31 +03:00
|
|
|
|
2020-12-17 14:37:16 +03:00
|
|
|
-- This field corresponds to the `DBTableMetadata` Haskell type
|
2020-12-08 17:22:31 +03:00
|
|
|
jsonb_build_object(
|
|
|
|
'oid', "table".oid :: integer,
|
|
|
|
'columns', coalesce(columns.info, '[]'),
|
|
|
|
'primary_key', primary_key.info,
|
|
|
|
-- Note: unique_constraints does NOT include primary key constraints!
|
|
|
|
'unique_constraints', coalesce(unique_constraints.info, '[]'),
|
|
|
|
'foreign_keys', coalesce(foreign_key_constraints.info, '[]'),
|
server: disable mutation for materialised views
The materialized views cannot be mutated, so this commit removes the option to run mutation on the materialized views via graphql endpoint. Before this, users could have tried running mutation for the materialized views using the graphql endpoint (or from HGE console), which would have resulted in the following error:
``` JSON
{
"errors": [
{
"extensions": {
"internal": {
"statement": "WITH \"articles_mat_view__mutation_result_alias\" AS (DELETE FROM \"public\".\"articles_mat_view\" WHERE (('true') AND (((((\"public\".\"articles_mat_view\".\"id\") = (('20155721-961c-4d8b-a5c4-873ed62c7a61')::uuid)) AND ('true')) AND ('true')) AND ('true'))) RETURNING * ), \"articles_mat_view__all_columns_alias\" AS (SELECT \"id\" , \"author_id\" , \"content\" , \"test_col\" , \"test_col2\" FROM \"articles_mat_view__mutation_result_alias\" ) SELECT json_build_object('affected_rows', (SELECT COUNT(*) FROM \"articles_mat_view__all_columns_alias\" ) ) ",
"prepared": false,
"error": {
"exec_status": "FatalError",
"hint": null,
"message": "cannot change materialized view \"articles_mat_view\"",
"status_code": "42809",
"description": null
},
"arguments": []
},
"path": "$",
"code": "unexpected"
},
"message": "database query error"
}
]
}
```
So, we don't want to generate the mutation fields for the materialized views altogether.
https://github.com/hasura/graphql-engine-mono/pull/2226
GitOrigin-RevId: 4ef441764035a8039e1c780d454569ee1f2febc3
2021-09-06 13:09:37 +03:00
|
|
|
-- Note: for views and materialized views, we are asking Postgres if it is mutable or not
|
|
|
|
-- and for any other case, we are assuming it to be mutable.
|
|
|
|
'view_info', CASE WHEN "table".relkind IN ('v', 'm') THEN jsonb_build_object(
|
2020-12-08 17:22:31 +03:00
|
|
|
'is_updatable', ((pg_catalog.pg_relation_is_updatable("table".oid, true) & 4) = 4),
|
|
|
|
'is_insertable', ((pg_catalog.pg_relation_is_updatable("table".oid, true) & 8) = 8),
|
|
|
|
'is_deletable', ((pg_catalog.pg_relation_is_updatable("table".oid, true) & 16) = 16)
|
|
|
|
) END,
|
2021-05-21 05:46:58 +03:00
|
|
|
'description', description.description,
|
2023-05-25 12:30:18 +03:00
|
|
|
'extra_table_metadata', jsonb_build_object(
|
|
|
|
'table_type', CASE WHEN "table".relkind IN ('v', 'm') THEN 'view' ELSE 'table' END
|
|
|
|
)
|
2020-12-08 17:22:31 +03:00
|
|
|
)::json AS info
|
|
|
|
|
2022-03-08 16:02:13 +03:00
|
|
|
-- tracked tables
|
|
|
|
-- $1 parameter provides JSON array of tracked tables
|
|
|
|
FROM
|
|
|
|
( SELECT "tracked"."name" AS "table_name",
|
|
|
|
"tracked"."schema" AS "table_schema"
|
|
|
|
FROM jsonb_to_recordset($1::jsonb) AS "tracked"("schema" text, "name" text)
|
|
|
|
) "tracked_table"
|
|
|
|
|
2020-12-08 17:22:31 +03:00
|
|
|
-- table & schema
|
2022-03-08 16:02:13 +03:00
|
|
|
LEFT JOIN
|
|
|
|
( SELECT "table".oid,
|
|
|
|
"table".relkind,
|
|
|
|
"table".relname AS "table_name",
|
|
|
|
"schema".nspname AS "table_schema"
|
|
|
|
FROM pg_catalog.pg_class "table"
|
|
|
|
JOIN pg_catalog.pg_namespace "schema"
|
|
|
|
ON schema.oid = "table".relnamespace
|
|
|
|
) "table"
|
|
|
|
ON "table"."table_name" = "tracked_table"."table_name"
|
|
|
|
AND "table"."table_schema" = "tracked_table"."table_schema"
|
2020-12-08 17:22:31 +03:00
|
|
|
|
|
|
|
-- description
|
|
|
|
LEFT JOIN pg_catalog.pg_description description
|
|
|
|
ON description.classoid = 'pg_catalog.pg_class'::regclass
|
|
|
|
AND description.objoid = "table".oid
|
|
|
|
AND description.objsubid = 0
|
|
|
|
|
|
|
|
-- columns
|
|
|
|
LEFT JOIN LATERAL
|
|
|
|
( SELECT jsonb_agg(jsonb_build_object(
|
|
|
|
'name', "column".attname,
|
|
|
|
'position', "column".attnum,
|
2022-04-11 11:04:12 +03:00
|
|
|
'type', json_build_object('name', coalesce(base_type.typname, "type".typname), 'type', "type".typtype),
|
2020-12-08 17:22:31 +03:00
|
|
|
'is_nullable', NOT "column".attnotnull,
|
2021-12-01 14:33:14 +03:00
|
|
|
'description', pg_catalog.col_description("table".oid, "column".attnum),
|
2022-02-03 17:14:33 +03:00
|
|
|
'mutability', jsonb_build_object(
|
|
|
|
'is_insertable', NOT (identitypolyfill.attidentity = 'a' OR generatedpolyfill.attgenerated = 's'),
|
|
|
|
'is_updatable', NOT (identitypolyfill.attidentity = 'a' OR generatedpolyfill.attgenerated = 's'))
|
2020-12-08 17:22:31 +03:00
|
|
|
)) AS info
|
|
|
|
FROM pg_catalog.pg_attribute "column"
|
2022-02-21 12:59:02 +03:00
|
|
|
|
2022-02-03 17:14:33 +03:00
|
|
|
-- The columns 'pg_attribute.attidentity' and 'pg_attribute.attgenerated' are
|
|
|
|
-- not available in older versions of Postgres, because those versions do not
|
|
|
|
-- implement the concepts the catalog columns represent.
|
2022-02-21 12:59:02 +03:00
|
|
|
-- To support older versions we apply an aliasing hack that ensures
|
|
|
|
-- _something_ called e.g. attidentity is in scope.
|
|
|
|
-- Originally sourced from: https://stackoverflow.com/questions/18951071/postgres-return-a-default-value-when-a-column-doesnt-exist.
|
|
|
|
INNER JOIN
|
|
|
|
(
|
|
|
|
SELECT attrelid, attnum, attname, CASE WHEN attidentity_exists
|
|
|
|
THEN attidentity::text
|
|
|
|
ELSE ''::text
|
|
|
|
END as attidentity
|
|
|
|
FROM pg_catalog.pg_attribute
|
|
|
|
CROSS JOIN (SELECT current_setting('server_version_num')::int >= 100000)
|
|
|
|
AS attidentity(attidentity_exists)
|
|
|
|
) AS identitypolyfill
|
|
|
|
ON identitypolyfill.attrelid = "column".attrelid
|
2022-02-03 17:14:33 +03:00
|
|
|
AND identitypolyfill.attnum = "column".attnum
|
|
|
|
AND identitypolyfill.attname = "column".attname
|
2022-02-21 12:59:02 +03:00
|
|
|
|
|
|
|
INNER JOIN
|
|
|
|
(
|
|
|
|
SELECT attrelid, attnum, attname, CASE WHEN attgenerated_exists
|
|
|
|
THEN attgenerated::text
|
|
|
|
ELSE ''::text
|
|
|
|
END as attgenerated
|
|
|
|
FROM pg_catalog.pg_attribute
|
|
|
|
CROSS JOIN (SELECT current_setting('server_version_num')::int >= 120000)
|
|
|
|
AS attgenerated(attgenerated_exists)
|
|
|
|
) AS generatedpolyfill
|
|
|
|
ON generatedpolyfill.attrelid = "column".attrelid
|
2022-02-03 17:14:33 +03:00
|
|
|
AND generatedpolyfill.attnum = "column".attnum
|
|
|
|
AND generatedpolyfill.attname = "column".attname
|
2022-02-21 12:59:02 +03:00
|
|
|
|
2020-12-08 17:22:31 +03:00
|
|
|
LEFT JOIN pg_catalog.pg_type "type"
|
|
|
|
ON "type".oid = "column".atttypid
|
|
|
|
LEFT JOIN pg_catalog.pg_type base_type
|
|
|
|
ON "type".typtype = 'd' AND base_type.oid = "type".typbasetype
|
|
|
|
WHERE "column".attrelid = "table".oid
|
|
|
|
-- columns where attnum <= 0 are special, system-defined columns
|
|
|
|
AND "column".attnum > 0
|
2021-11-01 14:03:59 +03:00
|
|
|
-- dropped columns still exist in the system catalog as "zombie" columns, so ignore those
|
2020-12-08 17:22:31 +03:00
|
|
|
AND NOT "column".attisdropped
|
|
|
|
) columns ON true
|
|
|
|
|
|
|
|
-- primary key
|
|
|
|
LEFT JOIN LATERAL
|
|
|
|
( SELECT jsonb_build_object(
|
2022-06-08 02:24:42 +03:00
|
|
|
'constraint', jsonb_build_object(
|
|
|
|
'name', class.relname,
|
|
|
|
'oid', class.oid :: integer),
|
2020-12-08 17:22:31 +03:00
|
|
|
'columns', coalesce(columns.info, '[]')
|
|
|
|
) AS info
|
2021-12-07 20:24:33 +03:00
|
|
|
FROM pg_catalog.pg_index idx
|
2020-12-08 17:22:31 +03:00
|
|
|
JOIN pg_catalog.pg_class class
|
2021-12-07 20:24:33 +03:00
|
|
|
ON class.oid = idx.indexrelid
|
2020-12-08 17:22:31 +03:00
|
|
|
LEFT JOIN LATERAL
|
|
|
|
( SELECT jsonb_agg("column".attname) AS info
|
|
|
|
FROM pg_catalog.pg_attribute "column"
|
|
|
|
WHERE "column".attrelid = "table".oid
|
2021-12-07 20:24:33 +03:00
|
|
|
AND "column".attnum = ANY (idx.indkey)
|
2020-12-08 17:22:31 +03:00
|
|
|
) AS columns ON true
|
2021-12-07 20:24:33 +03:00
|
|
|
WHERE idx.indrelid = "table".oid
|
|
|
|
AND idx.indisprimary
|
2020-12-08 17:22:31 +03:00
|
|
|
) primary_key ON true
|
|
|
|
|
|
|
|
-- unique constraints
|
|
|
|
LEFT JOIN LATERAL
|
2022-06-08 02:24:42 +03:00
|
|
|
( SELECT jsonb_agg(
|
|
|
|
jsonb_build_object(
|
|
|
|
'constraint', jsonb_build_object(
|
|
|
|
'name', class.relname,
|
|
|
|
'oid', class.oid :: integer
|
|
|
|
),
|
2022-06-17 10:48:20 +03:00
|
|
|
'columns', coalesce(columns.info, '[]')
|
2022-06-08 02:24:42 +03:00
|
|
|
)
|
|
|
|
) AS info
|
2021-12-07 20:24:33 +03:00
|
|
|
FROM pg_catalog.pg_index idx
|
2020-12-08 17:22:31 +03:00
|
|
|
JOIN pg_catalog.pg_class class
|
2021-12-07 20:24:33 +03:00
|
|
|
ON class.oid = idx.indexrelid
|
2022-06-08 02:24:42 +03:00
|
|
|
LEFT JOIN LATERAL
|
|
|
|
( SELECT jsonb_agg("column".attname) AS info
|
|
|
|
FROM pg_catalog.pg_attribute "column"
|
|
|
|
WHERE "column".attrelid = "table".oid
|
|
|
|
AND "column".attnum = ANY (idx.indkey)
|
|
|
|
) AS columns ON true
|
2021-12-07 20:24:33 +03:00
|
|
|
WHERE idx.indrelid = "table".oid
|
|
|
|
AND idx.indisunique
|
|
|
|
AND NOT idx.indisprimary
|
2020-12-08 17:22:31 +03:00
|
|
|
) unique_constraints ON true
|
|
|
|
|
|
|
|
-- foreign keys
|
2021-11-23 18:18:51 +03:00
|
|
|
LEFT JOIN
|
2020-12-08 17:22:31 +03:00
|
|
|
( SELECT jsonb_agg(jsonb_build_object(
|
|
|
|
'constraint', jsonb_build_object(
|
|
|
|
'name', foreign_key.constraint_name,
|
|
|
|
'oid', foreign_key.constraint_oid :: integer
|
|
|
|
),
|
|
|
|
'columns', foreign_key.columns,
|
|
|
|
'foreign_table', jsonb_build_object(
|
|
|
|
'schema', foreign_key.ref_table_table_schema,
|
|
|
|
'name', foreign_key.ref_table
|
|
|
|
),
|
|
|
|
'foreign_columns', foreign_key.ref_columns
|
2021-11-23 18:18:51 +03:00
|
|
|
)) AS info, -- This field corresponds to the `PGForeignKeyMetadata` Haskell type
|
|
|
|
foreign_key.table_schema,
|
|
|
|
foreign_key.table_name
|
2020-12-08 17:22:31 +03:00
|
|
|
FROM (SELECT
|
|
|
|
q.table_schema :: text,
|
|
|
|
q.table_name :: text,
|
|
|
|
q.constraint_name :: text,
|
|
|
|
min(q.constraint_oid) :: integer as constraint_oid,
|
|
|
|
min(q.ref_table_table_schema) :: text as ref_table_table_schema,
|
|
|
|
min(q.ref_table) :: text as ref_table,
|
|
|
|
json_agg(ac.attname) as columns,
|
|
|
|
json_agg(afc.attname) as ref_columns
|
|
|
|
FROM
|
|
|
|
(SELECT
|
|
|
|
ctn.nspname AS table_schema,
|
|
|
|
ct.relname AS table_name,
|
|
|
|
r.conrelid AS table_id,
|
|
|
|
r.conname as constraint_name,
|
|
|
|
r.oid as constraint_oid,
|
|
|
|
cftn.nspname AS ref_table_table_schema,
|
|
|
|
cft.relname as ref_table,
|
|
|
|
r.confrelid as ref_table_id,
|
|
|
|
UNNEST (r.conkey) AS column_id,
|
|
|
|
UNNEST (r.confkey) AS ref_column_id
|
|
|
|
FROM
|
|
|
|
pg_catalog.pg_constraint r
|
|
|
|
JOIN pg_catalog.pg_class ct
|
|
|
|
ON r.conrelid = ct.oid
|
|
|
|
JOIN pg_catalog.pg_namespace ctn
|
|
|
|
ON ct.relnamespace = ctn.oid
|
|
|
|
JOIN pg_catalog.pg_class cft
|
|
|
|
ON r.confrelid = cft.oid
|
|
|
|
JOIN pg_catalog.pg_namespace cftn
|
|
|
|
ON cft.relnamespace = cftn.oid
|
|
|
|
WHERE
|
|
|
|
r.contype = 'f'
|
|
|
|
) q
|
|
|
|
JOIN pg_catalog.pg_attribute ac
|
|
|
|
ON q.column_id = ac.attnum
|
|
|
|
AND q.table_id = ac.attrelid
|
|
|
|
JOIN pg_catalog.pg_attribute afc
|
|
|
|
ON q.ref_column_id = afc.attnum
|
|
|
|
AND q.ref_table_id = afc.attrelid
|
|
|
|
GROUP BY q.table_schema, q.table_name, q.constraint_name
|
|
|
|
) foreign_key
|
2021-11-23 18:18:51 +03:00
|
|
|
GROUP BY foreign_key.table_schema, foreign_key.table_name
|
|
|
|
) foreign_key_constraints
|
2022-03-08 16:02:13 +03:00
|
|
|
ON "table".table_name = foreign_key_constraints.table_name
|
|
|
|
AND "table".table_schema = foreign_key_constraints.table_schema
|
2020-12-08 17:22:31 +03:00
|
|
|
|
|
|
|
-- all these identify table-like things
|
|
|
|
WHERE "table".relkind IN ('r', 't', 'v', 'm', 'f', 'p')
|
|
|
|
-- and tables not from any system schemas
|
2022-06-08 21:53:18 +03:00
|
|
|
AND "table".table_schema NOT LIKE 'pg\_%'
|
2022-03-08 16:02:13 +03:00
|
|
|
AND "table".table_schema NOT IN ('information_schema', 'hdb_catalog', 'hdb_lib', '_timescaledb_internal');
|