diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/__init__.py b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/__init__.py index 63980cc8d2b..76acc4a146b 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/__init__.py +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/__init__.py @@ -1957,6 +1957,15 @@ def _getSQL_existing(self, did, data, vid): if 'schema' not in data: data['schema'] = res['schema'] + if self.node_type == 'mview' and ( + old_data.get('dependsonextensions') is None or + data.get('dependsonextensions') is None + ): + old_data['dependsonextensions'] = \ + old_data.get('dependsonextensions') or [] + data['dependsonextensions'] = \ + data.get('dependsonextensions') or [] + # merge vacuum lists into one data['vacuum_data'] = {} data['vacuum_data']['changed'] = [] @@ -2026,6 +2035,12 @@ def _getSQL_new(self, data): if data.get('toast_autovacuum', False): data['vacuum_data'] += vacuum_toast + if self.node_type == 'mview' and ( + data.get('dependsonextensions') is None + ): + data['dependsonextensions'] = \ + data.get('dependsonextensions') or [] + # Privileges for aclcol in self.allowed_acls: if aclcol in data: diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.js b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.js index 022e53ef7a9..e3f3fd68f2b 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.js +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.js @@ -132,6 +132,7 @@ define('pgadmin.node.mview', [ }]); }, getSchema: function(treeNodeInfo, itemNodeData) { + let nodeObj = pgBrowser.Nodes['extension']; return new MViewSchema( (privileges)=>getNodePrivilegeRoleSchema('', treeNodeInfo, itemNodeData, privileges), ()=>getNodeVacuumSettingsSchema(this, treeNodeInfo, itemNodeData), @@ -142,6 +143,16 @@ define('pgadmin.node.mview', [ return (m.label != 'pg_global'); }), table_amname_list: ()=>getNodeAjaxOptions('get_access_methods', this, treeNodeInfo, itemNodeData), + extensionsList:()=>getNodeAjaxOptions('nodes', nodeObj, treeNodeInfo, itemNodeData, { cacheLevel: 'server'}, + (data)=>{ + let res = []; + if (data && _.isArray(data)) { + _.each(data, function(d) { + res.push({label: d.label, value: d.label, data: d}); + }); + } + return res; + }), nodeInfo: treeNodeInfo, }, { diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.ui.js b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.ui.js index f5875c949fe..e56620e77e1 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.ui.js +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/static/js/mview.ui.js @@ -106,7 +106,23 @@ export default class MViewSchema extends BaseUISchema { id: 'fillfactor', label: gettext('Fill factor'), group: gettext('Definition'), mode: ['edit', 'create'], noEmpty: false, type: 'int', controlProps: {min: 10, max: 100} - },{ + }, + { + id: 'dependsonextensions', + label: gettext('Depends on extensions'), + group: gettext('Definition'), + type: 'select', + options: this.fieldOptions.extensionsList, + controlProps: { + multiple: true, + allowClear: true, + allowSelectAll: true, + placeholder: gettext('Select the Depends on extensions...'), + }, + min_version: 130000, + mode: ['create', 'edit', 'properties'] + }, + { id: 'vacuum_settings_str', label: gettext('Storage settings'), type: 'multiline', group: gettext('Definition'), mode: ['properties'], },{ diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/create.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/create.sql new file mode 100644 index 00000000000..67b6111e02d --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/create.sql @@ -0,0 +1,57 @@ +{# ===================== Create new view ===================== #} +{% if display_comments %} +-- View: {{ data.schema }}.{{ data.name }} + +-- DROP MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(data.schema, data.name) }}; + +{% endif %} +{% if data.name and data.schema and data.definition %} +CREATE MATERIALIZED VIEW{% if add_not_exists_clause %} IF NOT EXISTS{% endif %} {{ conn|qtIdent(data.schema, data.name) }} +{% if data.default_amname and data.default_amname != data.amname %} +USING {{data.amname}} +{% elif not data.default_amname and data.amname %} +USING {{data.amname}} +{% endif %} +{% if(data.fillfactor or data.autovacuum_enabled in ('t', 'f') or data.toast_autovacuum_enabled in ('t', 'f') or data['vacuum_data']|length > 0) %} +{% set ns = namespace(add_comma=false) %} +WITH ( +{% if data.fillfactor %} + FILLFACTOR = {{ data.fillfactor }}{% set ns.add_comma = true%}{% endif %}{% if data.autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + autovacuum_enabled = {% if data.autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %}{% if data.toast_autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + toast.autovacuum_enabled = {% if data.toast_autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %} +{% for field in data['vacuum_data'] %} +{% if field.value is defined and field.value != '' and field.value != none %} +{% if ns.add_comma %}, +{% endif %} {{ field.name }} = {{ field.value|lower }}{% set ns.add_comma = true%}{% endif %}{% endfor %} +{{ '\n' }}) +{% endif %} +{% if data.spcname %}TABLESPACE {{ data.spcname }} +{% endif %}AS +{{ data.definition.rstrip(';') }} +{% if data.with_data %} +WITH DATA; +{% else %} +WITH NO DATA; +{% endif %} +{% if data.owner %} + +ALTER TABLE IF EXISTS {{ conn|qtIdent(data.schema, data.name) }} + OWNER TO {{ conn|qtIdent(data.owner) }}; +{% endif %} +{% if data.dependsonextensions %} +{% for ext in data.dependsonextensions %} + +ALTER MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endfor %} +{% endif %} +{% if data.comment %} + +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + IS {{ data.comment|qtLiteral(conn) }}; +{% endif %} +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/properties.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/properties.sql new file mode 100644 index 00000000000..ae9406471a6 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/properties.sql @@ -0,0 +1,118 @@ +{# ========================== Fetch Materialized View Properties ========================= #} +{% if (vid and datlastsysoid) or scid %} +SELECT + c.oid, + c.xmin, + c.relname AS name, + c.reltablespace AS spcoid, + c.relispopulated AS with_data, + CASE WHEN length(spcname::text) > 0 THEN spcname ELSE + (SELECT sp.spcname FROM pg_catalog.pg_database dtb + JOIN pg_catalog.pg_tablespace sp ON dtb.dattablespace=sp.oid + WHERE dtb.oid = {{ did }}::oid) + END as spcname, + (SELECT st.setting from pg_catalog.pg_show_all_settings() st + WHERE st.name = 'default_table_access_method') as default_amname, + c.relacl, + nsp.nspname as schema, + pg_catalog.pg_get_userbyid(c.relowner) AS owner, + description AS comment, + ( + SELECT array_agg(DISTINCT e.extname) + FROM pg_depend d + JOIN pg_extension e ON d.refobjid = e.oid + WHERE d.objid = c.oid + ) AS dependsonextensions, + pg_catalog.pg_get_viewdef(c.oid, true) AS definition, + {# ============= Checks if it is system view ================ #} + {% if vid and datlastsysoid %} + CASE WHEN {{vid}} <= {{datlastsysoid}} THEN True ELSE False END AS system_view, + {% endif %} + pg_catalog.array_to_string(c.relacl::text[], ', ') AS acl, + (SELECT pg_catalog.array_agg(provider || '=' || label) FROM pg_catalog.pg_seclabels sl1 WHERE sl1.objoid=c.oid AND sl1.objsubid=0) AS seclabels, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'fillfactor=([0-9]*)') AS fillfactor, + (substring(pg_catalog.array_to_string(c.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS autovacuum_enabled, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age, + (substring(pg_catalog.array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS toast_autovacuum_enabled, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age, + c.reloptions AS reloptions, tst.reloptions AS toast_reloptions, am.amname, + (CASE WHEN c.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable +FROM + pg_catalog.pg_class c +LEFT OUTER JOIN pg_catalog.pg_namespace nsp on nsp.oid = c.relnamespace +LEFT OUTER JOIN pg_catalog.pg_tablespace spc on spc.oid=c.reltablespace +LEFT OUTER JOIN pg_catalog.pg_description des ON (des.objoid=c.oid and des.objsubid=0 AND des.classoid='pg_class'::regclass) +LEFT OUTER JOIN pg_catalog.pg_class tst ON tst.oid = c.reltoastrelid +LEFT OUTER JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE ((c.relhasrules AND (EXISTS ( + SELECT + r.rulename + FROM + pg_catalog.pg_rewrite r + WHERE + ((r.ev_class = c.oid) + AND (pg_catalog.bpchar(r.ev_type) = '1'::bpchar)) ))) + AND (c.relkind = 'm'::char) + ) +{% if (vid and datlastsysoid) %} + AND c.oid = {{vid}}::oid +{% elif scid %} + AND c.relnamespace = {{scid}}::oid +ORDER BY + c.relname +{% endif %} + +{% elif type == 'roles' %} +SELECT + pr.rolname +FROM + pg_catalog.pg_roles pr +WHERE + pr.rolcanlogin +ORDER BY + pr.rolname + +{% elif type == 'schemas' %} +SELECT + nsp.nspname +FROM + pg_catalog.pg_namespace nsp +WHERE + (nsp.nspname NOT LIKE E'pg\\_%' + AND nsp.nspname != 'information_schema') +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/update.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/update.sql new file mode 100644 index 00000000000..2c2d3501cdf --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/update.sql @@ -0,0 +1,221 @@ +{# ===================== Update View ===================#} +{% import 'macros/schemas/security.macros' as SECLABEL %} +{% import 'macros/schemas/privilege.macros' as PRIVILEGE %} +{%- if data -%} +{% set view_name = data.name if data.name else o_data.name %} +{% set view_schema = data.schema if data.schema else o_data.schema %} +{% set def = data.definition.rstrip(';') if data.definition %} +{# ===== Rename mat view ===== #} +{% if data.name and data.name != o_data.name %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(o_data.schema, o_data.name) }} + RENAME TO {{ conn|qtIdent(data.name) }}; + +{% endif %} +{# ===== Alter schema view ===== #} +{% if data.schema and data.schema != o_data.schema %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(o_data.schema, view_name ) }} + SET SCHEMA {{ conn|qtIdent(data.schema) }}; + +{% endif %} +{# ===== Alter Table owner ===== #} +{% if data.owner and data.owner != o_data.owner %} +ALTER TABLE IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} + OWNER TO {{ conn|qtIdent(data.owner) }}; + +{% endif %} +{# ===== First Drop and then create mat view ===== #} +{% if def and def != o_data.definition.rstrip(';') %} +DROP MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }}; +CREATE MATERIALIZED VIEW IF NOT EXISTS {{ conn|qtIdent(view_schema, view_name) }} +{% if data.amname and data.amname != o_data.amname %} +USING {{ data.amname }} +{% endif %} +{% if data.fillfactor or o_data.fillfactor %} +WITH( +{% if data.fillfactor %} + FILLFACTOR = {{ data.fillfactor }}{% if (data['vacuum_data'] is defined and data['vacuum_data']['changed']|length > 0) %},{% endif %} +{% elif o_data.fillfactor %} + FILLFACTOR = {{ o_data.fillfactor }}{% if (data['vacuum_data'] is defined and data['vacuum_data']['changed']|length > 0) %},{% endif %} +{% endif %} + +{% if data['vacuum_data']['changed']|length > 0 %} +{% for field in data['vacuum_data']['changed'] %} {{ field.name }} = {{ field.value|lower }}{% if not loop.last %}, +{% endif %} +{% endfor %} +{% endif %} +) +{% endif %} + AS +{{ def }} +{% if data.with_data is defined %} + WITH {{ 'DATA' if data.with_data else 'NO DATA' }}; +{% elif o_data.with_data is defined %} + WITH {{ 'DATA' if o_data.with_data else 'NO DATA' }}; + +{% endif %} +{% if o_data.owner and not data.owner %} +ALTER TABLE IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} + OWNER TO {{ conn|qtIdent(o_data.owner) }}; + +{% endif %} +{% if o_data.comment and not data.comment %} +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + IS {{ o_data.comment|qtLiteral(conn) }}; +{% endif %} +{% else %} +{# ======= Alter Tablespace ========= #} +{%- if data.spcname and o_data.spcname != data.spcname -%} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} + SET TABLESPACE {{ data.spcname }}; + +{% endif %} +{# ======= SET/RESET Fillfactor ========= #} +{% if data.fillfactor and o_data.fillfactor != data.fillfactor %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} +SET( + FILLFACTOR = {{ data.fillfactor }} +); + +{% elif data.fillfactor == '' and o_data.fillfactor|default('', 'true') != data.fillfactor %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} +RESET( + FILLFACTOR +); + +{% endif %} +{# ===== Check for with_data property ===== #} +{% if data.with_data is defined and o_data.with_data|lower != data.with_data|lower %} +REFRESH MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} WITH{{ ' NO' if data.with_data|lower == 'false' else '' }} DATA; + +{% endif %} +{# ===== Check for Autovacuum options ===== #} +{% if data.autovacuum_custom is defined and data.autovacuum_custom == False %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} RESET( + autovacuum_enabled, + autovacuum_vacuum_threshold, + autovacuum_analyze_threshold, + autovacuum_vacuum_scale_factor, + autovacuum_analyze_scale_factor, + autovacuum_vacuum_cost_delay, + autovacuum_vacuum_cost_limit, + autovacuum_freeze_min_age, + autovacuum_freeze_max_age, + autovacuum_freeze_table_age +); + +{% endif %} + +{% if data.toast_autovacuum is defined and data.toast_autovacuum == False %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} RESET( + toast.autovacuum_enabled, + toast.autovacuum_vacuum_threshold, + toast.autovacuum_analyze_threshold, + toast.autovacuum_vacuum_scale_factor, + toast.autovacuum_analyze_scale_factor, + toast.autovacuum_vacuum_cost_delay, + toast.autovacuum_vacuum_cost_limit, + toast.autovacuum_freeze_min_age, + toast.autovacuum_freeze_max_age, + toast.autovacuum_freeze_table_age +); + +{% endif %}{#-- toast_endif ends --#} +{% if data['vacuum_data']['changed']|length > 0 or data.autovacuum_enabled in ('t', 'f') or data.toast_autovacuum_enabled in ('t', 'f') %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(data.schema, data.name) }} SET( +{% if data.autovacuum_enabled in ('t', 'f') %} + autovacuum_enabled = {% if data.autovacuum_enabled == 't' %}true{% else %}false{% endif %}{% if data['vacuum_data']['changed']|length > 0 or data.toast_autovacuum_enabled in ('t', 'f') %}, +{% endif %} +{% endif %} +{% if data.toast_autovacuum_enabled in ('t', 'f') %} + toast.autovacuum_enabled = {% if data.toast_autovacuum_enabled == 't' %}true{% else %}false{% endif %}{% if data['vacuum_data']['changed']|length > 0 %}, +{% endif %} +{% endif %} +{% for field in data['vacuum_data']['changed'] %} +{% if field.value != None %} {{ field.name }} = {{ field.value|lower }}{% if not loop.last %}, +{% endif %} +{% endif %} +{% endfor %} + +); +{% endif %} +{% if data['vacuum_data']['reset']|length > 0 or data.autovacuum_enabled == 'x' or data.toast_autovacuum_enabled == 'x' %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} RESET( +{% if data.autovacuum_enabled == 'x' %} + autovacuum_enabled{% if data['vacuum_data']['reset']|length > 0 or data.toast_autovacuum_enabled == 'x' %}, +{% endif %} +{% endif %} +{% if data.toast_autovacuum_enabled == 'x' %} + toast.autovacuum_enabled{% if data['vacuum_data']['reset']|length > 0 %}, +{% endif %} +{% endif %} +{% for field in data['vacuum_data']['reset'] %} {{ field.name }}{% if not loop.last %}, +{% endif %} +{% endfor %} + +); +{% endif %} +{# ===== End check for custom autovacuum ===== #} +{% endif %}{# ===== End block for check data definition ===== #} +{% set old_comment = o_data.comment|default('', true) %} +{% if (data.comment is defined and (data.comment != old_comment)) %} + +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + IS {{ data.comment|qtLiteral(conn) }}; +{% endif %} +{# ============= The SQL generated below will change privileges ============= #} +{% if data.datacl %} +{% if 'deleted' in data.datacl %} +{% for priv in data.datacl.deleted %} +{{ PRIVILEGE.UNSETALL(conn, 'TABLE', priv.grantee, data.name, data.schema) }} +{% endfor %} +{% endif %} +{% if 'changed' in data.datacl %} +{% for priv in data.datacl.changed -%} +{% if priv.grantee != priv.old_grantee %} +{{ PRIVILEGE.UNSETALL(conn, 'TABLE', priv.old_grantee, data.name, data.schema) }} +{% else %} +{{ PRIVILEGE.UNSETALL(conn, 'TABLE', priv.grantee, data.name, data.schema) }} +{% endif %} +{{ PRIVILEGE.SET(conn, 'TABLE', priv.grantee, data.name, priv.without_grant, priv.with_grant, data.schema) }} +{%- endfor %} +{% endif %} +{% if 'added' in data.datacl %} +{% for priv in data.datacl.added %} +{{ PRIVILEGE.SET(conn, 'TABLE', priv.grantee, data.name, priv.without_grant, priv.with_grant, data.schema) }} +{% endfor %} +{% endif %} +{% endif %} +{# ============== The SQL generated below will change Security Label ========= #} +{% if data.seclabels is not none and data.seclabels|length > 0 %} +{% set seclabels = data.seclabels %} +{% if 'deleted' in seclabels and seclabels.deleted|length > 0 %} +{% for r in seclabels.deleted %} +{{ SECLABEL.UNSET(conn, 'MATERIALIZED VIEW', data.name, r.provider, data.schema) }} +{% endfor %} +{% endif %} +{% if 'added' in seclabels and seclabels.added|length > 0 %} +{% for r in seclabels.added %} +{{ SECLABEL.SET(conn, 'MATERIALIZED VIEW', data.name, r.provider, r.label, data.schema) }} +{% endfor %} +{% endif %} +{% if 'changed' in seclabels and seclabels.changed|length > 0 %} +{% for r in seclabels.changed %} +{{ SECLABEL.SET(conn, 'MATERIALIZED VIEW', data.name, r.provider, r.label, data.schema) }} +{% endfor %} +{% endif %} +{% endif %} +{% set old_exts = (o_data.dependsonextensions or []) | list %} +{% set new_exts = data.dependsonextensions if 'dependsonextensions' in data else None %} +{% if new_exts is not none and old_exts != new_exts %} +{% for ext in (old_exts + new_exts) | unique %} + +{% if ext in new_exts and ext not in old_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% elif ext in old_exts and ext not in new_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + NO DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endif %} +{% endfor %} +{% endif %} +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/create.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/create.sql new file mode 100644 index 00000000000..67b6111e02d --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/create.sql @@ -0,0 +1,57 @@ +{# ===================== Create new view ===================== #} +{% if display_comments %} +-- View: {{ data.schema }}.{{ data.name }} + +-- DROP MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(data.schema, data.name) }}; + +{% endif %} +{% if data.name and data.schema and data.definition %} +CREATE MATERIALIZED VIEW{% if add_not_exists_clause %} IF NOT EXISTS{% endif %} {{ conn|qtIdent(data.schema, data.name) }} +{% if data.default_amname and data.default_amname != data.amname %} +USING {{data.amname}} +{% elif not data.default_amname and data.amname %} +USING {{data.amname}} +{% endif %} +{% if(data.fillfactor or data.autovacuum_enabled in ('t', 'f') or data.toast_autovacuum_enabled in ('t', 'f') or data['vacuum_data']|length > 0) %} +{% set ns = namespace(add_comma=false) %} +WITH ( +{% if data.fillfactor %} + FILLFACTOR = {{ data.fillfactor }}{% set ns.add_comma = true%}{% endif %}{% if data.autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + autovacuum_enabled = {% if data.autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %}{% if data.toast_autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + toast.autovacuum_enabled = {% if data.toast_autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %} +{% for field in data['vacuum_data'] %} +{% if field.value is defined and field.value != '' and field.value != none %} +{% if ns.add_comma %}, +{% endif %} {{ field.name }} = {{ field.value|lower }}{% set ns.add_comma = true%}{% endif %}{% endfor %} +{{ '\n' }}) +{% endif %} +{% if data.spcname %}TABLESPACE {{ data.spcname }} +{% endif %}AS +{{ data.definition.rstrip(';') }} +{% if data.with_data %} +WITH DATA; +{% else %} +WITH NO DATA; +{% endif %} +{% if data.owner %} + +ALTER TABLE IF EXISTS {{ conn|qtIdent(data.schema, data.name) }} + OWNER TO {{ conn|qtIdent(data.owner) }}; +{% endif %} +{% if data.dependsonextensions %} +{% for ext in data.dependsonextensions %} + +ALTER MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endfor %} +{% endif %} +{% if data.comment %} + +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + IS {{ data.comment|qtLiteral(conn) }}; +{% endif %} +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/properties.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/properties.sql new file mode 100644 index 00000000000..ae9406471a6 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/properties.sql @@ -0,0 +1,118 @@ +{# ========================== Fetch Materialized View Properties ========================= #} +{% if (vid and datlastsysoid) or scid %} +SELECT + c.oid, + c.xmin, + c.relname AS name, + c.reltablespace AS spcoid, + c.relispopulated AS with_data, + CASE WHEN length(spcname::text) > 0 THEN spcname ELSE + (SELECT sp.spcname FROM pg_catalog.pg_database dtb + JOIN pg_catalog.pg_tablespace sp ON dtb.dattablespace=sp.oid + WHERE dtb.oid = {{ did }}::oid) + END as spcname, + (SELECT st.setting from pg_catalog.pg_show_all_settings() st + WHERE st.name = 'default_table_access_method') as default_amname, + c.relacl, + nsp.nspname as schema, + pg_catalog.pg_get_userbyid(c.relowner) AS owner, + description AS comment, + ( + SELECT array_agg(DISTINCT e.extname) + FROM pg_depend d + JOIN pg_extension e ON d.refobjid = e.oid + WHERE d.objid = c.oid + ) AS dependsonextensions, + pg_catalog.pg_get_viewdef(c.oid, true) AS definition, + {# ============= Checks if it is system view ================ #} + {% if vid and datlastsysoid %} + CASE WHEN {{vid}} <= {{datlastsysoid}} THEN True ELSE False END AS system_view, + {% endif %} + pg_catalog.array_to_string(c.relacl::text[], ', ') AS acl, + (SELECT pg_catalog.array_agg(provider || '=' || label) FROM pg_catalog.pg_seclabels sl1 WHERE sl1.objoid=c.oid AND sl1.objsubid=0) AS seclabels, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'fillfactor=([0-9]*)') AS fillfactor, + (substring(pg_catalog.array_to_string(c.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS autovacuum_enabled, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age, + (substring(pg_catalog.array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS toast_autovacuum_enabled, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age, + c.reloptions AS reloptions, tst.reloptions AS toast_reloptions, am.amname, + (CASE WHEN c.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable +FROM + pg_catalog.pg_class c +LEFT OUTER JOIN pg_catalog.pg_namespace nsp on nsp.oid = c.relnamespace +LEFT OUTER JOIN pg_catalog.pg_tablespace spc on spc.oid=c.reltablespace +LEFT OUTER JOIN pg_catalog.pg_description des ON (des.objoid=c.oid and des.objsubid=0 AND des.classoid='pg_class'::regclass) +LEFT OUTER JOIN pg_catalog.pg_class tst ON tst.oid = c.reltoastrelid +LEFT OUTER JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE ((c.relhasrules AND (EXISTS ( + SELECT + r.rulename + FROM + pg_catalog.pg_rewrite r + WHERE + ((r.ev_class = c.oid) + AND (pg_catalog.bpchar(r.ev_type) = '1'::bpchar)) ))) + AND (c.relkind = 'm'::char) + ) +{% if (vid and datlastsysoid) %} + AND c.oid = {{vid}}::oid +{% elif scid %} + AND c.relnamespace = {{scid}}::oid +ORDER BY + c.relname +{% endif %} + +{% elif type == 'roles' %} +SELECT + pr.rolname +FROM + pg_catalog.pg_roles pr +WHERE + pr.rolcanlogin +ORDER BY + pr.rolname + +{% elif type == 'schemas' %} +SELECT + nsp.nspname +FROM + pg_catalog.pg_namespace nsp +WHERE + (nsp.nspname NOT LIKE E'pg\\_%' + AND nsp.nspname != 'information_schema') +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/update.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/update.sql index ca6ba22b2e5..5e0b0a2b6c4 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/update.sql +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/15_plus/sql/update.sql @@ -211,4 +211,19 @@ COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} {% endfor %} {% endif %} {% endif %} +{% set old_exts = (o_data.dependsonextensions or []) | list %} +{% set new_exts = data.dependsonextensions if 'dependsonextensions' in data else None %} +{% if new_exts is not none and old_exts != new_exts %} +{% for ext in (old_exts + new_exts) | unique %} + +{% if ext in new_exts and ext not in old_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% elif ext in old_exts and ext not in new_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + NO DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endif %} +{% endfor %} +{% endif %} + {% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/create.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/create.sql new file mode 100644 index 00000000000..3bea9ebfaac --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/create.sql @@ -0,0 +1,57 @@ +{# ===================== Create new view ===================== #} +{% if display_comments %} +-- View: {{ data.schema }}.{{ data.name }} + +-- DROP MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }}; + +{% endif %} +{% if data.name and data.schema and data.definition %} +CREATE MATERIALIZED VIEW{% if add_not_exists_clause %} IF NOT EXISTS{% endif %} {{ conn|qtIdent(data.schema, data.name) }} +{% if data.default_amname and data.default_amname != data.amname %} +USING {{data.amname}} +{% elif not data.default_amname and data.amname %} +USING {{data.amname}} +{% endif %} +{% if(data.fillfactor or data.autovacuum_enabled in ('t', 'f') or data.toast_autovacuum_enabled in ('t', 'f') or data['vacuum_data']|length > 0) %} +{% set ns = namespace(add_comma=false) %} +WITH ( +{% if data.fillfactor %} + FILLFACTOR = {{ data.fillfactor }}{% set ns.add_comma = true%}{% endif %}{% if data.autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + autovacuum_enabled = {% if data.autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %}{% if data.toast_autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + toast.autovacuum_enabled = {% if data.toast_autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %} +{% for field in data['vacuum_data'] %} +{% if field.value is defined and field.value != '' and field.value != none %} +{% if ns.add_comma %}, +{% endif %} {{ field.name }} = {{ field.value|lower }}{% set ns.add_comma = true%}{% endif %}{% endfor %} +{{ '\n' }}) +{% endif %} +{% if data.spcname %}TABLESPACE {{ data.spcname }} +{% endif %}AS +{{ data.definition.rstrip(';') }} +{% if data.with_data %} +WITH DATA; +{% else %} +WITH NO DATA; +{% endif %} +{% if data.owner %} + +ALTER TABLE IF EXISTS {{ conn|qtIdent(data.schema, data.name) }} + OWNER TO {{ conn|qtIdent(data.owner) }}; +{% endif %} +{% if data.dependsonextensions %} +{% for ext in data.dependsonextensions %} + +ALTER MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endfor %} +{% endif %} +{% if data.comment %} + +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + IS {{ data.comment|qtLiteral(conn) }}; +{% endif %} +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/properties.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/properties.sql new file mode 100644 index 00000000000..2d5c91a8d47 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/properties.sql @@ -0,0 +1,118 @@ +{# ========================== Fetch Materialized View Properties ========================= #} +{% if (vid and datlastsysoid) or scid %} +SELECT + c.oid, + c.xmin, + c.relname AS name, + c.reltablespace AS spcoid, + c.relispopulated AS with_data, + CASE WHEN length(spcname::text) > 0 THEN spcname ELSE + (SELECT sp.spcname FROM pg_catalog.pg_database dtb + JOIN pg_catalog.pg_tablespace sp ON dtb.dattablespace=sp.oid + WHERE dtb.oid = {{ did }}::oid) + END as spcname, + (SELECT st.setting from pg_catalog.pg_show_all_settings() st + WHERE st.name = 'default_table_access_method') as default_amname, + c.relacl, + nsp.nspname as schema, + pg_catalog.pg_get_userbyid(c.relowner) AS owner, + description AS comment, + ( + SELECT array_agg(DISTINCT e.extname) + FROM pg_depend d + JOIN pg_extension e ON d.refobjid = e.oid + WHERE d.objid = c.oid + ) AS dependsonextensions, + pg_catalog.pg_get_viewdef(c.oid) AS definition, + {# ============= Checks if it is system view ================ #} + {% if vid and datlastsysoid %} + CASE WHEN {{vid}} <= {{datlastsysoid}} THEN True ELSE False END AS system_view, + {% endif %} + pg_catalog.array_to_string(c.relacl::text[], ', ') AS acl, + (SELECT pg_catalog.array_agg(provider || '=' || label) FROM pg_catalog.pg_seclabels sl1 WHERE sl1.objoid=c.oid AND sl1.objsubid=0) AS seclabels, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'fillfactor=([0-9]*)') AS fillfactor, + (substring(pg_catalog.array_to_string(c.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS autovacuum_enabled, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age, + (substring(pg_catalog.array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS toast_autovacuum_enabled, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age, + c.reloptions AS reloptions, tst.reloptions AS toast_reloptions, am.amname, + (CASE WHEN c.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable +FROM + pg_catalog.pg_class c +LEFT OUTER JOIN pg_catalog.pg_namespace nsp on nsp.oid = c.relnamespace +LEFT OUTER JOIN pg_catalog.pg_tablespace spc on spc.oid=c.reltablespace +LEFT OUTER JOIN pg_catalog.pg_description des ON (des.objoid=c.oid and des.objsubid=0 AND des.classoid='pg_class'::regclass) +LEFT OUTER JOIN pg_catalog.pg_class tst ON tst.oid = c.reltoastrelid +LEFT OUTER JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE ((c.relhasrules AND (EXISTS ( + SELECT + r.rulename + FROM + pg_catalog.pg_rewrite r + WHERE + ((r.ev_class = c.oid) + AND (pg_catalog.bpchar(r.ev_type) = '1'::bpchar)) ))) + AND (c.relkind = 'm'::char) + ) +{% if (vid and datlastsysoid) %} + AND c.oid = {{vid}}::oid +{% elif scid %} + AND c.relnamespace = {{scid}}::oid +ORDER BY + c.relname +{% endif %} + +{% elif type == 'roles' %} +SELECT + pr.rolname +FROM + pg_catalog.pg_roles pr +WHERE + pr.rolcanlogin +ORDER BY + pr.rolname + +{% elif type == 'schemas' %} +SELECT + nsp.nspname +FROM + pg_catalog.pg_namespace nsp +WHERE + (nsp.nspname NOT LIKE E'pg\\_%' + AND nsp.nspname != 'information_schema') +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/update.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/update.sql new file mode 100644 index 00000000000..840135c546d --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/13_plus/sql/update.sql @@ -0,0 +1,221 @@ +{# ===================== Update View ===================#} +{% import 'macros/schemas/security.macros' as SECLABEL %} +{% import 'macros/schemas/privilege.macros' as PRIVILEGE %} +{%- if data -%} +{% set view_name = data.name if data.name else o_data.name %} +{% set view_schema = data.schema if data.schema else o_data.schema %} +{% set def = data.definition.rstrip(';') if data.definition %} +{# ===== Rename mat view ===== #} +{% if data.name and data.name != o_data.name %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(o_data.schema, o_data.name) }} + RENAME TO {{ conn|qtIdent(data.name) }}; + +{% endif %} +{# ===== Alter schema view ===== #} +{% if data.schema and data.schema != o_data.schema %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(o_data.schema, view_name ) }} + SET SCHEMA {{ conn|qtIdent(data.schema) }}; + +{% endif %} +{# ===== Alter Table owner ===== #} +{% if data.owner and data.owner != o_data.owner %} +ALTER TABLE IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} + OWNER TO {{ conn|qtIdent(data.owner) }}; + +{% endif %} +{# ===== First Drop and then create mat view ===== #} +{% if def and def != o_data.definition.rstrip(';') %} +DROP MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }}; +CREATE MATERIALIZED VIEW IF NOT EXISTS {{ conn|qtIdent(view_schema, view_name) }} +{% if data.amname and data.amname != o_data.amname %} +USING {{ data.amname }} +{% endif %} +{% if data.fillfactor or o_data.fillfactor %} +WITH( +{% if data.fillfactor %} + FILLFACTOR = {{ data.fillfactor }}{% if (data['vacuum_data'] is defined and data['vacuum_data']['changed']|length > 0) %},{% endif %} +{% elif o_data.fillfactor %} + FILLFACTOR = {{ o_data.fillfactor }}{% if (data['vacuum_data'] is defined and data['vacuum_data']['changed']|length > 0) %},{% endif %} +{% endif %} + +{% if data['vacuum_data']['changed']|length > 0 %} +{% for field in data['vacuum_data']['changed'] %} {{ field.name }} = {{ field.value|lower }}{% if not loop.last %}, +{% endif %} +{% endfor %} +{% endif %} +) +{% endif %} + AS +{{ def }} +{% if data.with_data is defined %} + WITH {{ 'DATA' if data.with_data else 'NO DATA' }}; +{% elif o_data.with_data is defined %} + WITH {{ 'DATA' if o_data.with_data else 'NO DATA' }}; + +{% endif %} +{% if o_data.owner and not data.owner %} +ALTER TABLE IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} + OWNER TO {{ conn|qtIdent(o_data.owner) }}; + +{% endif %} +{% if o_data.comment and not data.comment %} +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + IS {{ o_data.comment|qtLiteral(conn) }}; +{% endif %} +{% else %} +{# ======= Alter Tablespace ========= #} +{%- if data.spcoid and o_data.spcoid != data.spcoid -%} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} + SET TABLESPACE {{ data.spcoid }}; + +{% endif %} +{# ======= SET/RESET Fillfactor ========= #} +{% if data.fillfactor and o_data.fillfactor != data.fillfactor %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} +SET( + FILLFACTOR = {{ data.fillfactor }} +); + +{% elif data.fillfactor == '' and o_data.fillfactor|default('', 'true') != data.fillfactor %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} +RESET( + FILLFACTOR +); + +{% endif %} +{# ===== Check for with_data property ===== #} +{% if data.with_data is defined and o_data.with_data|lower != data.with_data|lower %} +REFRESH MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} WITH{{ ' NO' if data.with_data|lower == 'false' else '' }} DATA; + +{% endif %} +{# ===== Check for Autovacuum options ===== #} +{% if data.autovacuum_custom is defined and data.autovacuum_custom == False %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} RESET( + autovacuum_enabled, + autovacuum_vacuum_threshold, + autovacuum_analyze_threshold, + autovacuum_vacuum_scale_factor, + autovacuum_analyze_scale_factor, + autovacuum_vacuum_cost_delay, + autovacuum_vacuum_cost_limit, + autovacuum_freeze_min_age, + autovacuum_freeze_max_age, + autovacuum_freeze_table_age +); + +{% endif %} + +{% if data.toast_autovacuum is defined and data.toast_autovacuum == False %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} RESET( + toast.autovacuum_enabled, + toast.autovacuum_vacuum_threshold, + toast.autovacuum_analyze_threshold, + toast.autovacuum_vacuum_scale_factor, + toast.autovacuum_analyze_scale_factor, + toast.autovacuum_vacuum_cost_delay, + toast.autovacuum_vacuum_cost_limit, + toast.autovacuum_freeze_min_age, + toast.autovacuum_freeze_max_age, + toast.autovacuum_freeze_table_age +); + +{% endif %}{#-- toast_endif ends --#} +{% if data['vacuum_data']['changed']|length > 0 or data.autovacuum_enabled in ('t', 'f') or data.toast_autovacuum_enabled in ('t', 'f') %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(data.schema, data.name) }} SET( +{% if data.autovacuum_enabled in ('t', 'f') %} + autovacuum_enabled = {% if data.autovacuum_enabled == 't' %}true{% else %}false{% endif %}{% if data['vacuum_data']['changed']|length > 0 or data.toast_autovacuum_enabled in ('t', 'f') %}, +{% endif %} +{% endif %} +{% if data.toast_autovacuum_enabled in ('t', 'f') %} + toast.autovacuum_enabled = {% if data.toast_autovacuum_enabled == 't' %}true{% else %}false{% endif %}{% if data['vacuum_data']['changed']|length > 0 %}, +{% endif %} +{% endif %} +{% for field in data['vacuum_data']['changed'] %} +{% if field.value != None %} {{ field.name }} = {{ field.value|lower }}{% if not loop.last %}, +{% endif %} +{% endif %} +{% endfor %} + +); +{% endif %} +{% if data['vacuum_data']['reset']|length > 0 or data.autovacuum_enabled == 'x' or data.toast_autovacuum_enabled == 'x' %} +ALTER MATERIALIZED VIEW IF EXISTS {{ conn|qtIdent(view_schema, view_name) }} RESET( +{% if data.autovacuum_enabled == 'x' %} + autovacuum_enabled{% if data['vacuum_data']['reset']|length > 0 or data.toast_autovacuum_enabled == 'x' %}, +{% endif %} +{% endif %} +{% if data.toast_autovacuum_enabled == 'x' %} + toast.autovacuum_enabled{% if data['vacuum_data']['reset']|length > 0 %}, +{% endif %} +{% endif %} +{% for field in data['vacuum_data']['reset'] %} {{ field.name }}{% if not loop.last %}, +{% endif %} +{% endfor %} + +); +{% endif %} +{# ===== End check for custom autovacuum ===== #} +{% endif %}{# ===== End block for check data definition ===== #} +{% set old_comment = o_data.comment|default('', true) %} +{% if (data.comment is defined and (data.comment != old_comment)) %} + +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + IS {{ data.comment|qtLiteral(conn) }}; +{% endif %} +{# ============= The SQL generated below will change privileges ============= #} +{% if data.datacl %} +{% if 'deleted' in data.datacl %} +{% for priv in data.datacl.deleted %} +{{ PRIVILEGE.UNSETALL(conn, 'TABLE', priv.grantee, data.name, data.schema) }} +{% endfor %} +{% endif %} +{% if 'changed' in data.datacl %} +{% for priv in data.datacl.changed -%} +{% if priv.grantee != priv.old_grantee %} +{{ PRIVILEGE.UNSETALL(conn, 'TABLE', priv.old_grantee, data.name, data.schema) }} +{% else %} +{{ PRIVILEGE.UNSETALL(conn, 'TABLE', priv.grantee, data.name, data.schema) }} +{% endif %} +{{ PRIVILEGE.SET(conn, 'TABLE', priv.grantee, data.name, priv.without_grant, priv.with_grant, data.schema) }} +{%- endfor %} +{% endif %} +{% if 'added' in data.datacl %} +{% for priv in data.datacl.added %} +{{ PRIVILEGE.SET(conn, 'TABLE', priv.grantee, data.name, priv.without_grant, priv.with_grant, data.schema) }} +{% endfor %} +{% endif %} +{% endif %} +{# ============== The SQL generated below will change Security Label ========= #} +{% if data.seclabels is not none and data.seclabels|length > 0 %} +{% set seclabels = data.seclabels %} +{% if 'deleted' in seclabels and seclabels.deleted|length > 0 %} +{% for r in seclabels.deleted %} +{{ SECLABEL.UNSET(conn, 'MATERIALIZED VIEW', data.name, r.provider, data.schema) }} +{% endfor %} +{% endif %} +{% if 'added' in seclabels and seclabels.added|length > 0 %} +{% for r in seclabels.added %} +{{ SECLABEL.SET(conn, 'MATERIALIZED VIEW', data.name, r.provider, r.label, data.schema) }} +{% endfor %} +{% endif %} +{% if 'changed' in seclabels and seclabels.changed|length > 0 %} +{% for r in seclabels.changed %} +{{ SECLABEL.SET(conn, 'MATERIALIZED VIEW', data.name, r.provider, r.label, data.schema) }} +{% endfor %} +{% endif %} +{% endif %} +{% set old_exts = (o_data.dependsonextensions or []) | list %} +{% set new_exts = data.dependsonextensions if 'dependsonextensions' in data else None %} +{% if new_exts is not none and old_exts != new_exts %} +{% for ext in (old_exts + new_exts) | unique %} + +{% if ext in new_exts and ext not in old_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% elif ext in old_exts and ext not in new_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + NO DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endif %} +{% endfor %} +{% endif %} +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/create.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/create.sql new file mode 100644 index 00000000000..3bea9ebfaac --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/create.sql @@ -0,0 +1,57 @@ +{# ===================== Create new view ===================== #} +{% if display_comments %} +-- View: {{ data.schema }}.{{ data.name }} + +-- DROP MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }}; + +{% endif %} +{% if data.name and data.schema and data.definition %} +CREATE MATERIALIZED VIEW{% if add_not_exists_clause %} IF NOT EXISTS{% endif %} {{ conn|qtIdent(data.schema, data.name) }} +{% if data.default_amname and data.default_amname != data.amname %} +USING {{data.amname}} +{% elif not data.default_amname and data.amname %} +USING {{data.amname}} +{% endif %} +{% if(data.fillfactor or data.autovacuum_enabled in ('t', 'f') or data.toast_autovacuum_enabled in ('t', 'f') or data['vacuum_data']|length > 0) %} +{% set ns = namespace(add_comma=false) %} +WITH ( +{% if data.fillfactor %} + FILLFACTOR = {{ data.fillfactor }}{% set ns.add_comma = true%}{% endif %}{% if data.autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + autovacuum_enabled = {% if data.autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %}{% if data.toast_autovacuum_enabled in ('t', 'f') %} +{% if ns.add_comma %}, +{% endif %} + toast.autovacuum_enabled = {% if data.toast_autovacuum_enabled == 't' %}TRUE{% else %}FALSE{% endif %}{% set ns.add_comma = true%}{% endif %} +{% for field in data['vacuum_data'] %} +{% if field.value is defined and field.value != '' and field.value != none %} +{% if ns.add_comma %}, +{% endif %} {{ field.name }} = {{ field.value|lower }}{% set ns.add_comma = true%}{% endif %}{% endfor %} +{{ '\n' }}) +{% endif %} +{% if data.spcname %}TABLESPACE {{ data.spcname }} +{% endif %}AS +{{ data.definition.rstrip(';') }} +{% if data.with_data %} +WITH DATA; +{% else %} +WITH NO DATA; +{% endif %} +{% if data.owner %} + +ALTER TABLE IF EXISTS {{ conn|qtIdent(data.schema, data.name) }} + OWNER TO {{ conn|qtIdent(data.owner) }}; +{% endif %} +{% if data.dependsonextensions %} +{% for ext in data.dependsonextensions %} + +ALTER MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endfor %} +{% endif %} +{% if data.comment %} + +COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(data.schema, data.name) }} + IS {{ data.comment|qtLiteral(conn) }}; +{% endif %} +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/properties.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/properties.sql new file mode 100644 index 00000000000..2d5c91a8d47 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/properties.sql @@ -0,0 +1,118 @@ +{# ========================== Fetch Materialized View Properties ========================= #} +{% if (vid and datlastsysoid) or scid %} +SELECT + c.oid, + c.xmin, + c.relname AS name, + c.reltablespace AS spcoid, + c.relispopulated AS with_data, + CASE WHEN length(spcname::text) > 0 THEN spcname ELSE + (SELECT sp.spcname FROM pg_catalog.pg_database dtb + JOIN pg_catalog.pg_tablespace sp ON dtb.dattablespace=sp.oid + WHERE dtb.oid = {{ did }}::oid) + END as spcname, + (SELECT st.setting from pg_catalog.pg_show_all_settings() st + WHERE st.name = 'default_table_access_method') as default_amname, + c.relacl, + nsp.nspname as schema, + pg_catalog.pg_get_userbyid(c.relowner) AS owner, + description AS comment, + ( + SELECT array_agg(DISTINCT e.extname) + FROM pg_depend d + JOIN pg_extension e ON d.refobjid = e.oid + WHERE d.objid = c.oid + ) AS dependsonextensions, + pg_catalog.pg_get_viewdef(c.oid) AS definition, + {# ============= Checks if it is system view ================ #} + {% if vid and datlastsysoid %} + CASE WHEN {{vid}} <= {{datlastsysoid}} THEN True ELSE False END AS system_view, + {% endif %} + pg_catalog.array_to_string(c.relacl::text[], ', ') AS acl, + (SELECT pg_catalog.array_agg(provider || '=' || label) FROM pg_catalog.pg_seclabels sl1 WHERE sl1.objoid=c.oid AND sl1.objsubid=0) AS seclabels, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'fillfactor=([0-9]*)') AS fillfactor, + (substring(pg_catalog.array_to_string(c.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS autovacuum_enabled, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(c.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS autovacuum_freeze_table_age, + (substring(pg_catalog.array_to_string(tst.reloptions, ',') FROM 'autovacuum_enabled=([a-z|0-9]*)'))::BOOL AS toast_autovacuum_enabled, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_threshold=([0-9]*)') AS toast_autovacuum_vacuum_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_vacuum_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_threshold=([0-9]*)') AS toast_autovacuum_analyze_threshold, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_analyze_scale_factor=([0-9]*[.]?[0-9]*)') AS toast_autovacuum_analyze_scale_factor, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_delay=([0-9]*)') AS toast_autovacuum_vacuum_cost_delay, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_vacuum_cost_limit=([0-9]*)') AS toast_autovacuum_vacuum_cost_limit, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_min_age=([0-9]*)') AS toast_autovacuum_freeze_min_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_max_age=([0-9]*)') AS toast_autovacuum_freeze_max_age, + substring(pg_catalog.array_to_string(tst.reloptions, ',') + FROM 'autovacuum_freeze_table_age=([0-9]*)') AS toast_autovacuum_freeze_table_age, + c.reloptions AS reloptions, tst.reloptions AS toast_reloptions, am.amname, + (CASE WHEN c.reltoastrelid = 0 THEN false ELSE true END) AS hastoasttable +FROM + pg_catalog.pg_class c +LEFT OUTER JOIN pg_catalog.pg_namespace nsp on nsp.oid = c.relnamespace +LEFT OUTER JOIN pg_catalog.pg_tablespace spc on spc.oid=c.reltablespace +LEFT OUTER JOIN pg_catalog.pg_description des ON (des.objoid=c.oid and des.objsubid=0 AND des.classoid='pg_class'::regclass) +LEFT OUTER JOIN pg_catalog.pg_class tst ON tst.oid = c.reltoastrelid +LEFT OUTER JOIN pg_catalog.pg_am am ON am.oid = c.relam + WHERE ((c.relhasrules AND (EXISTS ( + SELECT + r.rulename + FROM + pg_catalog.pg_rewrite r + WHERE + ((r.ev_class = c.oid) + AND (pg_catalog.bpchar(r.ev_type) = '1'::bpchar)) ))) + AND (c.relkind = 'm'::char) + ) +{% if (vid and datlastsysoid) %} + AND c.oid = {{vid}}::oid +{% elif scid %} + AND c.relnamespace = {{scid}}::oid +ORDER BY + c.relname +{% endif %} + +{% elif type == 'roles' %} +SELECT + pr.rolname +FROM + pg_catalog.pg_roles pr +WHERE + pr.rolcanlogin +ORDER BY + pr.rolname + +{% elif type == 'schemas' %} +SELECT + nsp.nspname +FROM + pg_catalog.pg_namespace nsp +WHERE + (nsp.nspname NOT LIKE E'pg\\_%' + AND nsp.nspname != 'information_schema') +{% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/update.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/update.sql index 6661e105440..f379047c409 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/update.sql +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/ppas/15_plus/sql/update.sql @@ -211,4 +211,18 @@ COMMENT ON MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} {% endfor %} {% endif %} {% endif %} +{% set old_exts = (o_data.dependsonextensions or []) | list %} +{% set new_exts = data.dependsonextensions if 'dependsonextensions' in data else None %} +{% if new_exts is not none and old_exts != new_exts %} +{% for ext in (old_exts + new_exts) | unique %} + +{% if ext in new_exts and ext not in old_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% elif ext in old_exts and ext not in new_exts %} +ALTER MATERIALIZED VIEW {{ conn|qtIdent(view_schema, view_name) }} + NO DEPENDS ON EXTENSION {{ conn|qtIdent(ext) }}; +{% endif %} +{% endfor %} +{% endif %} {% endif %} diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/create_mview_with_am.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/create_mview_with_am.sql new file mode 100644 index 00000000000..39d07b539a4 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/create_mview_with_am.sql @@ -0,0 +1,15 @@ +-- View: public.testmview_am_$%{}[]()&*^!/@`# + +-- DROP MATERIALIZED VIEW IF EXISTS public."testmview_am_$%{}[]()&*^!/@`#"; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public."testmview_am_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS + SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_am_$%{}[]()&*^!/@`#" + OWNER TO postgres; + +COMMENT ON MATERIALIZED VIEW public."testmview_am_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/test_mview.json index 146fb124100..a8bf5ef7d1d 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/test_mview.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/12_plus/test_mview.json @@ -272,7 +272,8 @@ "definition": "SELECT 1 AS col1", "amname": "heap" }, - "expected_msql_file": "create_mview_with_am_msql.sql" + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" } ] } diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/alter_mview_no_depends.msql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/alter_mview_no_depends.msql new file mode 100644 index 00000000000..5285163e9ee --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/alter_mview_no_depends.msql @@ -0,0 +1,2 @@ +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + NO DEPENDS ON EXTENSION postgres_fdw; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/alter_mview_no_depends.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/alter_mview_no_depends.sql new file mode 100644 index 00000000000..a16142a0fc1 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/alter_mview_no_depends.sql @@ -0,0 +1,18 @@ +-- View: public.testmview_$%{}[]()&*^!/@`# + +-- DROP MATERIALIZED VIEW IF EXISTS public."testmview_$%{}[]()&*^!/@`#"; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public."testmview_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS + SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_$%{}[]()&*^!/@`#" + OWNER TO postgres; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION plpgsql; + +COMMENT ON MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/create_mview_no_depends.msql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/create_mview_no_depends.msql new file mode 100644 index 00000000000..c986e30a474 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/create_mview_no_depends.msql @@ -0,0 +1,17 @@ +CREATE MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS +SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_$%{}[]()&*^!/@`#" + OWNER TO postgres; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION plpgsql; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION postgres_fdw; + +COMMENT ON MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/create_mview_no_depends.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/create_mview_no_depends.sql new file mode 100644 index 00000000000..6b0ad596eda --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/create_mview_no_depends.sql @@ -0,0 +1,21 @@ +-- View: public.testmview_$%{}[]()&*^!/@`# + +-- DROP MATERIALIZED VIEW IF EXISTS public."testmview_$%{}[]()&*^!/@`#"; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public."testmview_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS + SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_$%{}[]()&*^!/@`#" + OWNER TO postgres; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION plpgsql; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION postgres_fdw; + +COMMENT ON MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/test_mview.json new file mode 100644 index 00000000000..05f3415e6f3 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/13_plus/test_mview.json @@ -0,0 +1,341 @@ +{ + "scenarios": [ + { + "type": "create", + "name": "Create Extension", + "endpoint": "NODE-extension.obj", + "sql_endpoint": "NODE-extension.sql_id", + "data": { + "name": "postgres_fdw", + "version": "", + "relocatable": true + }, + "store_object_id": true + }, + { + "type": "create", + "name": "Create Materialised Views with extensions.", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "postgres", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "dependsonextensions": ["plpgsql", "postgres_fdw"] + }, + "expected_sql_file": "create_mview_no_depends.sql", + "expected_msql_file": "create_mview_no_depends.msql" + }, + { + "type": "alter", + "name": "Alter Materialised Views with NO DEPENDS ON", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "dependsonextensions": ["plpgsql"] + }, + "expected_sql_file": "alter_mview_no_depends.sql", + "expected_msql_file": "alter_mview_no_depends.msql" + }, + { + "type": "delete", + "name": "Drop Materialised Views", + "endpoint": "NODE-mview.delete_id", + "data": { + } + }, + { + "type": "delete", + "name": "Drop Extension", + "endpoint": "NODE-extension.delete", + "data": { + "ids": [""] + }, + "preprocess_data": true + }, + { + "type": "create", + "name": "Create Materialised Views", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "postgres", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1" + }, + "expected_sql_file": "create_mview.sql", + "expected_msql_file": "create_mview_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (Adding privileges)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "datacl": { + "added": [ + { + "grantee": "PUBLIC", + "grantor": "postgres", + "privileges": [ + { + "privilege_type": "a", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "r", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "w", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "d", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "D", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "x", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "t", + "privilege": true, + "with_grant": false + } + ] + } + ] + } + }, + "expected_sql_file": "alter_mview.sql", + "expected_msql_file": "alter_mview_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (Remove all privileges)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "datacl": { + "deleted": [ + { + "grantee": "PUBLIC", + "grantor": "postgres", + "privileges": [ + { + "privilege_type": "a", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "r", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "w", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "d", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "D", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "x", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "t", + "privilege": true, + "with_grant": false + } + ] + } + ] + } + }, + "expected_sql_file": "alter_mview_drop_all_priv.sql", + "expected_msql_file": "alter_mview_drop_all_priv_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (change grantee in privileges)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "datacl": { + "changed": [ + { + "grantee": "PUBLIC", + "grantor": "postgres", + "old_grantee": "postgres", + "privileges": [ + { + "privilege_type": "a", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "r", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "w", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "d", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "D", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "x", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "t", + "privilege": true, + "with_grant": false + } + ] + } + ] + } + }, + "expected_sql_file": "alter_mview_change_grantee_priv.sql", + "expected_msql_file": "alter_mview_change_grantee_priv_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (change definition)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "definition": "SELECT 12 AS col1;" + }, + "expected_sql_file": "alter_mview_definition.sql", + "expected_msql_file": "alter_mview_definition_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (Fillfactor)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "fillfactor": "18", + "with_data": true + }, + "expected_sql_file": "alter_mview_add_fillfactor.sql", + "expected_msql_file": "alter_mview_add_fillfactor_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (add table parameters)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "autovacuum_custom": true, + "autovacuum_enabled": "t", + "vacuum_table": { + "changed": [ + { + "name": "autovacuum_analyze_scale_factor", + "value": 0.2 + } + ] + } + }, + "expected_sql_file": "alter_mview_add_table_parameter.sql", + "expected_msql_file": "alter_mview_add_table_parameter_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (remove table parameters)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "autovacuum_custom": true, + "autovacuum_enabled": "x", + "vacuum_table": { + "changed": [ + { + "name": "autovacuum_analyze_scale_factor", + "value": null + } + ] + } + }, + "expected_sql_file": "alter_mview_remove_table_parameter.sql", + "expected_msql_file": "alter_mview_remove_table_parameter_msql.sql" + }, + { + "type": "create", + "name": "Create Materialised Views with access method", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "postgres", + "datacl": [], + "seclabels": [], + "name": "testmview_am_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "amname": "heap" + }, + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" + + } + ] + } + \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/15_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/15_plus/test_mview.json index 0141eec0e1c..1a97f355907 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/15_plus/test_mview.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/15_plus/test_mview.json @@ -1,5 +1,65 @@ { "scenarios": [ + { + "type": "create", + "name": "Create Extension", + "endpoint": "NODE-extension.obj", + "sql_endpoint": "NODE-extension.sql_id", + "data": { + "name": "postgres_fdw", + "version": "", + "relocatable": true + }, + "store_object_id": true + }, + { + "type": "create", + "name": "Create Materialised Views with extensions.", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "postgres", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "dependsonextensions": ["plpgsql", "postgres_fdw"] + }, + "expected_sql_file": "create_mview_no_depends.sql", + "expected_msql_file": "create_mview_no_depends.msql" + }, + { + "type": "alter", + "name": "Alter Materialised Views with NO DEPENDS.", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "dependsonextensions": ["plpgsql"] + }, + "expected_sql_file": "alter_mview_no_depends.sql", + "expected_msql_file": "alter_mview_no_depends.msql" + }, + { + "type": "delete", + "name": "Drop Materialised Views", + "endpoint": "NODE-mview.delete_id", + "data": { + } + }, + { + "type": "delete", + "name": "Drop Extension", + "endpoint": "NODE-extension.delete", + "data": { + "ids": [""] + }, + "preprocess_data": true + }, { "type": "create", "name": "Create Materialised Views", @@ -272,7 +332,8 @@ "definition": "SELECT 1 AS col1", "amname": "heap" }, - "expected_msql_file": "create_mview_with_am_msql.sql" + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" } ] } diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/16_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/16_plus/test_mview.json index 0141eec0e1c..52352f1cf87 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/16_plus/test_mview.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/pg/16_plus/test_mview.json @@ -1,5 +1,65 @@ { "scenarios": [ + { + "type": "create", + "name": "Create Extension", + "endpoint": "NODE-extension.obj", + "sql_endpoint": "NODE-extension.sql_id", + "data": { + "name": "postgres_fdw", + "version": "", + "relocatable": true + }, + "store_object_id": true + }, + { + "type": "create", + "name": "Create Materialised Views with extensions.", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "postgres", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "dependsonextensions": ["plpgsql", "postgres_fdw"] + }, + "expected_sql_file": "create_mview_no_depends.sql", + "expected_msql_file": "create_mview_no_depends.msql" + }, + { + "type": "alter", + "name": "Alter Materialised Views with NO DEPENDS.", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "dependsonextensions": ["plpgsql"] + }, + "expected_sql_file": "alter_mview_no_depends.sql", + "expected_msql_file": "alter_mview_no_depends.msql" + }, + { + "type": "delete", + "name": "Drop Materialised Views", + "endpoint": "NODE-mview.delete_id", + "data": { + } + }, + { + "type": "delete", + "name": "Drop Extension", + "endpoint": "NODE-extension.delete", + "data": { + "ids": [""] + }, + "preprocess_data": true + }, { "type": "create", "name": "Create Materialised Views", @@ -272,7 +332,8 @@ "definition": "SELECT 1 AS col1", "amname": "heap" }, - "expected_msql_file": "create_mview_with_am_msql.sql" + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" } ] } diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/create_mview_with_am.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/create_mview_with_am.sql new file mode 100644 index 00000000000..dc2495d5f51 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/create_mview_with_am.sql @@ -0,0 +1,15 @@ +-- View: public.testmview_am_$%{}[]()&*^!/@`# + +-- DROP MATERIALIZED VIEW public."testmview_am_$%{}[]()&*^!/@`#"; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public."testmview_am_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS + SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_am_$%{}[]()&*^!/@`#" + OWNER TO enterprisedb; + +COMMENT ON MATERIALIZED VIEW public."testmview_am_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/test_mview.json index ed01fea1993..2dc012bf264 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/test_mview.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/12_plus/test_mview.json @@ -272,7 +272,8 @@ "definition": "SELECT 1 AS col1", "amname": "heap" }, - "expected_msql_file": "create_mview_with_am_msql.sql" + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" } ] } diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/alter_mview_no_depends.msql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/alter_mview_no_depends.msql new file mode 100644 index 00000000000..5285163e9ee --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/alter_mview_no_depends.msql @@ -0,0 +1,2 @@ +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + NO DEPENDS ON EXTENSION postgres_fdw; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/alter_mview_no_depends.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/alter_mview_no_depends.sql new file mode 100644 index 00000000000..864379ca086 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/alter_mview_no_depends.sql @@ -0,0 +1,18 @@ +-- View: public.testmview_$%{}[]()&*^!/@`# + +-- DROP MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#"; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public."testmview_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS + SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_$%{}[]()&*^!/@`#" + OWNER TO enterprisedb; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION plpgsql; + +COMMENT ON MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/create_mview_no_depends.msql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/create_mview_no_depends.msql new file mode 100644 index 00000000000..770f48c130c --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/create_mview_no_depends.msql @@ -0,0 +1,17 @@ +CREATE MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS +SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_$%{}[]()&*^!/@`#" + OWNER TO enterprisedb; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION plpgsql; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION postgres_fdw; + +COMMENT ON MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/create_mview_no_depends.sql b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/create_mview_no_depends.sql new file mode 100644 index 00000000000..ccd6c5f2d84 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/create_mview_no_depends.sql @@ -0,0 +1,21 @@ +-- View: public.testmview_$%{}[]()&*^!/@`# + +-- DROP MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#"; + +CREATE MATERIALIZED VIEW IF NOT EXISTS public."testmview_$%{}[]()&*^!/@`#" +TABLESPACE pg_default +AS + SELECT 1 AS col1 +WITH NO DATA; + +ALTER TABLE IF EXISTS public."testmview_$%{}[]()&*^!/@`#" + OWNER TO enterprisedb; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION plpgsql; + +ALTER MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + DEPENDS ON EXTENSION postgres_fdw; + +COMMENT ON MATERIALIZED VIEW public."testmview_$%{}[]()&*^!/@`#" + IS 'comment1'; \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/test_mview.json new file mode 100644 index 00000000000..f73dd28fd21 --- /dev/null +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/13_plus/test_mview.json @@ -0,0 +1,340 @@ +{ + "scenarios": [ + { + "type": "create", + "name": "Create Extension", + "endpoint": "NODE-extension.obj", + "sql_endpoint": "NODE-extension.sql_id", + "data": { + "name": "postgres_fdw", + "version": "", + "relocatable": true + }, + "store_object_id": true + }, + { + "type": "create", + "name": "Create Materialised Views with extensions.", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "enterprisedb", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "dependsonextensions": ["plpgsql", "postgres_fdw"] + }, + "expected_sql_file": "create_mview_no_depends.sql", + "expected_msql_file": "create_mview_no_depends.msql" + }, + { + "type": "alter", + "name": "Alter Materialised Views with NO DEPENDS ON.", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "dependsonextensions": ["plpgsql"] + }, + "expected_sql_file": "alter_mview_no_depends.sql", + "expected_msql_file": "alter_mview_no_depends.msql" + }, + { + "type": "delete", + "name": "Drop Materialised Views", + "endpoint": "NODE-mview.delete_id", + "data": { + } + }, + { + "type": "delete", + "name": "Drop Extension", + "endpoint": "NODE-extension.delete", + "data": { + "ids": [""] + }, + "preprocess_data": true + }, + { + "type": "create", + "name": "Create Materialised Views", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "enterprisedb", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1" + }, + "expected_sql_file": "create_mview.sql", + "expected_msql_file": "create_mview_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (Adding privileges)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "datacl": { + "added": [ + { + "grantee": "PUBLIC", + "grantor": "enterprisedb", + "privileges": [ + { + "privilege_type": "a", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "r", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "w", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "d", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "D", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "x", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "t", + "privilege": true, + "with_grant": false + } + ] + } + ] + } + }, + "expected_sql_file": "alter_mview.sql", + "expected_msql_file": "alter_mview_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (Remove all privileges)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "datacl": { + "deleted": [ + { + "grantee": "PUBLIC", + "grantor": "enterprisedb", + "privileges": [ + { + "privilege_type": "a", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "r", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "w", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "d", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "D", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "x", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "t", + "privilege": true, + "with_grant": false + } + ] + } + ] + } + }, + "expected_sql_file": "alter_mview_drop_all_priv.sql", + "expected_msql_file": "alter_mview_drop_all_priv_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (change grantee in privileges)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "datacl": { + "changed": [ + { + "grantee": "PUBLIC", + "grantor": "enterprisedb", + "old_grantee": "enterprisedb", + "privileges": [ + { + "privilege_type": "a", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "r", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "w", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "d", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "D", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "x", + "privilege": true, + "with_grant": false + }, + { + "privilege_type": "t", + "privilege": true, + "with_grant": false + } + ] + } + ] + } + }, + "expected_sql_file": "alter_mview_change_grantee_priv.sql", + "expected_msql_file": "alter_mview_change_grantee_priv_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (change definition)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "definition": "SELECT 12 AS col1;" + }, + "expected_sql_file": "alter_mview_definition.sql", + "expected_msql_file": "alter_mview_definition_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (Fillfactor)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "fillfactor": "18", + "with_data": true + }, + "expected_sql_file": "alter_mview_add_fillfactor.sql", + "expected_msql_file": "alter_mview_add_fillfactor_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (add table parameters)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "autovacuum_custom": true, + "autovacuum_enabled": "t", + "vacuum_table": { + "changed": [ + { + "name": "autovacuum_analyze_scale_factor", + "value": 0.2 + } + ] + } + }, + "expected_sql_file": "alter_mview_add_table_parameter.sql", + "expected_msql_file": "alter_mview_add_table_parameter_msql.sql" + }, + { + "type": "alter", + "name": "Alter Materialised Views (remove table parameters)", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "autovacuum_custom": true, + "autovacuum_enabled": "x", + "vacuum_table": { + "changed": [ + { + "name": "autovacuum_analyze_scale_factor", + "value": null + } + ] + } + }, + "expected_sql_file": "alter_mview_remove_table_parameter.sql", + "expected_msql_file": "alter_mview_remove_table_parameter_msql.sql" + }, + { + "type": "create", + "name": "Create Materialised Views with access method", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "enterprisedb", + "datacl": [], + "seclabels": [], + "name": "testmview_am_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "amname": "heap" + }, + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" + } + ] + } + \ No newline at end of file diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/15_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/15_plus/test_mview.json index 5969e3cfac0..9e18388d61a 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/15_plus/test_mview.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/15_plus/test_mview.json @@ -1,5 +1,65 @@ { "scenarios": [ + { + "type": "create", + "name": "Create Extension", + "endpoint": "NODE-extension.obj", + "sql_endpoint": "NODE-extension.sql_id", + "data": { + "name": "postgres_fdw", + "version": "", + "relocatable": true + }, + "store_object_id": true + }, + { + "type": "create", + "name": "Create Materialised Views with extensions.", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "enterprisedb", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "dependsonextensions": ["plpgsql", "postgres_fdw"] + }, + "expected_sql_file": "create_mview_no_depends.sql", + "expected_msql_file": "create_mview_no_depends.msql" + }, + { + "type": "alter", + "name": "Alter Materialised Views with NO DEPENDS ON.", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "dependsonextensions": ["plpgsql"] + }, + "expected_sql_file": "alter_mview_no_depends.sql", + "expected_msql_file": "alter_mview_no_depends.msql" + }, + { + "type": "delete", + "name": "Drop Materialised Views", + "endpoint": "NODE-mview.delete_id", + "data": { + } + }, + { + "type": "delete", + "name": "Drop Extension", + "endpoint": "NODE-extension.delete", + "data": { + "ids": [""] + }, + "preprocess_data": true + }, { "type": "create", "name": "Create Materialised Views", @@ -272,7 +332,8 @@ "definition": "SELECT 1 AS col1", "amname": "heap" }, - "expected_msql_file": "create_mview_with_am_msql.sql" + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" } ] } diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/16_plus/test_mview.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/16_plus/test_mview.json index 5969e3cfac0..9e18388d61a 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/16_plus/test_mview.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/ppas/16_plus/test_mview.json @@ -1,5 +1,65 @@ { "scenarios": [ + { + "type": "create", + "name": "Create Extension", + "endpoint": "NODE-extension.obj", + "sql_endpoint": "NODE-extension.sql_id", + "data": { + "name": "postgres_fdw", + "version": "", + "relocatable": true + }, + "store_object_id": true + }, + { + "type": "create", + "name": "Create Materialised Views with extensions.", + "endpoint": "NODE-mview.obj", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql", + "data": { + "spcname": "pg_default", + "schema": "public", + "owner": "enterprisedb", + "datacl": [], + "seclabels": [], + "name": "testmview_$%{}[]()&*^!/@`#", + "comment": "comment1", + "definition": "SELECT 1 AS col1", + "dependsonextensions": ["plpgsql", "postgres_fdw"] + }, + "expected_sql_file": "create_mview_no_depends.sql", + "expected_msql_file": "create_mview_no_depends.msql" + }, + { + "type": "alter", + "name": "Alter Materialised Views with NO DEPENDS ON.", + "endpoint": "NODE-mview.obj_id", + "sql_endpoint": "NODE-mview.sql_id", + "msql_endpoint": "NODE-mview.msql_id", + "data": { + "dependsonextensions": ["plpgsql"] + }, + "expected_sql_file": "alter_mview_no_depends.sql", + "expected_msql_file": "alter_mview_no_depends.msql" + }, + { + "type": "delete", + "name": "Drop Materialised Views", + "endpoint": "NODE-mview.delete_id", + "data": { + } + }, + { + "type": "delete", + "name": "Drop Extension", + "endpoint": "NODE-extension.delete", + "data": { + "ids": [""] + }, + "preprocess_data": true + }, { "type": "create", "name": "Create Materialised Views", @@ -272,7 +332,8 @@ "definition": "SELECT 1 AS col1", "amname": "heap" }, - "expected_msql_file": "create_mview_with_am_msql.sql" + "expected_msql_file": "create_mview_with_am_msql.sql", + "expected_sql_file": "create_mview_with_am.sql" } ] } diff --git a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/view_test_data.json b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/view_test_data.json index 2a8663c012c..015bce58767 100644 --- a/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/view_test_data.json +++ b/web/pgadmin/browser/server_groups/servers/databases/schemas/views/tests/view_test_data.json @@ -88,7 +88,8 @@ "datacl": [], "seclabels": [], "name": "test_mview_add_", - "definition": "SELECT 'test_pgadmin';" + "definition": "SELECT 'test_pgadmin';", + "dependsonextensions": ["plpgsql"] }, "mocking_required": false, "mock_data": {}, @@ -1054,7 +1055,8 @@ "query": "\"CREATE MATERIALIZED VIEW %s.%s TABLESPACE pg_default AS SELECT 'test_pgadmin' WITH NO DATA;ALTER TABLE %s.%s OWNER TO %s\" % (schema_name, view_name, schema_name, view_name, server['username'])" }, "test_data": { - "comment": "This is test comment" + "comment": "This is test comment", + "dependsonextensions": ["plpgsql"] }, "mocking_required": false, "mock_data": {}, diff --git a/web/regression/javascript/schema_ui_files/mview.ui.spec.js b/web/regression/javascript/schema_ui_files/mview.ui.spec.js index 94fc63739bb..0e91db34e94 100644 --- a/web/regression/javascript/schema_ui_files/mview.ui.spec.js +++ b/web/regression/javascript/schema_ui_files/mview.ui.spec.js @@ -53,6 +53,13 @@ describe('MaterializedViewSchema', ()=>{ await getPropertiesView(createSchemaObject(), getInitData); }); + it('dependsonextensions field exists', ()=>{ + let field = _.find(schemaObj.fields, (f)=>f.id=='dependsonextensions'); + expect(field).toBeTruthy(); + expect(field.type).toBe('select'); + expect(field.controlProps.multiple).toBe(true); + }); + it('validate', ()=>{ initializeSchemaWithData(schemaObj, {}); let state = {};