Skip to content

Commit 3bbe7ed

Browse files
authored
feat: support pg_stat_user_tables and key_column_usage (#19739) (#20513)
1 parent dd623f6 commit 3bbe7ed

File tree

7 files changed

+227
-16
lines changed

7 files changed

+227
-16
lines changed
Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,63 @@
1+
statement ok
2+
create table t(a int, b bigint, key int primary key);
3+
4+
statement ok
5+
create view v as select * from t;
6+
7+
statement ok
8+
create materialized view mv as select * from t;
9+
10+
query TT
11+
select table_schema, table_name from information_schema.views where table_schema = 'public';
12+
----
13+
public v
14+
15+
query TT
16+
select table_schema, table_name from information_schema.tables where table_schema = 'public' order by table_name;
17+
----
18+
public mv
19+
public t
20+
public v
21+
22+
query TTTTTTTT
23+
select constraint_schema, constraint_name, table_schema, table_name from information_schema.table_constraints where table_schema = 'public' order by table_name;
24+
----
25+
public mv_pkey public mv
26+
public t_pkey public t
27+
28+
query TT
29+
select schema_name from information_schema.schemata order by schema_name;
30+
----
31+
information_schema
32+
pg_catalog
33+
public
34+
rw_catalog
35+
36+
query TTTTTII
37+
select * EXCEPT(constraint_catalog, table_catalog) from information_schema.key_column_usage where table_schema = 'public' order by table_name;
38+
----
39+
public mv_pkey public mv key 3 NULL
40+
public t_pkey public t key 3 NULL
41+
42+
query TTTITTT
43+
select table_schema, table_name, column_name, ordinal_position, data_type, udt_schema, udt_name from information_schema.columns where table_schema = 'public' order by table_name, ordinal_position;
44+
----
45+
public mv a 1 integer pg_catalog int4
46+
public mv b 2 bigint pg_catalog int8
47+
public mv key 3 integer pg_catalog int4
48+
public t a 1 integer pg_catalog int4
49+
public t b 2 bigint pg_catalog int8
50+
public t key 3 integer pg_catalog int4
51+
public v a 1 integer pg_catalog int4
52+
public v b 2 bigint pg_catalog int8
53+
public v key 3 integer pg_catalog int4
54+
55+
56+
statement ok
57+
drop materialized view mv;
58+
59+
statement ok
60+
drop view v;
61+
62+
statement ok
63+
drop table t;

e2e_test/batch/catalog/pg_class.slt.part

Lines changed: 15 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -2,22 +2,22 @@ query ITIT
22
SELECT oid,relname,relowner,relkind FROM pg_catalog.pg_class ORDER BY oid limit 15;
33
----
44
2147478647 columns 1 v
5-
2147478648 schemata 1 v
6-
2147478649 table_constraints 1 v
7-
2147478650 tables 1 v
8-
2147478651 views 1 v
9-
2147478652 pg_am 1 v
10-
2147478653 pg_attrdef 1 v
11-
2147478654 pg_attribute 1 v
12-
2147478655 pg_auth_members 1 v
13-
2147478656 pg_cast 1 r
14-
2147478657 pg_class 1 v
15-
2147478658 pg_collation 1 v
16-
2147478659 pg_constraint 1 r
17-
2147478660 pg_conversion 1 v
18-
2147478661 pg_database 1 v
5+
2147478648 key_column_usage 1 v
6+
2147478649 schemata 1 v
7+
2147478650 table_constraints 1 v
8+
2147478651 tables 1 v
9+
2147478652 views 1 v
10+
2147478653 pg_am 1 v
11+
2147478654 pg_attrdef 1 v
12+
2147478655 pg_attribute 1 v
13+
2147478656 pg_auth_members 1 v
14+
2147478657 pg_cast 1 r
15+
2147478658 pg_class 1 v
16+
2147478659 pg_collation 1 v
17+
2147478660 pg_constraint 1 r
18+
2147478661 pg_conversion 1 v
1919

2020
query ITIT
2121
SELECT oid,relname,relowner,relkind FROM pg_catalog.pg_class WHERE oid = 'pg_namespace'::regclass;
2222
----
23-
2147478672 pg_namespace 1 v
23+
2147478673 pg_namespace 1 v
Lines changed: 59 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,59 @@
1+
// Copyright 2024 RisingWave Labs
2+
//
3+
// Licensed under the Apache License, Version 2.0 (the "License");
4+
// you may not use this file except in compliance with the License.
5+
// You may obtain a copy of the License at
6+
//
7+
// http://www.apache.org/licenses/LICENSE-2.0
8+
//
9+
// Unless required by applicable law or agreed to in writing, software
10+
// distributed under the License is distributed on an "AS IS" BASIS,
11+
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
12+
// See the License for the specific language governing permissions and
13+
// limitations under the License.
14+
15+
use risingwave_common::types::Fields;
16+
use risingwave_frontend_macro::system_catalog;
17+
18+
/// The view `key_column_usage` contains all constraints belonging to tables that the current user owns or has some privilege other than SELECT on.
19+
/// Ref: [`https://www.postgresql.org/docs/current/infoschema-key-column-usage.html`]
20+
/// Limitation:
21+
/// This view assume the constraint schema is the same as the table schema, since `pg_catalog`.`pg_constraint` only support primary key.
22+
#[system_catalog(
23+
view,
24+
"information_schema.key_column_usage",
25+
"WITH key_column_usage_without_name AS (
26+
SELECT CURRENT_DATABASE() AS constraint_catalog,
27+
pg_namespace.nspname AS constraint_schema,
28+
pg_constraint.conname AS constraint_name,
29+
CURRENT_DATABASE() AS table_catalog,
30+
pg_namespace.nspname AS table_schema,
31+
pg_class.relname AS table_name,
32+
unnest(conkey) as col_id,
33+
conrelid as table_id
34+
FROM pg_catalog.pg_constraint
35+
JOIN pg_catalog.pg_class ON pg_constraint.conrelid = pg_class.oid
36+
JOIN rw_catalog.rw_relations ON rw_relations.id = pg_class.oid
37+
JOIN pg_catalog.pg_namespace ON pg_class.relnamespace = pg_namespace.oid
38+
WHERE rw_relations.relation_type != 'table' or (rw_relations.relation_type = 'table' and has_table_privilege(pg_constraint.conrelid, 'INSERT, UPDATE, DELETE'))
39+
ORDER BY constraint_catalog, constraint_schema, constraint_name
40+
)
41+
SELECT constraint_catalog, constraint_schema, constraint_name, table_catalog, table_schema, table_name,
42+
name as column_name, rw_columns.position as ordinal_position, NULL::int as position_in_unique_constraint
43+
FROM key_column_usage_without_name
44+
JOIN rw_catalog.rw_columns ON
45+
rw_columns.position = key_column_usage_without_name.col_id AND
46+
rw_columns.relation_id = key_column_usage_without_name.table_id"
47+
)]
48+
#[derive(Fields)]
49+
struct KeyColumnUsage {
50+
constraint_catalog: String,
51+
constraint_schema: String,
52+
constraint_name: String,
53+
table_catalog: String,
54+
table_schema: String,
55+
table_name: String,
56+
column_name: String,
57+
ordinal_position: i32,
58+
position_in_unique_constraint: i32,
59+
}

src/frontend/src/catalog/system_catalog/information_schema/mod.rs

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,7 @@
1313
// limitations under the License.
1414

1515
mod columns;
16+
mod key_column_usage;
1617
mod schemata;
1718
mod table_constraints;
1819
mod tables;

src/frontend/src/catalog/system_catalog/information_schema/table_constraints.rs

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -18,7 +18,7 @@ use risingwave_frontend_macro::system_catalog;
1818
/// The view `table_constraints` contains all constraints belonging to tables that the current user owns or has some privilege other than SELECT on.
1919
/// Ref: [`https://www.postgresql.org/docs/current/infoschema-table-constraints.html`]
2020
/// Limitation:
21-
/// This view assume the constraint schema is the same as the table schema, since `pg_clatalog`.`pg_constraint` only support primrary key.
21+
/// This view assume the constraint schema is the same as the table schema, since `pg_catalog`.`pg_constraint` only support primary key.
2222
#[system_catalog(
2323
view,
2424
"information_schema.table_constraints",

src/frontend/src/catalog/system_catalog/pg_catalog/mod.rs

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -46,6 +46,7 @@ mod pg_settings;
4646
mod pg_shadow;
4747
mod pg_shdescription;
4848
mod pg_stat_activity;
49+
mod pg_stat_user_tables;
4950
mod pg_tables;
5051
mod pg_tablespace;
5152
mod pg_trigger;
Lines changed: 87 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,87 @@
1+
// Copyright 2024 RisingWave Labs
2+
//
3+
// Licensed under the Apache License, Version 2.0 (the "License");
4+
// you may not use this file except in compliance with the License.
5+
// You may obtain a copy of the License at
6+
//
7+
// http://www.apache.org/licenses/LICENSE-2.0
8+
//
9+
// Unless required by applicable law or agreed to in writing, software
10+
// distributed under the License is distributed on an "AS IS" BASIS,
11+
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
12+
// See the License for the specific language governing permissions and
13+
// limitations under the License.
14+
15+
use risingwave_common::types::{Fields, Timestamptz};
16+
use risingwave_frontend_macro::system_catalog;
17+
18+
/// The `pg_stat_user_tables` view will contain one row for each user table in the current database,
19+
/// showing statistics about accesses to that specific table.
20+
/// Ref: [`https://www.postgresql.org/docs/current/monitoring-stats.html#MONITORING-PG-STAT-ALL-TABLES-VIEW`]
21+
#[system_catalog(
22+
view,
23+
"pg_catalog.pg_stat_user_tables",
24+
"SELECT
25+
rr.id as relid,
26+
rs.name as schemaname,
27+
rr.name as relname,
28+
NULL::bigint as seq_scan,
29+
NULL::timestamptz as last_seq_scan,
30+
NULL::bigint as seq_tup_read,
31+
NULL::bigint as idx_scan,
32+
NULL::timestamptz as last_idx_scan,
33+
NULL::bigint as idx_tup_fetch,
34+
NULL::bigint as n_tup_ins,
35+
NULL::bigint as n_tup_del,
36+
NULL::bigint as n_tup_hot_upd,
37+
NULL::bigint as n_tup_newpage_upd,
38+
rts.total_key_count as n_live_tup,
39+
NULL::bigint as n_dead_tup,
40+
NULL::bigint as n_mod_since_analyze,
41+
NULL::bigint as n_ins_since_vacuum,
42+
NULL::timestamptz as last_vacuum,
43+
NULL::timestamptz as last_autovacuum,
44+
NULL::timestamptz as last_analyze,
45+
NULL::timestamptz as last_autoanalyze,
46+
NULL::bigint as vacuum_count,
47+
NULL::bigint as autovacuum_count,
48+
NULL::bigint as analyze_count,
49+
NULL::bigint as autoanalyze_count
50+
FROM
51+
rw_relations rr
52+
left join rw_table_stats rts on rr.id = rts.id
53+
join rw_schemas rs on schema_id = rs.id
54+
WHERE
55+
rs.name != 'rw_catalog'
56+
AND rs.name != 'pg_catalog'
57+
AND rs.name != 'information_schema'
58+
"
59+
)]
60+
#[derive(Fields)]
61+
struct PgStatUserTables {
62+
relid: i32,
63+
schemaname: String,
64+
relname: String,
65+
seq_scan: i64,
66+
last_seq_scan: Timestamptz,
67+
seq_tup_read: i64,
68+
idx_scan: i64,
69+
last_idx_scan: Timestamptz,
70+
idx_tup_fetch: i64,
71+
n_tup_ins: i64,
72+
n_tup_del: i64,
73+
n_tup_hot_upd: i64,
74+
n_tup_newpage_upd: i64,
75+
n_live_tup: i64,
76+
n_dead_tup: i64,
77+
n_mod_since_analyze: i64,
78+
n_ins_since_vacuum: i64,
79+
last_vacuum: Timestamptz,
80+
last_autovacuum: Timestamptz,
81+
last_analyze: Timestamptz,
82+
last_autoanalyze: Timestamptz,
83+
vacuum_count: i64,
84+
autovacuum_count: i64,
85+
analyze_count: i64,
86+
autoanalyze_count: i64,
87+
}

0 commit comments

Comments
 (0)