From 2b51211d77421102709f4cfff28325e179902891 Mon Sep 17 00:00:00 2001 From: zhubin79 <18784715772@163.com> Date: Thu, 24 Apr 2025 11:36:07 +0800 Subject: [PATCH] =?UTF-8?q?D=20=E5=BA=93=E5=B8=B8=E7=94=A8=E8=A7=86?= =?UTF-8?q?=E5=9B=BE=E5=85=BC=E5=AE=B9?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- contrib/shark/expected/test_sysviews.out | 546 +++++++++++++++++ contrib/shark/shark--1.0.sql | 708 +++++++++++++++++++++++ contrib/shark/sql/test_sysviews.sql | 161 ++++++ 3 files changed, 1415 insertions(+) diff --git a/contrib/shark/expected/test_sysviews.out b/contrib/shark/expected/test_sysviews.out index bf40fe48ef..8f316bb9fb 100644 --- a/contrib/shark/expected/test_sysviews.out +++ b/contrib/shark/expected/test_sysviews.out @@ -351,6 +351,552 @@ drop table school_department; drop table class; drop table teacher; drop table student; +-- test sys views +\d sys.all_objects + View "sys.all_objects" + Column | Type | Modifiers +---------------------+-----------------------------+----------- + name | name | + object_id | oid | + principal_id | oid | + schema_id | oid | + parent_object_id | oid | + type | bpchar | + type_desc | nvarchar2 | + create_date | timestamp without time zone | + modify_date | timestamp without time zone | + is_ms_shipped | "bit" | + is_published | "bit" | + is_schema_published | "bit" | + +\d sys.objects + View "sys.objects" + Column | Type | Modifiers +---------------------+-----------------------------+----------- + name | name | + object_id | oid | + principal_id | oid | + schema_id | oid | + parent_object_id | oid | + type | bpchar | + type_desc | nvarchar2 | + create_date | timestamp without time zone | + modify_date | timestamp without time zone | + is_ms_shipped | "bit" | + is_published | "bit" | + is_schema_published | "bit" | + +\d sys.tables + View "sys.tables" + Column | Type | Modifiers +------------------------------------+-----------------------------+----------- + name | name | + object_id | oid | + principal_id | oid | + schema_id | oid | + parent_object_id | oid | + type | bpchar | + type_desc | nvarchar2 | + create_date | timestamp without time zone | + modify_date | timestamp without time zone | + is_ms_shipped | "bit" | + is_published | "bit" | + is_schema_published | "bit" | + lob_data_space_id | oid | + filestream_data_space_id | integer | + max_column_id_used | integer | + lock_on_bulk_load | bit(1) | + uses_ansi_nulls | bit(1) | + is_replicated | bit(1) | + has_replication_filter | bit(1) | + is_merge_published | bit(1) | + is_sync_tran_subscribed | bit(1) | + has_unchecked_assembly_data | bit(1) | + text_in_row_limit | integer | + large_value_types_out_of_row | bit(1) | + is_tracked_by_cdc | tinyint | + lock_escalation | tinyint | + lock_escalation_desc | nvarchar2(60) | + is_filetable | bit(1) | + is_memory_optimized | "bit" | + durability | tinyint | + durability_desc | nvarchar2(60) | + temporal_type | tinyint | + temporal_type_desc | nvarchar2(60) | + history_table_id | integer | + is_remote_data_archive_enabled | bit(1) | + is_external | bit(1) | + history_retention_period | integer | + history_retention_period_unit | integer | + history_retention_period_unit_desc | nvarchar2(10) | + is_node | bit(1) | + is_edge | bit(1) | + +\d sys.views + View "sys.views" + Column | Type | Modifiers +-----------------------------+-----------------------------+----------- + name | name | + object_id | oid | + principal_id | oid | + schema_id | oid | + parent_object_id | oid | + type | character(2) | + type_desc | nvarchar2(60) | + create_date | timestamp without time zone | + modify_date | timestamp without time zone | + is_ms_shipped | bit(1) | + is_published | bit(1) | + is_schema_published | bit(1) | + is_replicated | bit(1) | + has_replication_filter | bit(1) | + has_opaque_metadata | bit(1) | + has_unchecked_assembly_data | bit(1) | + with_check_option | bit(1) | + is_date_correlation_view | bit(1) | + +\d sys.all_columns + View "sys.all_columns" + Column | Type | Modifiers +----------------------------+---------------+----------- + object_id | oid | + name | name | + column_id | integer | + system_type_id | oid | + user_type_id | oid | + max_length | smallint | + precision | smallint | + scale | smallint | + collation_name | name | + is_nullable | bit(1) | + is_ansi_padded | bit(1) | + is_rowguidcol | bit(1) | + is_identity | bit(1) | + is_computed | bit(1) | + is_filestream | bit(1) | + is_replicated | "bit" | + is_non_sql_subscribed | bit(1) | + is_merge_published | bit(1) | + is_dts_replicated | bit(1) | + is_xml_document | bit(1) | + xml_collection_id | oid | + default_object_id | oid | + rule_object_id | integer | + is_sparse | bit(1) | + is_column_set | bit(1) | + generated_always_type | tinyint | + generated_always_type_desc | nvarchar2(60) | + +\d sys.columns + View "sys.columns" + Column | Type | Modifiers +-------------------------------------+---------------+----------- + object_id | oid | + name | name | + column_id | integer | + system_type_id | oid | + user_type_id | oid | + max_length | smallint | + precision | smallint | + scale | smallint | + collation_name | name | + is_nullable | bit(1) | + is_ansi_padded | bit(1) | + is_rowguidcol | bit(1) | + is_identity | bit(1) | + is_computed | bit(1) | + is_filestream | bit(1) | + is_replicated | "bit" | + is_non_sql_subscribed | bit(1) | + is_merge_published | bit(1) | + is_dts_replicated | bit(1) | + is_xml_document | bit(1) | + xml_collection_id | oid | + default_object_id | oid | + rule_object_id | integer | + is_sparse | bit(1) | + is_column_set | bit(1) | + generated_always_type | tinyint | + generated_always_type_desc | nvarchar2(60) | + encryption_type | integer | + encryption_type_desc | nvarchar2(64) | + encryption_algorithm_name | name | + column_encryption_key_id | oid | + column_encryption_key_database_name | name | + is_hidden | bit(1) | + is_masked | bit(1) | + graph_type | integer | + graph_type_desc | nvarchar2(60) | + +\d sys.indexes + View "sys.indexes" + Column | Type | Modifiers +---------------------------+-------------------+----------- + object_id | oid | + name | name | + index_id | oid | + type | tinyint | + type_desc | nvarchar2(60) | + is_unique | bit(1) | + data_space_id | oid | + ignore_dup_key | bit(1) | + is_primary_key | bit(1) | + is_unique_constraint | bit(1) | + fill_factor | tinyint | + is_padded | bit(1) | + is_disabled | bit(1) | + is_hypothetical | bit(1) | + allow_row_locks | bit(1) | + allow_page_locks | bit(1) | + has_filter | bit(1) | + filter_definition | character varying | + compression_delay | integer | + suppress_dup_key_messages | bit(1) | + +\d sys.procedures + View "sys.procedures" + Column | Type | Modifiers +---------------------------+-----------------------------+----------- + name | name | + object_id | oid | + principal_id | oid | + schema_id | oid | + parent_object_id | oid | + type | bpchar | + type_desc | nvarchar2 | + create_date | timestamp without time zone | + modify_date | timestamp without time zone | + is_ms_shipped | "bit" | + is_published | "bit" | + is_schema_published | "bit" | + is_auto_executed | bit(1) | + is_execution_replicated | bit(1) | + is_repl_serializable_only | bit(1) | + skips_repl_constraints | bit(1) | + +drop table if exists t_index; +NOTICE: table "t_index" does not exist, skipping +create table t_index (id int primary key, c2 int not null, c3 char(1), c4 text, c5 numeric(10, 2)); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "t_index_pkey" for table "t_index" +create unique index t_index_c2_uind on t_index(c2); +create index t_index_c3_c2_ind on t_index(c3, c2); +create index t_index_func_c4_ind on t_index(lower(c4)); +create index t_index_hash_c3_ind on t_index using hash(c3); +create index t_index_filter_c5_ind on t_index (c5) where c5 > 100.00; +drop table if exists t_foreign1; +NOTICE: table "t_foreign1" does not exist, skipping +create table t_foreign1 (f_id int primary key, f_name text not null, f_age int default 18); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "t_foreign1_pkey" for table "t_foreign1" +-- foreign key, check constraint +drop table if exists t_foreign2; +NOTICE: table "t_foreign2" does not exist, skipping +create table t_foreign2 (f_id int primary key not null, f_c2 int references t_foreign1(f_id), f_salary real check(f_salary > 0)); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "t_foreign2_pkey" for table "t_foreign2" +-- columns table +create table t_column (c1 int, c2 text, c3 char(1), constraint t_stats_col_pk primary key (c1)) with (orientation = column); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "t_stats_col_pk" for table "t_column" +-- temporal table +create temp table t_temp_table as select * from t_index; +-- view +drop view if exists v_normal; +NOTICE: view "v_normal" does not exist, skipping +create view v_normal as select * from t_index; +-- view with check option +drop view if exists v_check; +NOTICE: view "v_check" does not exist, skipping +create view v_check as select * from t_index where id > 10 with check option; +-- materialized view +drop materialized view if exists mv_normal; +NOTICE: materialized view "mv_normal" does not exist, skipping +create materialized view mv_normal as select * from t_foreign1; +-- sequence +create sequence if not exists seq_order + increment by 1 + start with 1 + nocycle; +select seq_order.nextval; + nextval +--------- + 1 +(1 row) + +create table t_orders (order_id int primary key default nextval('seq_order'), order_date date); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "t_orders_pkey" for table "t_orders" +-- synonym +create synonym syn_tbl for t_orders; +-- trigger +create table t_tg_src (c1 int, c2 int, c3 int); +create table t_tg_des (c1 int, c2 int, c3 int); +create or replace function tri_insert_func() returns trigger as +$$ +begin + insert into t_tg_des values (NEW.c1, NEW.c2, NEW.c3); + return NEW; +end +$$ language plpgsql; +create trigger insert_trigger +before insert on t_tg_src +for each row +execute procedure tri_insert_func(); +-- function +create or replace function test_sub(a int, b int) returns int as $$ +begin + return a - b; +end; +$$ language plpgsql; +-- procedure +create or replace procedure test_sum(in a int, in b int, out c int) as +begin + c = a + b; +end; +/ +select name, s.nspname, po.relname, type, type_desc, is_ms_shipped, is_published, is_schema_published +from sys.all_objects o +inner join pg_namespace s on o.schema_id = s.oid +left join pg_class po on po.oid = parent_object_id +where s.nspname = 'sys_view_test' +order by object_id; + name | nspname | relname | type | type_desc | is_ms_shipped | is_published | is_schema_published +---------------------------+---------------+------------+------+------------------------+---------------+--------------+--------------------- + t_seq | sys_view_test | | SO | SEQUENCE_OBJECT | 0 | 0 | 0 + tg_log | sys_view_test | | FN | SQL_SCALAR_FUNCTION | 0 | 0 | 0 + t_index | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_index_pkey | sys_view_test | t_index | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + t_foreign1 | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + | sys_view_test | t_foreign1 | D | DE | 0 | 0 | 0 + t_foreign1_pkey | sys_view_test | t_foreign1 | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + t_foreign2 | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_foreign2_f_salary_check | sys_view_test | t_foreign2 | C | CHECK_CONSTRAINT | 0 | 0 | 0 + t_foreign2_pkey | sys_view_test | t_foreign2 | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + t_foreign2_f_c2_fkey | sys_view_test | t_foreign2 | F | FOREIGN_KEY_CONSTRAINT | 0 | 0 | 0 + t_column | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_stats_col_pk | sys_view_test | t_column | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + v_normal | sys_view_test | | V | VIEW | 0 | 0 | 0 + v_check | sys_view_test | | V | VIEW | 0 | 0 | 0 + mv_normal | sys_view_test | | V | VIEW | 0 | 0 | 0 + seq_order | sys_view_test | | SO | SEQUENCE_OBJECT | 0 | 0 | 0 + t_orders | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + | sys_view_test | t_orders | D | DE | 0 | 0 | 0 + t_orders_pkey | sys_view_test | t_orders | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + syn_tbl | sys_view_test | | SN | SYNONYM | 0 | 0 | 0 + t_tg_src | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_tg_des | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + tri_insert_func | sys_view_test | | FN | SQL_SCALAR_FUNCTION | 0 | 0 | 0 + test_sub | sys_view_test | | FN | SQL_SCALAR_FUNCTION | 0 | 0 | 0 + test_sum | sys_view_test | | P | SQL_STORED_PROCEDURE | 0 | 0 | 0 +(26 rows) + +select name, s.nspname, po.relname, type, type_desc, is_ms_shipped, is_published, is_schema_published +from sys.objects o +inner join pg_namespace s on o.schema_id = s.oid +left join pg_class po on po.oid = parent_object_id +where s.nspname = 'sys_view_test' +order by object_id; + name | nspname | relname | type | type_desc | is_ms_shipped | is_published | is_schema_published +---------------------------+---------------+------------+------+------------------------+---------------+--------------+--------------------- + t_seq | sys_view_test | | SO | SEQUENCE_OBJECT | 0 | 0 | 0 + t_index | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_index_pkey | sys_view_test | t_index | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + t_foreign1 | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + | sys_view_test | t_foreign1 | D | DE | 0 | 0 | 0 + t_foreign1_pkey | sys_view_test | t_foreign1 | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + t_foreign2 | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_foreign2_f_salary_check | sys_view_test | t_foreign2 | C | CHECK_CONSTRAINT | 0 | 0 | 0 + t_foreign2_pkey | sys_view_test | t_foreign2 | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + t_foreign2_f_c2_fkey | sys_view_test | t_foreign2 | F | FOREIGN_KEY_CONSTRAINT | 0 | 0 | 0 + t_column | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_stats_col_pk | sys_view_test | t_column | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + v_normal | sys_view_test | | V | VIEW | 0 | 0 | 0 + v_check | sys_view_test | | V | VIEW | 0 | 0 | 0 + mv_normal | sys_view_test | | V | VIEW | 0 | 0 | 0 + seq_order | sys_view_test | | SO | SEQUENCE_OBJECT | 0 | 0 | 0 + t_orders | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + | sys_view_test | t_orders | D | DE | 0 | 0 | 0 + t_orders_pkey | sys_view_test | t_orders | PK | PRIMARY_KEY_CONSTRAINT | 0 | 0 | 0 + syn_tbl | sys_view_test | | SN | Synonym | 0 | 0 | 0 + t_tg_src | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + t_tg_des | sys_view_test | | U | USER_TABLE | 0 | 0 | 0 + test_sum | sys_view_test | | P | SQL_STORED_PROCEDURE | 0 | 0 | 0 +(23 rows) + +select + name, s.nspname, type, type_desc, is_ms_shipped, is_published, is_schema_published, + max_column_id_used, uses_ansi_nulls, is_replicated, is_memory_optimized, durability, durability_desc, temporal_type, temporal_type_desc +from sys.tables t +inner join pg_namespace s on t.schema_id = s.oid +where s.nspname = 'sys_view_test' +order by object_id; + name | nspname | type | type_desc | is_ms_shipped | is_published | is_schema_published | max_column_id_used | uses_ansi_nulls | is_replicated | is_memory_optimized | durability | durability_desc | temporal_type | temporal_type_desc +------------+---------------+------+------------+---------------+--------------+---------------------+--------------------+-----------------+---------------+---------------------+------------+-----------------+---------------+-------------------- + t_index | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 5 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE + t_foreign1 | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 3 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE + t_foreign2 | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 3 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE + t_column | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 3 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE + t_orders | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 2 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE + t_tg_src | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 3 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE + t_tg_des | sys_view_test | U | USER_TABLE | 0 | 0 | 0 | 3 | 1 | 1 | 0 | 0 | SCHEMA_AND_DATA | 0 | NON_TEMPORAL_TABLE +(7 rows) + +select name, s.nspname, type, type_desc, is_ms_shipped, is_published, is_schema_published, with_check_option +from sys.views v +inner join pg_namespace s on v.schema_id = s.oid +where s.nspname = 'sys_view_test' +order by object_id; + name | nspname | type | type_desc | is_ms_shipped | is_published | is_schema_published | with_check_option +-----------+---------------+------+-----------+---------------+--------------+---------------------+------------------- + v_normal | sys_view_test | V | VIEW | 0 | 0 | 0 | 0 + v_check | sys_view_test | V | VIEW | 0 | 0 | 0 | 1 + mv_normal | sys_view_test | V | VIEW | 0 | 0 | 0 | 0 +(3 rows) + +select t.relname, c.name, column_id, max_length, precision, scale, is_nullable, is_computed, is_replicated, generated_always_type, generated_always_type_desc +from sys.all_columns c +inner join pg_class t on c.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' +order by object_id, column_id; + relname | name | column_id | max_length | precision | scale | is_nullable | is_computed | is_replicated | generated_always_type | generated_always_type_desc +------------+------------+-----------+------------+-----------+-------+-------------+-------------+---------------+-----------------------+---------------------------- + t_index | id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c2 | 2 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c4 | 4 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c5 | 5 | 15 | 10 | 2 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign1 | f_id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign1 | f_name | 2 | -1 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign1 | f_age | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign2 | f_id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign2 | f_c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign2 | f_salary | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_column | c1 | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_column | c2 | 2 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_column | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | id | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c4 | 4 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c5 | 5 | 15 | 10 | 2 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | id | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c4 | 4 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c5 | 5 | 15 | 10 | 2 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + mv_normal | f_id | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + mv_normal | f_name | 2 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + mv_normal | f_age | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_orders | order_id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_orders | order_date | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_src | c1 | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_src | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_src | c3 | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_des | c1 | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_des | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_des | c3 | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE +(35 rows) + +select t.relname, c.name, column_id, max_length, precision, scale, is_nullable, is_computed, is_replicated, generated_always_type, generated_always_type_desc +from sys.columns c +inner join pg_class t on c.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' +order by object_id, column_id; + relname | name | column_id | max_length | precision | scale | is_nullable | is_computed | is_replicated | generated_always_type | generated_always_type_desc +------------+------------+-----------+------------+-----------+-------+-------------+-------------+---------------+-----------------------+---------------------------- + t_index | id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c2 | 2 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c4 | 4 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_index | c5 | 5 | 15 | 10 | 2 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign1 | f_id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign1 | f_name | 2 | -1 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign1 | f_age | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign2 | f_id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign2 | f_c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_foreign2 | f_salary | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_column | c1 | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_column | c2 | 2 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_column | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | id | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c4 | 4 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_normal | c5 | 5 | 15 | 10 | 2 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | id | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c3 | 3 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c4 | 4 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + v_check | c5 | 5 | 15 | 10 | 2 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + mv_normal | f_id | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + mv_normal | f_name | 2 | -1 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + mv_normal | f_age | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_orders | order_id | 1 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | NOT_APPLICABLE + t_orders | order_date | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_src | c1 | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_src | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_src | c3 | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_des | c1 | 1 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_des | c2 | 2 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE + t_tg_des | c3 | 3 | 4 | 0 | 0 | 1 | 0 | 0 | 0 | NOT_APPLICABLE +(35 rows) + +select t.relname, name, i.type, type_desc, i.is_unique, is_primary_key, is_unique_constraint, fill_factor, is_disabled, has_filter, filter_definition +from sys.indexes i +inner join pg_class t on i.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' +order by index_id; + relname | name | type | type_desc | is_unique | is_primary_key | is_unique_constraint | fill_factor | is_disabled | has_filter | filter_definition +------------+-----------------------+------+--------------------------+-----------+----------------+----------------------+-------------+-------------+------------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + t_index | t_index_pkey | 2 | NONCLUSTERED | 1 | 1 | 0 | 0 | 0 | 0 | + t_index | t_index_c2_uind | 2 | NONCLUSTERED | 1 | 0 | 0 | 0 | 0 | 0 | + t_index | t_index_c3_c2_ind | 2 | NONCLUSTERED | 0 | 0 | 0 | 0 | 0 | 0 | + t_index | t_index_func_c4_ind | 2 | NONCLUSTERED | 0 | 0 | 0 | 0 | 0 | 0 | + t_index | t_index_hash_c3_ind | 7 | NONCLUSTERED HASH | 0 | 0 | 0 | 0 | 0 | 0 | + t_index | t_index_filter_c5_ind | 2 | NONCLUSTERED | 0 | 0 | 0 | 0 | 0 | 1 | {OPEXPR :opno 1756 :opfuncid 1720 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 0 :args ({VAR :varno 1 :varattno 5 :vartype 1700 :vartypmod 655366 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 5 :location 57} {CONST :consttype 1700 :consttypmod -1 :constcollid 0 :constlen -1 :constbyval false :constisnull false :ismaxvalue false :location 62 :constvalue 8 [ 32 0 0 0 0 -127 100 0 ] :cursor_data :row_count 0 :cur_dno -1 :is_open false :found false :not_found false :null_open false :null_fetch false}) :location 60} + t_foreign1 | t_foreign1_pkey | 2 | NONCLUSTERED | 1 | 1 | 0 | 0 | 0 | 0 | + t_foreign2 | t_foreign2_pkey | 2 | NONCLUSTERED | 1 | 1 | 0 | 0 | 0 | 0 | + t_column | t_stats_col_pk | 6 | NONCLUSTERED COLUMNSTORE | 1 | 1 | 0 | 0 | 0 | 0 | + t_orders | t_orders_pkey | 2 | NONCLUSTERED | 1 | 1 | 0 | 0 | 0 | 0 | +(10 rows) + +select name, s.nspname, type, type_desc, is_ms_shipped, is_published +from sys.procedures p +inner join pg_namespace s on p.schema_id = s.oid +where s.nspname = 'sys_view_test' +order by object_id; + name | nspname | type | type_desc | is_ms_shipped | is_published +----------+---------------+------+----------------------+---------------+-------------- + test_sum | sys_view_test | P | SQL_STORED_PROCEDURE | 0 | 0 +(1 row) + +-- disable index +alter index t_index_func_c4_ind disable; +select t.relname, name, i.type, type_desc, is_disabled +from sys.indexes i +inner join pg_class t on i.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' and name = 't_index_func_c4_ind'; + relname | name | type | type_desc | is_disabled +---------+---------------------+------+--------------+------------- + t_index | t_index_func_c4_ind | 2 | NONCLUSTERED | 1 +(1 row) + +drop procedure test_sum; +drop function test_sub; +drop table t_tg_des; +drop table t_tg_src; +drop function tri_insert_func; +drop synonym syn_tbl; +drop table t_orders; +drop sequence seq_order; +drop materialized view mv_normal; +drop view v_check; +drop view v_normal; +drop table t_temp_table; +drop table t_column; +drop table t_foreign2; +drop table t_foreign1; +drop table t_index; reset search_path; drop schema sys_view_test cascade; NOTICE: drop cascades to 2 other objects diff --git a/contrib/shark/shark--1.0.sql b/contrib/shark/shark--1.0.sql index f371d9b850..6fc2368f08 100644 --- a/contrib/shark/shark--1.0.sql +++ b/contrib/shark/shark--1.0.sql @@ -556,4 +556,712 @@ lateral ( where has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c_tab.relname), 'SELECT'); grant select on sys.sysindexkeys to public; +create or replace function sys.ts_is_mot_table_helper(in reloid oid) +returns bit as $$ + select case ( + select w.fdwname from pg_foreign_table t + left join pg_foreign_server s on t.ftserver = s.oid + left join pg_foreign_data_wrapper w on s.srvfdw = w.oid + where t.ftrelid = reloid) + when 'mot_fdw' then 1::bit + else 0::bit end; +$$ language sql; + +create or replace function sys.ts_is_publication_helper(in relid oid) +returns bit as $$ + select case + when (select 1 from pg_publication_rel where prrelid = relid) = 1 then 1::bit + else 0::bit end; +$$ language sql; + +create or replace function sys.ts_graph_type_helper(in relid oid, in typ text) +returns boolean as $$ +begin + if not (select exists (select 1 from pg_extension where extname = 'age')) then + return false; + end if; + + return (select exists( + select 1 from ag_catalog.ag_label ag inner join pg_class c on c.oid = ag.relation where c.oid = relid and ag.kind = typ + )); +end +$$ language plpgsql; + +create or replace function sys.ts_tables_obj_internal() +returns table ( + out_name name, + out_object_id oid, + out_principal_id oid, + out_schema_id oid, + out_schema_name name, + out_parent_object_id oid, + out_type char(2), + out_type_desc nvarchar(60), + out_create_date timestamp, + out_modify_date timestamp, + out_ms_shipped bit, + out_published bit, + out_schema_published bit +) +as $$ +begin +return query +select + t.relname, + t.oid, + cast(case s.nspowner when t.relowner then null else t.relowner end as oid), + s.oid, + s.nspname, + cast(0 as oid), + cast(case s.nspname + when 'information_schema' then 'S' + when 'pg_catalog' then 'S' + else 'U' end as char(2)), + cast(case s.nspname + when 'information_schema' then 'SYSTEM_TABLE' + when 'pg_catalog' then 'SYSTEM_TABLE' + else 'USER_TABLE' end as nvarchar(60)), + cast(o.ctime as timestamp), + cast(o.mtime as timestamp), + cast(case s.nspname + when 'information_schema' then 1 + when 'pg_catalog' then 1 + else 0 end as bit), + ts_is_publication_helper(t.oid), + cast(0 as bit) +from pg_class t +inner join pg_namespace s on s.oid = t.relnamespace +inner join pg_object o on o.object_oid = t.oid +where t.relpersistence in ('p', 'u', 't') +and t.relkind = 'r' +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(t.relname), 'SELECT'); +end $$ +language plpgsql; + +create or replace view sys.tables as +select + ti.out_name as name, + ti.out_object_id as object_id, + ti.out_principal_id as principal_id, + ti.out_schema_id as schema_id, + ti.out_parent_object_id as parent_object_id, + ti.out_type as type, + ti.out_type_desc as type_desc, + ti.out_create_date as create_date, + ti.out_modify_date as modify_date, + ti.out_ms_shipped as is_ms_shipped, + ti.out_published as is_published, + ti.out_schema_published as is_schema_published, + t.reltoastrelid as lob_data_space_id, + cast(null as int) as filestream_data_space_id, + cast(t.relnatts as int) as max_column_id_used, + cast(0 as bit) as lock_on_bulk_load, + cast(1 as bit) as uses_ansi_nulls, + cast(1 as bit) as is_replicated, + cast(0 as bit) as has_replication_filter, + cast(0 as bit) as is_merge_published, + cast(0 as bit) as is_sync_tran_subscribed, + cast(0 as bit) as has_unchecked_assembly_data, + cast(0 as int) as text_in_row_limit, + cast(0 as bit) as large_value_types_out_of_row, + cast(0 as tinyint) as is_tracked_by_cdc, + cast(1 as tinyint) as lock_escalation, + cast('DISABLE' as nvarchar(60)) as lock_escalation_desc, + cast(0 as bit) as is_filetable, + sys.ts_is_mot_table_helper(t.oid) as is_memory_optimized, + cast(0 as tinyint) as durability, + cast('SCHEMA_AND_DATA' as nvarchar(60)) as durability_desc, + cast(case t.relpersistence when 't' then 2 else 0 end as tinyint) as temporal_type, + cast(case t.relpersistence when 't' then 'SYSTEM_VERSIONED_TEMPORAL_TABLE' else 'NON_TEMPORAL_TABLE' end as nvarchar(60)) as temporal_type_desc, + cast(null as int) as history_table_id, + cast(0 as bit) as is_remote_data_archive_enabled, + cast(case t.relkind when 'f' then 1 else 0 end as bit) as is_external, + cast(0 as int) as history_retention_period, + cast(-1 as int) as history_retention_period_unit, + cast('INFINITE' as nvarchar(10)) as history_retention_period_unit_desc, + cast(case when sys.ts_graph_type_helper(t.oid, 'v') then 1 else 0 end as bit) as is_node, + cast(case when sys.ts_graph_type_helper(t.oid, 'e') then 1 else 0 end as bit) as is_edge +from sys.ts_tables_obj_internal() ti +inner join pg_class t on ti.out_object_id = t.oid +where ti.out_type = 'U' and ti.out_schema_name not in ('cstore', 'pg_toast'); + +create or replace view sys.views as +select + t.relname as name, + t.oid as object_id, + cast(case s.nspowner when t.relowner then null else t.relowner end as oid) as principal_id, + s.oid as schema_id, + cast(0 as oid) as parent_object_id, + cast('V' as char(2)) as type, + cast('VIEW' as nvarchar(60)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published, + cast(0 as bit) as is_replicated, + cast(0 as bit) as has_replication_filter, + cast(0 as bit) as has_opaque_metadata, + cast(0 as bit) as has_unchecked_assembly_data, + cast(case when sys.tsql_relation_reloptions_helper(t.reloptions, 'check_option') is null then 0 else 1 end as bit) as with_check_option, + cast(0 as bit) as is_date_correlation_view +from pg_class t +inner join pg_namespace s on t.relnamespace = s.oid +inner join pg_object o on o.object_oid = t.oid +where t.relkind in ('v', 'm') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(t.relname), 'SELECT') +and s.nspname not in ('information_schema', 'pg_catalog', 'dbe_perf'); + +create or replace function sys.ts_numeric_precision_helper(in typname text, in typmod int) +returns smallint as $$ +declare + prec smallint := 0; +begin + if typmod = -1 then + return 0; + end if; + + case lower(typname) + when 'numeric' then prec := ((typmod - 4) >> 16) & 65535; + when 'decimal' then prec := ((typmod - 4) >> 16) & 65535; + else prec := 0; + end case; + + return prec; +end; +$$ language plpgsql; + +create or replace function sys.ts_numeric_scale_helper(in typname text, in typmod int) +returns smallint as $$ +declare + scale smallint := 0; +begin + if typmod = -1 then + return 0; + end if; + + case lower(typname) + when 'numeric' then scale := (typmod - 4) & 65535; + when 'decimal' then scale := (typmod - 4) & 65535; + else scale := 0; + end case; + + return scale; +end; +$$ language plpgsql; + +create or replace view sys.all_columns as +select + a.attrelid as object_id, + a.attname as name, + cast(a.attnum as int) as column_id, + a.atttypid as system_type_id, + a.atttypid as user_type_id, + sys.tsql_type_max_length_helper(t.typname, a.attlen, a.atttypmod) as max_length, + sys.ts_numeric_precision_helper(t.typname, a.atttypmod) as precision, + sys.ts_numeric_scale_helper(t.typname, a.atttypmod) as scale, + coll.collname as collation_name, + cast(case a.attnotnull when 't' then 0 else 1 end as bit) as is_nullable, + cast(0 as bit) as is_ansi_padded, + cast(0 as bit) as is_rowguidcol, + cast(0 as bit) as is_identity, + cast(case when d.adgencol = 'p' then 1 else 0 end as bit) as is_computed, + cast(0 as bit) as is_filestream, + sys.ts_is_publication_helper(a.attrelid) as is_replicated, + cast(0 as bit) as is_non_sql_subscribed, + cast(0 as bit) as is_merge_published, + cast(0 as bit) as is_dts_replicated, + cast(0 as bit) as is_xml_document, + cast(0 as oid) as xml_collection_id, + d.oid as default_object_id, + cast(0 as int) as rule_object_id, + cast(0 as bit) as is_sparse, + cast(0 as bit) as is_column_set, + cast(0 as tinyint) as generated_always_type, + cast('NOT_APPLICABLE' as nvarchar(60)) as generated_always_type_desc +from pg_attribute a +inner join pg_class c on c.oid = attrelid +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_type t on t.oid = a.atttypid +left join pg_attrdef d on a.attrelid = d.adrelid and a.attnum = d.adnum +left join pg_collation coll on coll.oid = a.attcollation +where not a.attisdropped and a.attnum > 0 +and c.relkind in ('r', 'v', 'm', 'f') +and has_column_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), a.attname, 'SELECT'); + +create or replace view sys.columns as +select + a.attrelid as object_id, + a.attname as name, + cast(a.attnum as int) as column_id, + a.atttypid as system_type_id, + a.atttypid as user_type_id, + sys.tsql_type_max_length_helper(t.typname, a.attlen, a.atttypmod) as max_length, + sys.ts_numeric_precision_helper(t.typname, a.atttypmod) as precision, + sys.ts_numeric_scale_helper(t.typname, a.atttypmod) as scale, + coll.collname as collation_name, + cast(case a.attnotnull when 't' then 0 else 1 end as bit) as is_nullable, + cast(0 as bit) as is_ansi_padded, + cast(0 as bit) as is_rowguidcol, + cast(0 as bit) as is_identity, + cast(case when d.adgencol = 's' then 1 else 0 end as bit) as is_computed, + cast(0 as bit) as is_filestream, + sys.ts_is_publication_helper(a.attrelid) as is_replicated, + cast(0 as bit) as is_non_sql_subscribed, + cast(0 as bit) as is_merge_published, + cast(0 as bit) as is_dts_replicated, + cast(0 as bit) as is_xml_document, + cast(0 as oid) as xml_collection_id, + d.oid as default_object_id, + cast(0 as int) as rule_object_id, + cast(0 as bit) as is_sparse, + cast(0 as bit) as is_column_set, + cast(0 as tinyint) as generated_always_type, + cast('NOT_APPLICABLE' as nvarchar(60)) as generated_always_type_desc, + cast(case e.encryption_type when 2 then 1 else 2 end as int) as encryption_type, + cast(case e.encryption_type when 2 then 'RANDOMIZED' else 'DETERMINISTIC' end as nvarchar(64)) as encryption_type_desc, + cast((select value from gs_column_keys_args where column_key_id = e.column_key_id and key = 'ALGORITHM') as name) as encryption_algorithm_name, + e.column_key_id as column_encryption_key_id, + cast(null as name) as column_encryption_key_database_name, + cast(0 as bit) as is_hidden, + cast(0 as bit) as is_masked, + cast(null as int) as graph_type, + cast(null as nvarchar(60)) as graph_type_desc +from pg_attribute a +inner join pg_class c on c.oid = attrelid +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_type t on t.oid = a.atttypid +left join pg_attrdef d on a.attrelid = d.adrelid and a.attnum = d.adnum +left join pg_collation coll on coll.oid = a.attcollation +left join gs_encrypted_columns e on e.rel_id = a.attrelid and e.column_name = a.attname +where not a.attisdropped and a.attnum > 0 +and c.relkind in ('r', 'v', 'm', 'f') +and has_column_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), a.attname, 'SELECT') +and s.nspname not in ('information_schema', 'pg_catalog', 'dbe_pldeveloper', 'coverage', 'dbe_perf', 'cstore', 'db4ai'); + +create or replace function sys.ts_index_type_helper(in indexid oid, in reloptions text[]) +returns tinyint as $$ +declare + tab_type text; + ind_typ tinyint; +begin + select sys.tsql_relation_reloptions_helper(reloptions, 'orientation') into tab_type; + + case (select amname from pg_am where oid = (select relam from pg_class where oid = indexid)) + when 'hash' then ind_typ := 7; + else ind_typ := (case tab_type when 'row' then 2 else 6 end); + end case; + + return ind_typ; +end; +$$ language plpgsql; + +create or replace view sys.indexes as +select + ind.indrelid as object_id, + i.relname as name, + ind.indexrelid as index_id, + sys.ts_index_type_helper(ind.indexrelid, t.reloptions) as type, + cast(case sys.ts_index_type_helper(ind.indexrelid, t.reloptions) + when 2 then 'NONCLUSTERED' + when 6 then 'NONCLUSTERED COLUMNSTORE' + else 'NONCLUSTERED HASH' end as nvarchar(60)) as type_desc, + cast(case ind.indisunique when 't' then 1 else 0 end as bit) as is_unique, + t.reltablespace as data_space_id, + cast(0 as bit) as ignore_dup_key, + cast(case ind.indisprimary when 't' then 1 else 0 end as bit) as is_primary_key, + cast(case when const.oid is null then 0 else 1 end as bit) as is_unique_constraint, + cast(case + when sys.tsql_relation_reloptions_helper(i.reloptions, 'fillfactory') is null then '0' + else sys.tsql_relation_reloptions_helper(i.reloptions, 'fillfactory') + end as tinyint) as fill_factor, + cast(0 as bit) as is_padded, + cast(case ind.indisenable when 't' then 0 else 1 end as bit) as is_disabled, + cast(0 as bit) as is_hypothetical, + cast(1 as bit) as allow_row_locks, + cast(1 as bit) as allow_page_locks, + cast(case when ind.indpred is null then 0 else 1 end as bit) as has_filter, + cast(ind.indpred as varchar) as filter_definition, + cast(0 as int) as compression_delay, + cast(0 as bit) as suppress_dup_key_messages +from pg_index ind +inner join pg_class i on ind.indexrelid = i.oid +inner join pg_class t on ind.indrelid = t.oid +left join pg_constraint const on const.conindid = i.oid and const.contype = 'u' +where ind.indisvalid; + +create or replace function sys.ts_procedure_object_internal() +returns table ( + out_name name, + out_object_id oid, + out_principal_id oid, + out_schema_id oid, + out_scheam name, + out_parent_object_id oid, + out_type char(2), + out_type_desc nvarchar(60), + out_create_date timestamp, + out_modify_date timestamp, + out_ms_shipped bit, + out_published bit, + out_schema_published bit +) as $$ +begin +return query +select + p.proname, + p.oid, + cast(case s.nspowner when p.proowner then null else p.proowner end as oid), + s.oid, + s.nspname, + cast(0 as oid), + cast(case p.prokind + when 'f' then + case p.proisagg when 't' then 'AF' else 'FN' end + else 'P' end + as char(2)) as type, + cast(case p.prokind + when 'f' then + case p.proisagg when 't' then 'AGGREGATE_FUNCTION' else 'SQL_SCALAR_FUNCTION' end + else 'SQL_STORED_PROCEDURE' end + as nvarchar(60)) as type, + cast(o.ctime as timestamp), + cast(o.mtime as timestamp), + cast(0 as bit), + cast(0 as bit), + cast(0 as bit) +from pg_proc p +inner join pg_namespace s on s.oid = p.pronamespace +inner join pg_object o on o.object_oid = p.oid +where has_function_privilege(p.oid, 'EXECUTE'); +end $$ +language plpgsql; + +create or replace view sys.procedures as +select + pi.out_name as name, + pi.out_object_id as object_id, + pi.out_principal_id as principal_id, + pi.out_schema_id as schema_id, + pi.out_parent_object_id as parent_object_id, + pi.out_type as type, + pi.out_type_desc as type_desc, + pi.out_create_date as create_date, + pi.out_modify_date as modify_date, + pi.out_ms_shipped as is_ms_shipped, + pi.out_published as is_published, + pi.out_schema_published as is_schema_published, + cast(0 as bit) as is_auto_executed, + cast(0 as bit) as is_execution_replicated, + cast(0 as bit) as is_repl_serializable_only, + cast(0 as bit) as skips_repl_constraints +from sys.ts_procedure_object_internal() pi +where pi.out_type = 'P' +and pi.out_scheam not in ('pg_catalog', 'information_schema'); + +create or replace view sys.all_objects as +select + ti.out_name as name, + ti.out_object_id as object_id, + ti.out_principal_id as principal_id, + ti.out_schema_id as schema_id, + ti.out_parent_object_id as parent_object_id, + ti.out_type as type, + ti.out_type_desc as type_desc, + ti.out_create_date as create_date, + ti.out_modify_date as modify_date, + ti.out_ms_shipped as is_ms_shipped, + ti.out_published as is_published, + ti.out_schema_published as is_schema_published +from sys.ts_tables_obj_internal() ti +union all +select + c.relname as name, + c.oid as object_id, + cast(case s.nspowner when c.relowner then null else c.relowner end as oid) as principal_id, + s.oid as schema_id, + cast(0 as oid) as parent_object_id, + cast('SO' as char(2)) as type, + cast('SEQUENCE_OBJECT' as nvarchar(60)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_class c +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_object o on o.object_oid = c.oid +where relkind in ('S', 'L') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +union all +select + c.relname as name, + c.oid as object_id, + cast(case s.nspowner when c.relowner then null else c.relowner end as oid) as principal_id, + s.oid as schema_id, + cast(0 as oid) as parent_object_id, + cast('V' as char(2)) as type, + cast('VIEW' as nvarchar(60)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_class c +inner join pg_namespace s on c.relnamespace = s.oid +inner join pg_object o on o.object_oid = c.oid +where c.relkind in ('v', 'm') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +union all +select + pi.out_name as name, + pi.out_object_id as object_id, + pi.out_principal_id as principal_id, + pi.out_schema_id as schema_id, + pi.out_parent_object_id as parent_object_id, + pi.out_type as type, + pi.out_type_desc as type_desc, + pi.out_create_date as create_date, + pi.out_modify_date as modify_date, + pi.out_ms_shipped as is_ms_shipped, + pi.out_published as is_published, + pi.out_schema_published as is_schema_published +from sys.ts_procedure_object_internal() pi +union all +select + con.conname as name, + con.oid as object_id, + cast(null as oid) as principal_id, + con.connamespace as schema_id, + con.conrelid as parent_object_id, + cast(case con.contype + when 'c' then 'C' + when 'p' then 'PK' + when 'u' then 'UQ' + when 'f' then 'F' + end as char(2)) as type, + cast(case con.contype + when 'c' then 'CHECK_CONSTRAINT' + when 'p' then 'PRIMARY_KEY_CONSTRAINT' + when 'u' then 'UNIQUE_CONSTRAINT' + when 'f' then 'FOREIGN_KEY_CONSTRAINT' + end as nvarchar(60)) as type_desc, + cast(null as timestamp) as create_date, + cast(null as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_constraint con +inner join pg_class c on c.oid = con.conrelid +inner join pg_namespace s on s.oid = con.connamespace +where con.contype in ('c', 'p', 'u', 'f') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +union all +select + tg.tgname as name, + tg.oid as object_id, + cast(null as oid) as principal_id, + c.relnamespace as schema_id, + tg.tgrelid as parent_object_id, + cast('TR' as char(2)) as type, + cast('SQL DML trigger' as nvarchar(60)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_trigger tg +inner join pg_class c on c.oid = tg.tgrelid +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_object o on o.object_oid = tg.oid +where has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +union all +select + cast(null as name) as name, + ad.oid as object_id, + cast(null as oid) as principal_id, + c.relnamespace as schema_id, + ad.adrelid as parent_object_id, + cast('D' as char(2)) as type, + cast('DEFAULT' as nvarchar(2)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_attrdef ad +inner join pg_class c on c.oid = ad.adrelid +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_object o on o.object_oid = ad.adrelid +where has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +union all +select + syn.synname as name, + syn.oid as object_id, + cast(case s.nspowner when syn.synowner then null else syn.synowner end as oid) as principal_id, + syn.synnamespace as schema_id, + cast(null as oid) as parent_object_id, + cast('SN' as char(2)) as type, + cast('SYNONYM' as nvarchar(60)) as type_desc, + cast(null as timestamp) as create_date, + cast(null as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_synonym syn +inner join pg_namespace s on s.oid = syn.synnamespace; + +create or replace view sys.objects as +select + t.name as name, + t.object_id as object_id, + t.principal_id as principal_id, + t.schema_id as schema_id, + t.parent_object_id as parent_object_id, + t.type as type, + t.type_desc as type_desc, + t.create_date as create_date, + t.modify_date as modify_date, + t.is_ms_shipped as is_ms_shipped, + t.is_published as is_published, + t.is_schema_published as is_schema_published +from sys.tables t +union all +select + c.relname as name, + c.oid as object_id, + cast(case s.nspowner when c.relowner then null else c.relowner end as oid) as principal_id, + s.oid as schema_id, + cast(0 as oid) as parent_object_id, + cast('SO' as char(2)) as type, + cast('SEQUENCE_OBJECT' as nvarchar(60)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_class c +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_object o on o.object_oid = c.oid +where relkind in ('S', 'L') +and s.nspname not in ('information_schema', 'pg_catalog') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +union all +select + v.name as name, + v.object_id as object_id, + v.principal_id as principal_id, + v.schema_id as schema_id, + v.parent_object_id as parent_object_id, + v.type as type, + v.type_desc as type_desc, + v.create_date as create_date, + v.modify_date as modify_date, + v.is_ms_shipped as is_ms_shipped, + v.is_published as is_published, + v.is_schema_published as is_schema_published +from sys.views v +union all +select + p.name, + p.object_id, + p.principal_id, + p.schema_id, + p.parent_object_id, + p.type, + p.type_desc, + p.create_date, + p.modify_date, + p.is_ms_shipped, + p.is_published, + p.is_schema_published +from sys.procedures p +union all +select + con.conname as name, + con.oid as object_id, + cast(null as oid) as principal_id, + con.connamespace as schema_id, + con.conrelid as parent_object_id, + cast(case con.contype + when 'c' then 'C' + when 'p' then 'PK' + when 'u' then 'UQ' + when 'f' then 'F' + end as char(2)) as type, + cast(case con.contype + when 'c' then 'CHECK_CONSTRAINT' + when 'p' then 'PRIMARY_KEY_CONSTRAINT' + when 'u' then 'UNIQUE_CONSTRAINT' + when 'f' then 'FOREIGN_KEY_CONSTRAINT' + end as nvarchar(60)) as type_desc, + cast(null as timestamp) as create_date, + cast(null as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_constraint con +inner join pg_class c on c.oid = con.conrelid +inner join pg_namespace s on s.oid = con.connamespace +where con.contype in ('c', 'p', 'u', 'f') +and has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +and s.nspname not in ('information_schema', 'pg_catalog') +union all +select + tg.tgname as name, + tg.oid as object_id, + cast(null as oid) as principal_id, + c.relnamespace as schema_id, + tg.tgrelid as parent_object_id, + cast('TR' as char(2)) as type, + cast('SQL DML trigger' as nvarchar(60)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_trigger tg +inner join pg_class c on c.oid = tg.tgrelid +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_object o on o.object_oid = tg.oid +where has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +and s.nspname not in ('information_schema', 'pg_catalog') +union all +select + cast(null as name) as name, + ad.oid as object_id, + cast(null as oid) as principal_id, + c.relnamespace as schema_id, + ad.adrelid as parent_object_id, + cast('D' as char(2)) as type, + cast('DEFAULT' as nvarchar(2)) as type_desc, + cast(o.ctime as timestamp) as create_date, + cast(o.mtime as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_attrdef ad +inner join pg_class c on c.oid = ad.adrelid +inner join pg_namespace s on s.oid = c.relnamespace +inner join pg_object o on o.object_oid = ad.adrelid +where has_table_privilege(quote_ident(s.nspname) ||'.'||quote_ident(c.relname), 'SELECT') +and s.nspname not in ('information_schema', 'pg_catalog') +union all +select + syn.synname as name, + syn.oid as object_id, + cast(case s.nspowner when syn.synowner then null else syn.synowner end as oid) as principal_id, + syn.synnamespace as schema_id, + cast(null as oid) as parent_object_id, + cast('SN' as char(2)) as type, + cast('Synonym' as nvarchar(60)) as type_desc, + cast(null as timestamp) as create_date, + cast(null as timestamp) as modify_date, + cast(0 as bit) as is_ms_shipped, + cast(0 as bit) as is_published, + cast(0 as bit) as is_schema_published +from pg_synonym syn +inner join pg_namespace s on s.oid = syn.synnamespace +where s.nspname not in ('information_schema', 'pg_catalog'); + reset search_path; diff --git a/contrib/shark/sql/test_sysviews.sql b/contrib/shark/sql/test_sysviews.sql index 0a2854756e..79302e5b86 100644 --- a/contrib/shark/sql/test_sysviews.sql +++ b/contrib/shark/sql/test_sysviews.sql @@ -149,5 +149,166 @@ drop table class; drop table teacher; drop table student; +-- test sys views +\d sys.all_objects +\d sys.objects +\d sys.tables +\d sys.views +\d sys.all_columns +\d sys.columns +\d sys.indexes +\d sys.procedures + +drop table if exists t_index; +create table t_index (id int primary key, c2 int not null, c3 char(1), c4 text, c5 numeric(10, 2)); +create unique index t_index_c2_uind on t_index(c2); +create index t_index_c3_c2_ind on t_index(c3, c2); +create index t_index_func_c4_ind on t_index(lower(c4)); +create index t_index_hash_c3_ind on t_index using hash(c3); +create index t_index_filter_c5_ind on t_index (c5) where c5 > 100.00; + +drop table if exists t_foreign1; +create table t_foreign1 (f_id int primary key, f_name text not null, f_age int default 18); +-- foreign key, check constraint +drop table if exists t_foreign2; +create table t_foreign2 (f_id int primary key not null, f_c2 int references t_foreign1(f_id), f_salary real check(f_salary > 0)); + +-- columns table +create table t_column (c1 int, c2 text, c3 char(1), constraint t_stats_col_pk primary key (c1)) with (orientation = column); + +-- temporal table +create temp table t_temp_table as select * from t_index; + +-- view +drop view if exists v_normal; +create view v_normal as select * from t_index; +-- view with check option +drop view if exists v_check; +create view v_check as select * from t_index where id > 10 with check option; +-- materialized view +drop materialized view if exists mv_normal; +create materialized view mv_normal as select * from t_foreign1; + +-- sequence +create sequence if not exists seq_order + increment by 1 + start with 1 + nocycle; +select seq_order.nextval; +create table t_orders (order_id int primary key default nextval('seq_order'), order_date date); + +-- synonym +create synonym syn_tbl for t_orders; + +-- trigger +create table t_tg_src (c1 int, c2 int, c3 int); +create table t_tg_des (c1 int, c2 int, c3 int); +create or replace function tri_insert_func() returns trigger as +$$ +begin + insert into t_tg_des values (NEW.c1, NEW.c2, NEW.c3); + return NEW; +end +$$ language plpgsql; +create trigger insert_trigger +before insert on t_tg_src +for each row +execute procedure tri_insert_func(); + +-- function +create or replace function test_sub(a int, b int) returns int as $$ +begin + return a - b; +end; +$$ language plpgsql; + +-- procedure +create or replace procedure test_sum(in a int, in b int, out c int) as +begin + c = a + b; +end; +/ + +select name, s.nspname, po.relname, type, type_desc, is_ms_shipped, is_published, is_schema_published +from sys.all_objects o +inner join pg_namespace s on o.schema_id = s.oid +left join pg_class po on po.oid = parent_object_id +where s.nspname = 'sys_view_test' +order by object_id; + +select name, s.nspname, po.relname, type, type_desc, is_ms_shipped, is_published, is_schema_published +from sys.objects o +inner join pg_namespace s on o.schema_id = s.oid +left join pg_class po on po.oid = parent_object_id +where s.nspname = 'sys_view_test' +order by object_id; + +select + name, s.nspname, type, type_desc, is_ms_shipped, is_published, is_schema_published, + max_column_id_used, uses_ansi_nulls, is_replicated, is_memory_optimized, durability, durability_desc, temporal_type, temporal_type_desc +from sys.tables t +inner join pg_namespace s on t.schema_id = s.oid +where s.nspname = 'sys_view_test' +order by object_id; + +select name, s.nspname, type, type_desc, is_ms_shipped, is_published, is_schema_published, with_check_option +from sys.views v +inner join pg_namespace s on v.schema_id = s.oid +where s.nspname = 'sys_view_test' +order by object_id; + +select t.relname, c.name, column_id, max_length, precision, scale, is_nullable, is_computed, is_replicated, generated_always_type, generated_always_type_desc +from sys.all_columns c +inner join pg_class t on c.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' +order by object_id, column_id; + +select t.relname, c.name, column_id, max_length, precision, scale, is_nullable, is_computed, is_replicated, generated_always_type, generated_always_type_desc +from sys.columns c +inner join pg_class t on c.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' +order by object_id, column_id; + +select t.relname, name, i.type, type_desc, i.is_unique, is_primary_key, is_unique_constraint, fill_factor, is_disabled, has_filter, filter_definition +from sys.indexes i +inner join pg_class t on i.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' +order by index_id; + +select name, s.nspname, type, type_desc, is_ms_shipped, is_published +from sys.procedures p +inner join pg_namespace s on p.schema_id = s.oid +where s.nspname = 'sys_view_test' +order by object_id; + +-- disable index +alter index t_index_func_c4_ind disable; + +select t.relname, name, i.type, type_desc, is_disabled +from sys.indexes i +inner join pg_class t on i.object_id = t.oid +inner join pg_namespace s on t.relnamespace = s.oid +where s.nspname = 'sys_view_test' and name = 't_index_func_c4_ind'; + +drop procedure test_sum; +drop function test_sub; +drop table t_tg_des; +drop table t_tg_src; +drop function tri_insert_func; +drop synonym syn_tbl; +drop table t_orders; +drop sequence seq_order; +drop materialized view mv_normal; +drop view v_check; +drop view v_normal; +drop table t_temp_table; +drop table t_column; +drop table t_foreign2; +drop table t_foreign1; +drop table t_index; + reset search_path; drop schema sys_view_test cascade; -- Gitee