-
Notifications
You must be signed in to change notification settings - Fork 592
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
hzxa21
wants to merge
7
commits into
main
Choose a base branch
from
patrick/metabase-catalog-fix
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
+227
−16
Open
Changes from 6 commits
Commits
Show all changes
7 commits
Select commit
Hold shift + click to select a range
70bccbd
feat: support pg_stat_user_tables and key_column_usage
hzxa21 0bd35d5
save
hzxa21 512def1
add e2e test for information schema
hzxa21 ed28d4d
fix pg_class.slt
hzxa21 002ea06
not check db in e2e
hzxa21 452d006
fix e2e
hzxa21 44ef0b5
fix typo
hzxa21 File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 TT | ||
select table_schema, table_name from information_schema.views where table_schema = 'public'; | ||
---- | ||
public v | ||
|
||
query TT | ||
select table_schema, table_name from information_schema.tables where table_schema = 'public' order by table_name; | ||
---- | ||
public mv | ||
public t | ||
public v | ||
|
||
query TTTTTTTT | ||
select constraint_schema, constraint_name, table_schema, table_name from information_schema.table_constraints where table_schema = 'public' order by table_name; | ||
---- | ||
public mv_pkey public mv | ||
public t_pkey public t | ||
|
||
query TT | ||
select schema_name from information_schema.schemata order by schema_name; | ||
---- | ||
information_schema | ||
pg_catalog | ||
public | ||
rw_catalog | ||
|
||
query TTTTTII | ||
select * EXCEPT(constraint_catalog, table_catalog) from information_schema.key_column_usage where table_schema = 'public' order by table_name; | ||
---- | ||
public mv_pkey public mv key 3 NULL | ||
public t_pkey public t key 3 NULL | ||
|
||
query TTTITTT | ||
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; | ||
---- | ||
public mv a 1 integer pg_catalog int4 | ||
public mv b 2 bigint pg_catalog int8 | ||
public mv key 3 integer pg_catalog int4 | ||
public t a 1 integer pg_catalog int4 | ||
public t b 2 bigint pg_catalog int8 | ||
public t key 3 integer pg_catalog int4 | ||
public v a 1 integer pg_catalog int4 | ||
public v b 2 bigint pg_catalog int8 | ||
public v key 3 integer pg_catalog int4 | ||
|
||
|
||
statement ok | ||
drop materialized view mv; | ||
|
||
statement ok | ||
drop view v; | ||
|
||
statement ok | ||
drop table t; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
59 changes: 59 additions & 0 deletions
59
src/frontend/src/catalog/system_catalog/information_schema/key_column_usage.rs
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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, | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
87 changes: 87 additions & 0 deletions
87
src/frontend/src/catalog/system_catalog/pg_catalog/pg_stat_user_tables.rs
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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, | ||
} |
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
There's a typo in the comment:
primrary
should beprimary
in the limitation note. Also, there's a typo inpg_clatalog
which should bepg_catalog
.The corrected comment should read: "...since
pg_catalog.pg_constraint
only supports primary key."Spotted by Graphite Reviewer
Is this helpful? React 👍 or 👎 to let us know.