mirror of
https://github.com/pgadmin-org/pgadmin4.git
synced 2025-02-25 18:55:31 -06:00
Added support to show statistics for materialized views. #3316
This commit is contained in:
@@ -21,6 +21,7 @@ New features
|
||||
************
|
||||
|
||||
| `Issue #3275 <https://github.com/pgadmin-org/pgadmin4/issues/3275>`_ - Allow on demand record count setting to be changed per user using preferences.
|
||||
| `Issue #3316 <https://github.com/pgadmin-org/pgadmin4/issues/3316>`_ - Added support to show statistics for materialized views.
|
||||
|
||||
Housekeeping
|
||||
************
|
||||
|
@@ -23,7 +23,7 @@ SELECT
|
||||
FROM
|
||||
pg_catalog.pg_stat_all_tables st
|
||||
JOIN
|
||||
pg_catalog.pg_class cl on cl.oid=st.relid
|
||||
pg_catalog.pg_class cl on cl.oid=st.relid and cl.relkind IN ('r','s','t','p')
|
||||
WHERE
|
||||
schemaname = {{schema_name|qtLiteral(conn)}}
|
||||
ORDER BY st.relname;
|
||||
|
@@ -350,7 +350,7 @@ class ViewNode(PGChildNodeView, VacuumSettings, SchemaDiffObjectCompare):
|
||||
'nodes': [{'get': 'node'}, {'get': 'nodes'}],
|
||||
'sql': [{'get': 'sql'}],
|
||||
'msql': [{'get': 'msql'}, {'get': 'msql'}],
|
||||
'stats': [{'get': 'statistics'}],
|
||||
'stats': [{'get': 'statistics'}, {'get': 'statistics'}],
|
||||
'dependency': [{'get': 'dependencies'}],
|
||||
'dependent': [{'get': 'dependents'}],
|
||||
'configs': [{'get': 'configs'}],
|
||||
@@ -2341,6 +2341,79 @@ class MViewNode(ViewNode, VacuumSettings):
|
||||
|
||||
return make_json_response(success=1)
|
||||
|
||||
@check_precondition
|
||||
def statistics(self, gid, sid, did, scid, vid=None):
|
||||
"""
|
||||
Statistics
|
||||
|
||||
Args:
|
||||
gid: Server Group ID
|
||||
sid: Server ID
|
||||
did: Database ID
|
||||
scid: Schema ID
|
||||
vid: View ID
|
||||
|
||||
Returns the statistics for a particular MView if vid is specified,
|
||||
otherwise it will return statistics for all the MView in that
|
||||
schema.
|
||||
"""
|
||||
status, schema_name = self.conn.execute_scalar(
|
||||
render_template(
|
||||
"/".join([self.template_path, 'sql/get_schema.sql']),
|
||||
conn=self.conn, scid=scid
|
||||
)
|
||||
)
|
||||
if not status:
|
||||
return internal_server_error(errormsg=schema_name)
|
||||
|
||||
if vid is None:
|
||||
status, res = self.conn.execute_dict(
|
||||
render_template(
|
||||
"/".join([self.template_path,
|
||||
'sql/coll_mview_stats.sql']), conn=self.conn,
|
||||
schema_name=schema_name
|
||||
)
|
||||
)
|
||||
else:
|
||||
# For Individual mview stats
|
||||
|
||||
# Check if pgstattuple extension is already created?
|
||||
# if created then only add extended stats
|
||||
status, is_pgstattuple = self.conn.execute_scalar("""
|
||||
SELECT (count(extname) > 0) AS is_pgstattuple
|
||||
FROM pg_catalog.pg_extension
|
||||
WHERE extname='pgstattuple'
|
||||
""")
|
||||
if not status:
|
||||
return internal_server_error(errormsg=is_pgstattuple)
|
||||
|
||||
# Fetch MView name
|
||||
status, mview_name = self.conn.execute_scalar(
|
||||
render_template(
|
||||
"/".join([self.template_path, 'sql/get_view_name.sql']),
|
||||
conn=self.conn, scid=scid, vid=vid
|
||||
)
|
||||
)
|
||||
if not status:
|
||||
return internal_server_error(errormsg=mview_name)
|
||||
|
||||
status, res = self.conn.execute_dict(
|
||||
render_template(
|
||||
"/".join([self.template_path, 'sql/stats.sql']),
|
||||
conn=self.conn, schema_name=schema_name,
|
||||
mview_name=mview_name,
|
||||
is_pgstattuple=is_pgstattuple, vid=vid
|
||||
)
|
||||
)
|
||||
|
||||
if not status:
|
||||
return internal_server_error(errormsg=res)
|
||||
|
||||
return make_json_response(
|
||||
data=res,
|
||||
status=200
|
||||
)
|
||||
|
||||
|
||||
SchemaDiffRegistry(view_blueprint.node_type, ViewNode)
|
||||
ViewNode.register_node_view(view_blueprint)
|
||||
|
@@ -39,6 +39,7 @@ define('pgadmin.node.mview', [
|
||||
label: gettext('Materialized Views'),
|
||||
type: 'coll-mview',
|
||||
columns: ['name', 'owner', 'comment'],
|
||||
hasStatistics: true,
|
||||
canDrop: schemaChildTreeNode.isTreeItemOfChildOfSchema,
|
||||
canDropCascade: schemaChildTreeNode.isTreeItemOfChildOfSchema,
|
||||
});
|
||||
@@ -64,6 +65,7 @@ define('pgadmin.node.mview', [
|
||||
label: gettext('Materialized View'),
|
||||
hasSQL: true,
|
||||
hasDepends: true,
|
||||
hasStatistics: true,
|
||||
hasScriptTypes: ['create', 'select'],
|
||||
collection_type: 'coll-mview',
|
||||
width: pgBrowser.stdW.md + 'px',
|
||||
|
@@ -0,0 +1,29 @@
|
||||
SELECT
|
||||
st.relname AS {{ conn|qtIdent(_('View Name')) }},
|
||||
n_tup_ins AS {{ conn|qtIdent(_('Tuples inserted')) }},
|
||||
n_tup_upd AS {{ conn|qtIdent(_('Tuples updated')) }},
|
||||
n_tup_del AS {{ conn|qtIdent(_('Tuples deleted')) }},
|
||||
n_tup_hot_upd AS {{ conn|qtIdent(_('Tuples HOT updated')) }},
|
||||
n_live_tup AS {{ conn|qtIdent(_('Live tuples')) }},
|
||||
n_dead_tup AS {{ conn|qtIdent(_('Dead tuples')) }},
|
||||
last_vacuum AS {{ conn|qtIdent(_('Last vacuum')) }},
|
||||
last_autovacuum AS {{ conn|qtIdent(_('Last autovacuum')) }},
|
||||
last_analyze AS {{ conn|qtIdent(_('Last analyze')) }},
|
||||
last_autoanalyze AS {{ conn|qtIdent(_('Last autoanalyze')) }},
|
||||
vacuum_count AS {{ conn|qtIdent(_('Vacuum counter')) }},
|
||||
autovacuum_count AS {{ conn|qtIdent(_('Autovacuum counter')) }},
|
||||
analyze_count AS {{ conn|qtIdent(_('Analyze counter')) }},
|
||||
autoanalyze_count AS {{ conn|qtIdent(_('Autoanalyze counter')) }},
|
||||
pg_catalog.pg_relation_size(st.relid)
|
||||
+ CASE WHEN cl.reltoastrelid = 0 THEN 0 ELSE pg_catalog.pg_relation_size(cl.reltoastrelid)
|
||||
+ COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=cl.reltoastrelid)::int8, 0) END
|
||||
+ COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=st.relid)::int8, 0) AS {{ conn|qtIdent(_('Total Size')) }}
|
||||
FROM
|
||||
pg_catalog.pg_stat_all_tables st
|
||||
JOIN
|
||||
pg_catalog.pg_class cl on cl.oid=st.relid and cl.relkind = 'm'
|
||||
WHERE
|
||||
schemaname = {{schema_name|qtLiteral(conn)}}
|
||||
ORDER BY st.relname;
|
@@ -0,0 +1,53 @@
|
||||
SELECT
|
||||
seq_scan AS {{ conn|qtIdent(_('Sequential scans')) }},
|
||||
seq_tup_read AS {{ conn|qtIdent(_('Sequential tuples read')) }},
|
||||
idx_scan AS {{ conn|qtIdent(_('Index scans')) }},
|
||||
idx_tup_fetch AS {{ conn|qtIdent(_('Index tuples fetched')) }},
|
||||
n_tup_ins AS {{ conn|qtIdent(_('Tuples inserted')) }},
|
||||
n_tup_upd AS {{ conn|qtIdent(_('Tuples updated')) }},
|
||||
n_tup_del AS {{ conn|qtIdent(_('Tuples deleted')) }},
|
||||
n_tup_hot_upd AS {{ conn|qtIdent(_('Tuples HOT updated')) }},
|
||||
n_live_tup AS {{ conn|qtIdent(_('Live tuples')) }},
|
||||
n_dead_tup AS {{ conn|qtIdent(_('Dead tuples')) }},
|
||||
heap_blks_read AS {{ conn|qtIdent(_('Heap blocks read')) }},
|
||||
heap_blks_hit AS {{ conn|qtIdent(_('Heap blocks hit')) }},
|
||||
idx_blks_read AS {{ conn|qtIdent(_('Index blocks read')) }},
|
||||
idx_blks_hit AS {{ conn|qtIdent(_('Index blocks hit')) }},
|
||||
toast_blks_read AS {{ conn|qtIdent(_('Toast blocks read')) }},
|
||||
toast_blks_hit AS {{ conn|qtIdent(_('Toast blocks hit')) }},
|
||||
tidx_blks_read AS {{ conn|qtIdent(_('Toast index blocks read')) }},
|
||||
tidx_blks_hit AS {{ conn|qtIdent(_('Toast index blocks hit')) }},
|
||||
last_vacuum AS {{ conn|qtIdent(_('Last vacuum')) }},
|
||||
last_autovacuum AS {{ conn|qtIdent(_('Last autovacuum')) }},
|
||||
last_analyze AS {{ conn|qtIdent(_('Last analyze')) }},
|
||||
last_autoanalyze AS {{ conn|qtIdent(_('Last autoanalyze')) }},
|
||||
pg_catalog.pg_relation_size(stat.relid) AS {{ conn|qtIdent(_('Table size')) }},
|
||||
CASE WHEN cl.reltoastrelid = 0 THEN NULL ELSE pg_catalog.pg_size_pretty(pg_catalog.pg_relation_size(cl.reltoastrelid)
|
||||
+ COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=cl.reltoastrelid)::int8, 0))
|
||||
END AS {{ conn|qtIdent(_('Toast table size')) }},
|
||||
COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=stat.relid)::int8, 0)
|
||||
AS {{ conn|qtIdent(_('Indexes size')) }}
|
||||
{% if is_pgstattuple %}
|
||||
{#== EXTENDED STATS ==#}
|
||||
,tuple_count AS {{ conn|qtIdent(_('Tuple count')) }},
|
||||
tuple_len AS {{ conn|qtIdent(_('Tuple length')) }},
|
||||
tuple_percent AS {{ conn|qtIdent(_('Tuple percent')) }},
|
||||
dead_tuple_count AS {{ conn|qtIdent(_('Dead tuple count')) }},
|
||||
dead_tuple_len AS {{ conn|qtIdent(_('Dead tuple length')) }},
|
||||
dead_tuple_percent AS {{ conn|qtIdent(_('Dead tuple percent')) }},
|
||||
free_space AS {{ conn|qtIdent(_('Free space')) }},
|
||||
free_percent AS {{ conn|qtIdent(_('Free percent')) }}
|
||||
FROM
|
||||
pgstattuple('{{schema_name}}.{{mview_name}}'), pg_catalog.pg_stat_all_tables stat
|
||||
{% else %}
|
||||
FROM
|
||||
pg_catalog.pg_stat_all_tables stat
|
||||
{% endif %}
|
||||
JOIN
|
||||
pg_catalog.pg_statio_all_tables statio ON stat.relid = statio.relid
|
||||
JOIN
|
||||
pg_catalog.pg_class cl ON cl.oid=stat.relid
|
||||
WHERE
|
||||
stat.relid = {{ vid }}::oid
|
@@ -0,0 +1,29 @@
|
||||
SELECT
|
||||
st.relname AS {{ conn|qtIdent(_('View Name')) }},
|
||||
n_tup_ins AS {{ conn|qtIdent(_('Tuples inserted')) }},
|
||||
n_tup_upd AS {{ conn|qtIdent(_('Tuples updated')) }},
|
||||
n_tup_del AS {{ conn|qtIdent(_('Tuples deleted')) }},
|
||||
n_tup_hot_upd AS {{ conn|qtIdent(_('Tuples HOT updated')) }},
|
||||
n_live_tup AS {{ conn|qtIdent(_('Live tuples')) }},
|
||||
n_dead_tup AS {{ conn|qtIdent(_('Dead tuples')) }},
|
||||
last_vacuum AS {{ conn|qtIdent(_('Last vacuum')) }},
|
||||
last_autovacuum AS {{ conn|qtIdent(_('Last autovacuum')) }},
|
||||
last_analyze AS {{ conn|qtIdent(_('Last analyze')) }},
|
||||
last_autoanalyze AS {{ conn|qtIdent(_('Last autoanalyze')) }},
|
||||
vacuum_count AS {{ conn|qtIdent(_('Vacuum counter')) }},
|
||||
autovacuum_count AS {{ conn|qtIdent(_('Autovacuum counter')) }},
|
||||
analyze_count AS {{ conn|qtIdent(_('Analyze counter')) }},
|
||||
autoanalyze_count AS {{ conn|qtIdent(_('Autoanalyze counter')) }},
|
||||
pg_catalog.pg_relation_size(st.relid)
|
||||
+ CASE WHEN cl.reltoastrelid = 0 THEN 0 ELSE pg_catalog.pg_relation_size(cl.reltoastrelid)
|
||||
+ COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=cl.reltoastrelid)::int8, 0) END
|
||||
+ COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=st.relid)::int8, 0) AS {{ conn|qtIdent(_('Total Size')) }}
|
||||
FROM
|
||||
pg_catalog.pg_stat_all_tables st
|
||||
JOIN
|
||||
pg_catalog.pg_class cl on cl.oid=st.relid and cl.relkind = 'm'
|
||||
WHERE
|
||||
schemaname = {{schema_name|qtLiteral(conn)}}
|
||||
ORDER BY st.relname;
|
@@ -0,0 +1,53 @@
|
||||
SELECT
|
||||
seq_scan AS {{ conn|qtIdent(_('Sequential scans')) }},
|
||||
seq_tup_read AS {{ conn|qtIdent(_('Sequential tuples read')) }},
|
||||
idx_scan AS {{ conn|qtIdent(_('Index scans')) }},
|
||||
idx_tup_fetch AS {{ conn|qtIdent(_('Index tuples fetched')) }},
|
||||
n_tup_ins AS {{ conn|qtIdent(_('Tuples inserted')) }},
|
||||
n_tup_upd AS {{ conn|qtIdent(_('Tuples updated')) }},
|
||||
n_tup_del AS {{ conn|qtIdent(_('Tuples deleted')) }},
|
||||
n_tup_hot_upd AS {{ conn|qtIdent(_('Tuples HOT updated')) }},
|
||||
n_live_tup AS {{ conn|qtIdent(_('Live tuples')) }},
|
||||
n_dead_tup AS {{ conn|qtIdent(_('Dead tuples')) }},
|
||||
heap_blks_read AS {{ conn|qtIdent(_('Heap blocks read')) }},
|
||||
heap_blks_hit AS {{ conn|qtIdent(_('Heap blocks hit')) }},
|
||||
idx_blks_read AS {{ conn|qtIdent(_('Index blocks read')) }},
|
||||
idx_blks_hit AS {{ conn|qtIdent(_('Index blocks hit')) }},
|
||||
toast_blks_read AS {{ conn|qtIdent(_('Toast blocks read')) }},
|
||||
toast_blks_hit AS {{ conn|qtIdent(_('Toast blocks hit')) }},
|
||||
tidx_blks_read AS {{ conn|qtIdent(_('Toast index blocks read')) }},
|
||||
tidx_blks_hit AS {{ conn|qtIdent(_('Toast index blocks hit')) }},
|
||||
last_vacuum AS {{ conn|qtIdent(_('Last vacuum')) }},
|
||||
last_autovacuum AS {{ conn|qtIdent(_('Last autovacuum')) }},
|
||||
last_analyze AS {{ conn|qtIdent(_('Last analyze')) }},
|
||||
last_autoanalyze AS {{ conn|qtIdent(_('Last autoanalyze')) }},
|
||||
pg_catalog.pg_relation_size(stat.relid) AS {{ conn|qtIdent(_('Table size')) }},
|
||||
CASE WHEN cl.reltoastrelid = 0 THEN NULL ELSE pg_catalog.pg_size_pretty(pg_catalog.pg_relation_size(cl.reltoastrelid)
|
||||
+ COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=cl.reltoastrelid)::int8, 0))
|
||||
END AS {{ conn|qtIdent(_('Toast table size')) }},
|
||||
COALESCE((SELECT SUM(pg_catalog.pg_relation_size(indexrelid))
|
||||
FROM pg_catalog.pg_index WHERE indrelid=stat.relid)::int8, 0)
|
||||
AS {{ conn|qtIdent(_('Indexes size')) }}
|
||||
{% if is_pgstattuple %}
|
||||
{#== EXTENDED STATS ==#}
|
||||
,tuple_count AS {{ conn|qtIdent(_('Tuple count')) }},
|
||||
tuple_len AS {{ conn|qtIdent(_('Tuple length')) }},
|
||||
tuple_percent AS {{ conn|qtIdent(_('Tuple percent')) }},
|
||||
dead_tuple_count AS {{ conn|qtIdent(_('Dead tuple count')) }},
|
||||
dead_tuple_len AS {{ conn|qtIdent(_('Dead tuple length')) }},
|
||||
dead_tuple_percent AS {{ conn|qtIdent(_('Dead tuple percent')) }},
|
||||
free_space AS {{ conn|qtIdent(_('Free space')) }},
|
||||
free_percent AS {{ conn|qtIdent(_('Free percent')) }}
|
||||
FROM
|
||||
pgstattuple('{{schema_name}}.{{mview_name}}'), pg_catalog.pg_stat_all_tables stat
|
||||
{% else %}
|
||||
FROM
|
||||
pg_catalog.pg_stat_all_tables stat
|
||||
{% endif %}
|
||||
JOIN
|
||||
pg_catalog.pg_statio_all_tables statio ON stat.relid = statio.relid
|
||||
JOIN
|
||||
pg_catalog.pg_class cl ON cl.oid=stat.relid
|
||||
WHERE
|
||||
stat.relid = {{ vid }}::oid
|
Reference in New Issue
Block a user