Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: support pg_stat_user_tables and key_column_usage #19739

Open
wants to merge 3 commits into
base: main
Choose a base branch
from
Open
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
63 changes: 63 additions & 0 deletions e2e_test/batch/catalog/information_schema.slt
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
statement ok
create table t(a int, b bigint, key int primary key);

statement ok
create view v as select * from t;

statement ok
create materialized view mv as select * from t;

query TTT
select table_catalog, table_schema, table_name from information_schema.views where table_schema = 'public';
----
dev public v

query TTT
select table_catalog, table_schema, table_name from information_schema.tables where table_schema = 'public' order by table_name;
----
dev public mv
dev public t
dev public v

query TTTTTTTTTT
select constraint_catalog, constraint_schema, constraint_name, table_catalog, table_schema, table_name from information_schema.table_constraints where table_schema = 'public' order by table_name;
----
dev public mv_pkey dev public mv
dev public t_pkey dev public t

query TTT
select catalog_name, schema_name, schema_owner from information_schema.schemata order by schema_name;
----
dev information_schema root
dev pg_catalog root
dev public root
dev rw_catalog root

query TTTTTTTII
select * from information_schema.key_column_usage where table_schema = 'public' order by table_name;
----
dev public mv_pkey dev public mv key 3 NULL
dev public t_pkey dev public t key 3 NULL

query TTTTITTTT
select table_catalog, table_schema, table_name, column_name, ordinal_position, data_type, udt_catalog, udt_schema, udt_name from information_schema.columns where table_schema = 'public' order by table_name, ordinal_position;
----
dev public mv a 1 integer dev pg_catalog int4
dev public mv b 2 bigint dev pg_catalog int8
dev public mv key 3 integer dev pg_catalog int4
dev public t a 1 integer dev pg_catalog int4
dev public t b 2 bigint dev pg_catalog int8
dev public t key 3 integer dev pg_catalog int4
dev public v a 1 integer dev pg_catalog int4
dev public v b 2 bigint dev pg_catalog int8
dev public v key 3 integer dev pg_catalog int4


statement ok
drop materialized view mv;

statement ok
drop view v;

statement ok
drop table t;
28 changes: 14 additions & 14 deletions e2e_test/batch/catalog/pg_class.slt.part
Original file line number Diff line number Diff line change
Expand Up @@ -2,20 +2,20 @@ query ITIT
SELECT oid,relname,relowner,relkind FROM pg_catalog.pg_class ORDER BY oid limit 15;
----
2147478647 columns 1 v
2147478648 schemata 1 v
2147478649 table_constraints 1 v
2147478650 tables 1 v
2147478651 views 1 v
2147478652 pg_am 1 v
2147478653 pg_attrdef 1 v
2147478654 pg_attribute 1 v
2147478655 pg_auth_members 1 v
2147478656 pg_cast 1 r
2147478657 pg_class 1 v
2147478658 pg_collation 1 v
2147478659 pg_constraint 1 r
2147478660 pg_conversion 1 v
2147478661 pg_database 1 v
2147478648 key_column_usage 1 v
2147478649 schemata 1 v
2147478650 table_constraints 1 v
2147478651 tables 1 v
2147478652 views 1 v
2147478653 pg_am 1 v
2147478654 pg_attrdef 1 v
2147478655 pg_attribute 1 v
2147478656 pg_auth_members 1 v
2147478657 pg_cast 1 r
2147478658 pg_class 1 v
2147478659 pg_collation 1 v
2147478660 pg_constraint 1 r
2147478661 pg_conversion 1 v

query ITIT
SELECT oid,relname,relowner,relkind FROM pg_catalog.pg_class WHERE oid = 'pg_namespace'::regclass;
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
// Copyright 2024 RisingWave Labs
//
// Licensed under the Apache License, Version 2.0 (the "License");
// you may not use this file except in compliance with the License.
// You may obtain a copy of the License at
//
// http://www.apache.org/licenses/LICENSE-2.0
//
// Unless required by applicable law or agreed to in writing, software
// distributed under the License is distributed on an "AS IS" BASIS,
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
// See the License for the specific language governing permissions and
// limitations under the License.

use risingwave_common::types::Fields;
use risingwave_frontend_macro::system_catalog;

/// The view `key_column_usage` contains all constraints belonging to tables that the current user owns or has some privilege other than SELECT on.
/// Ref: [`https://www.postgresql.org/docs/current/infoschema-key-column-usage.html`]
/// Limitation:
/// This view assume the constraint schema is the same as the table schema, since `pg_clatalog`.`pg_constraint` only support primrary key.
#[system_catalog(
view,
"information_schema.key_column_usage",
"WITH key_column_usage_without_name AS (
SELECT CURRENT_DATABASE() AS constraint_catalog,
pg_namespace.nspname AS constraint_schema,
pg_constraint.conname AS constraint_name,
CURRENT_DATABASE() AS table_catalog,
pg_namespace.nspname AS table_schema,
pg_class.relname AS table_name,
unnest(conkey) as col_id,
conrelid as table_id
FROM pg_catalog.pg_constraint
JOIN pg_catalog.pg_class ON pg_constraint.conrelid = pg_class.oid
JOIN rw_catalog.rw_relations ON rw_relations.id = pg_class.oid
JOIN pg_catalog.pg_namespace ON pg_class.relnamespace = pg_namespace.oid
WHERE rw_relations.relation_type != 'table' or (rw_relations.relation_type = 'table' and has_table_privilege(pg_constraint.conrelid, 'INSERT, UPDATE, DELETE'))
ORDER BY constraint_catalog, constraint_schema, constraint_name
)
SELECT constraint_catalog, constraint_schema, constraint_name, table_catalog, table_schema, table_name,
name as column_name, rw_columns.position as ordinal_position, NULL::int as position_in_unique_constraint
FROM key_column_usage_without_name
JOIN rw_catalog.rw_columns ON
rw_columns.position = key_column_usage_without_name.col_id AND
rw_columns.relation_id = key_column_usage_without_name.table_id"
)]
#[derive(Fields)]
struct KeyColumnUsage {
constraint_catalog: String,
constraint_schema: String,
constraint_name: String,
table_catalog: String,
table_schema: String,
table_name: String,
column_name: String,
ordinal_position: i32,
position_in_unique_constraint: i32,
}
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@
// limitations under the License.

mod columns;
mod key_column_usage;
mod schemata;
mod table_constraints;
mod tables;
Expand Down
1 change: 1 addition & 0 deletions src/frontend/src/catalog/system_catalog/pg_catalog/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -46,6 +46,7 @@ mod pg_settings;
mod pg_shadow;
mod pg_shdescription;
mod pg_stat_activity;
mod pg_stat_user_tables;
mod pg_tables;
mod pg_tablespace;
mod pg_trigger;
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,87 @@
// Copyright 2024 RisingWave Labs
//
// Licensed under the Apache License, Version 2.0 (the "License");
// you may not use this file except in compliance with the License.
// You may obtain a copy of the License at
//
// http://www.apache.org/licenses/LICENSE-2.0
//
// Unless required by applicable law or agreed to in writing, software
// distributed under the License is distributed on an "AS IS" BASIS,
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
// See the License for the specific language governing permissions and
// limitations under the License.

use risingwave_common::types::{Fields, Timestamptz};
use risingwave_frontend_macro::system_catalog;

/// The `pg_stat_user_tables` view will contain one row for each user table in the current database,
/// showing statistics about accesses to that specific table.
/// Ref: [`https://www.postgresql.org/docs/current/monitoring-stats.html#MONITORING-PG-STAT-ALL-TABLES-VIEW`]
#[system_catalog(
view,
"pg_catalog.pg_stat_user_tables",
"SELECT
rr.id as relid,
rs.name as schemaname,
rr.name as relname,
NULL::bigint as seq_scan,
NULL::timestamptz as last_seq_scan,
NULL::bigint as seq_tup_read,
NULL::bigint as idx_scan,
NULL::timestamptz as last_idx_scan,
NULL::bigint as idx_tup_fetch,
NULL::bigint as n_tup_ins,
NULL::bigint as n_tup_del,
NULL::bigint as n_tup_hot_upd,
NULL::bigint as n_tup_newpage_upd,
rts.total_key_count as n_live_tup,
NULL::bigint as n_dead_tup,
NULL::bigint as n_mod_since_analyze,
NULL::bigint as n_ins_since_vacuum,
NULL::timestamptz as last_vacuum,
NULL::timestamptz as last_autovacuum,
NULL::timestamptz as last_analyze,
NULL::timestamptz as last_autoanalyze,
NULL::bigint as vacuum_count,
NULL::bigint as autovacuum_count,
NULL::bigint as analyze_count,
NULL::bigint as autoanalyze_count
FROM
rw_relations rr
left join rw_table_stats rts on rr.id = rts.id
join rw_schemas rs on schema_id = rs.id
WHERE
rs.name != 'rw_catalog'
AND rs.name != 'pg_catalog'
AND rs.name != 'information_schema'
"
)]
#[derive(Fields)]
struct PgStatUserTables {
relid: i32,
schemaname: String,
relname: String,
seq_scan: i64,
last_seq_scan: Timestamptz,
seq_tup_read: i64,
idx_scan: i64,
last_idx_scan: Timestamptz,
idx_tup_fetch: i64,
n_tup_ins: i64,
n_tup_del: i64,
n_tup_hot_upd: i64,
n_tup_newpage_upd: i64,
n_live_tup: i64,
n_dead_tup: i64,
n_mod_since_analyze: i64,
n_ins_since_vacuum: i64,
last_vacuum: Timestamptz,
last_autovacuum: Timestamptz,
last_analyze: Timestamptz,
last_autoanalyze: Timestamptz,
vacuum_count: i64,
autovacuum_count: i64,
analyze_count: i64,
autoanalyze_count: i64,
}
Loading