Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Binary file modified docs/en_US/images/materialized_view_definition.png
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
3 changes: 3 additions & 0 deletions docs/en_US/materialized_view_dialog.rst
Original file line number Diff line number Diff line change
Expand Up @@ -47,6 +47,9 @@ Use the fields in the *Storage* tab to maintain the materialized view:
* Use the *Fill Factor* field to specify a fill factor for the materialized
view. The fill factor for a table is a percentage between 10 and 100. 100
(complete packing) is the default.
* Use the drop-down listbox next to *Depends on extensions* to select the extension that this materialized view
depends on (for example, edbspl). If set, dropping the extension will automatically drop the
materialized view as well.

Click the *Code* tab to continue.

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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'] = []
Expand Down Expand Up @@ -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:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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),
Expand All @@ -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,
},
{
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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'],
},{
Expand Down
Original file line number Diff line number Diff line change
@@ -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 %}
Original file line number Diff line number Diff line change
@@ -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,
Comment on lines +20 to +25
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

⚠️ Potential issue | 🟠 Major

Add dependency type filter to ensure correctness.

The query retrieves all dependencies between the materialized view and extensions, but doesn't filter by dependency type. This could return incorrect results if the materialized view has other dependency relationships with extensions beyond explicit DEPENDS ON EXTENSION declarations.

Apply this diff to filter for extension dependencies only:

     (
       SELECT array_agg(DISTINCT e.extname)
       FROM pg_depend d
       JOIN pg_extension e ON d.refobjid = e.oid
-      WHERE d.objid = c.oid
+      WHERE d.objid = c.oid
+        AND d.deptype = 'x'
     ) AS dependsonextensions,

The deptype = 'x' filter ensures only DEPENDS ON EXTENSION relationships are captured, not other dependency types.

📝 Committable suggestion

‼️ IMPORTANT
Carefully review the code before committing. Ensure that it accurately replaces the highlighted code, contains no missing lines, and has no issues with indentation. Thoroughly test & benchmark the code to ensure it meets the requirements.

Suggested change
(
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,
(
SELECT array_agg(DISTINCT e.extname)
FROM pg_depend d
JOIN pg_extension e ON d.refobjid = e.oid
WHERE d.objid = c.oid
AND d.deptype = 'x'
) AS dependsonextensions,
🤖 Prompt for AI Agents
In
web/pgadmin/browser/server_groups/servers/databases/schemas/views/templates/mviews/pg/13_plus/sql/properties.sql
around lines 20-25, the subquery collecting extension dependencies lacks a
dependency-type filter and may return non-extension relations; modify the WHERE
clause to include "AND d.deptype = 'x'" so only DEPENDS ON EXTENSION ('x')
relationships are aggregated, ensuring correct results.

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 %}
Loading
Loading