graphql-engine/server/src-rsr/pg_table_metadata.sql
paritosh-08 8c05efb6d9 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 10:10:35 +00:00

156 lines
6.2 KiB
SQL

SELECT
schema.nspname AS table_schema,
"table".relname AS table_name,
-- This field corresponds to the `DBTableMetadata` Haskell type
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, '[]'),
-- 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(
'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,
'description', description.description,
'extra_table_metadata', '[]'::json
)::json AS info
-- table & schema
FROM pg_catalog.pg_class "table"
JOIN pg_catalog.pg_namespace schema
ON schema.oid = "table".relnamespace
-- 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,
'type', coalesce(base_type.typname, "type".typname),
'is_nullable', NOT "column".attnotnull,
'is_identity', coalesce(("info_column".is_identity::boolean), false),
'description', pg_catalog.col_description("table".oid, "column".attnum)
)) AS info
FROM pg_catalog.pg_attribute "column"
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
LEFT JOIN information_schema.columns "info_column"
ON "info_column".column_name = "column".attname
AND "info_column".table_name = "table".relname
AND "info_column".table_schema = "schema".nspname
WHERE "column".attrelid = "table".oid
-- columns where attnum <= 0 are special, system-defined columns
AND "column".attnum > 0
-- dropped columns still exist in the system catalog as “zombie” columns, so ignore those
AND NOT "column".attisdropped
) columns ON true
-- primary key
LEFT JOIN LATERAL
( SELECT jsonb_build_object(
'constraint', jsonb_build_object('name', class.relname, 'oid', class.oid :: integer),
'columns', coalesce(columns.info, '[]')
) AS info
FROM pg_catalog.pg_index index
JOIN pg_catalog.pg_class class
ON class.oid = index.indexrelid
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 (index.indkey)
) AS columns ON true
WHERE index.indrelid = "table".oid
AND index.indisprimary
) primary_key ON true
-- unique constraints
LEFT JOIN LATERAL
( SELECT jsonb_agg(jsonb_build_object('name', class.relname, 'oid', class.oid :: integer)) AS info
FROM pg_catalog.pg_index index
JOIN pg_catalog.pg_class class
ON class.oid = index.indexrelid
WHERE index.indrelid = "table".oid
AND index.indisunique
AND NOT index.indisprimary
) unique_constraints ON true
-- foreign keys
LEFT JOIN LATERAL
( 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
)) AS info -- This field corresponds to the `PGForeignKeyMetadata` Haskell type
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
WHERE foreign_key.table_schema = schema.nspname
AND foreign_key.table_name = "table".relname
) foreign_key_constraints ON true
-- all these identify table-like things
WHERE "table".relkind IN ('r', 't', 'v', 'm', 'f', 'p')
-- and tables not from any system schemas
AND schema.nspname NOT LIKE 'pg_%'
AND schema.nspname NOT IN ('information_schema', 'hdb_catalog');