当前位置:首页 > 数据库 > 正文内容

PostgreSQL体系表或视图中pg_node_tree类型值解析

邻居的猫1个月前 (12-09)数据库2061

PostgreSQL体系表或视图中pg_node_tree类型值解析

pg_node_tree类型阐明

pg_node_tree是一种openGauss/PostgreSQL内部数据类型,用于表明树形结构的数据。这个数据类型一般对用户不行见,因而直接查询或操作它的内容一般需求运用一些PostgreSQL的内置函数或东西。

包括pg_node_tree类型的体系视图/表,以pg12版别为例:

postgres=# select table_schema,table_name,column_name from information_schema.columns where data_type = 'pg_node_tree';
 table_schema |      table_name      |  column_name
--------------+----------------------+----------------
 pg_catalog   | pg_proc              | proargdefaults
 pg_catalog   | pg_type              | typdefaultbin
 pg_catalog   | pg_class             | relpartbound
 pg_catalog   | pg_attrdef           | adbin
 pg_catalog   | pg_constraint        | conbin
 pg_catalog   | pg_index             | indexprs
 pg_catalog   | pg_index             | indpred
 pg_catalog   | pg_rewrite           | ev_qual
 pg_catalog   | pg_rewrite           | ev_action
 pg_catalog   | pg_trigger           | tgqual
 pg_catalog   | pg_policy            | polqual
 pg_catalog   | pg_policy            | polwithcheck
 pg_catalog   | pg_partitioned_table | partexprs
(13 rows)

postgres=#

解析对应联系

体系表/视图 字段名 解析运用表达式
pg_proc proargdefaults pg_get_expr(proargdefaults,'pg_proc'::regclass)
pg_get_function_arguments(oid)
pg_type typdefaultbin
pg_class relpartbound pg_get_expr(relpartbound,oid)
pg_attrdef adbin pg_get_expr(adbin,adrelid)
pg_constraint conbin pg_get_expr(conbin,conrelid)
pg_get_constraintdef(oid)
pg_index indexprs pg_get_expr(indexprs,indrelid)
pg_index indpred pg_get_expr(indpred,indrelid)
pg_rewrite ev_qual
pg_rewrite ev_action
pg_trigger tgqual pg_get_triggerdef(oid)
pg_policy polqual
pg_policy polwithcheck
pg_partitioned_table partexprs pg_get_expr(partexprs,partrelid)

pg_node_tree类型值解析

关于存储再pg_node_tree类型中的数据,能够运用pg_get_expr()函数将其转换为可读的SQL表达式。这个函数将笼统的树形结构转换为一个人类可读的SQL表达式方式。

pg_get_expr函数阐明:

pg_get_expr(pg_node_tree, relation_oid)
pg_get_expr(pg_node_tree, relation_oid, pretty_bool)

回来类型:text

反编译一个表达式的内部方式,假定其间的任何 Var 指向由第二个参数指示的联系

解析pg_attrdef.adbin

pg_attrdef存储列的默认值。列的首要信息存储在pg_attribute。只要那些显式指定了一个默认值的列才会在这个目录中有一个项。

-- 创立测试表
drop table if exists test_t;
create table test_t (id int,name varchar(20) default 'test',update_time timestamp default current_timestamp);

-- 原查询成果
select t1.adrelid::regclass,t2.attname,adbin
from pg_attrdef t1
join pg_attribute t2 on t1.adrelid=t2.attrelid and t1.adnum=t2.attnum
where t2.attnum>0
      and t1.adrelid::regclass::text='test_t';
-[ RECORD 1 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
adrelid | test_t
attname | name
adbin   | {FUNCEXPR :funcid 669 :funcresulttype 1043 :funcretset false :funcvariadic false :funcformat 2 :funccollid 100 :inputcollid 100 :args ({CONST :consttype 1043 :consttypmod -1 :constcollid 100 :constlen -1 :constbyval false :constisnull false :location 53 :constvalue 8 [ 32 0 0 0 116 101 115 116 ]} {CONST :consttype 23 :consttypmod -1 :constcollid 0 :constlen 4 :constbyval true :constisnull false :location -1 :constvalue 4 [ 24 0 0 0 0 0 0 0 ]} {CONST :consttype 16 :consttypmod -1 :constcollid 0 :constlen 1 :constbyval true :constisnull false :location -1 :constvalue 1 [ 0 0 0 0 0 0 0 0 ]}) :location -1}
-[ RECORD 2 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
adrelid | test_t
attname | update_time
adbin   | {FUNCEXPR :funcid 2027 :funcresulttype 1114 :funcretset false :funcvariadic false :funcformat 2 :funccollid 0 :inputcollid 0 :args ({SQLVALUEFUNCTION :op 3 :type 1184 :typmod -1 :location 90}) :location -1}

-- 解析后
select t1.adrelid::regclass,t2.attname,pg_get_expr(adbin,t1.adrelid)
from pg_attrdef t1
join pg_attribute t2 on t1.adrelid=t2.attrelid and t1.adnum=t2.attnum
where t2.attnum>0
      and t1.adrelid::regclass::text='test_t';
 adrelid |   attname   |        pg_get_expr
---------+-------------+---------------------------
 test_t  | name        | 'test'::character varying
 test_t  | update_time | CURRENT_TIMESTAMP
(2 rows)      

解析pg_proc.proargdefaults

-- 创立测试函数
CREATE OR REPLACE FUNCTION test_fun(
    arg1 INTEGER,
    arg2 INTEGER DEFAULT 0,
    arg3 TEXT DEFAULT 'default_value'
)
RETURNS INTEGER
AS $$
BEGIN
    RETURN arg1 + arg2;
END;
$$ LANGUAGE plpgsql;

-- 正常查询
postgres=# select proargdefaults from pg_proc where proname = 'test_fun';

                                        proargdefaults
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 ({CONST :consttype 23 :consttypmod -1 :constcollid 0 :constlen 4 :constbyval true :constisnull false :location 80 :constvalue 4 [ 0 0 0 0 0 0 0 0 ]} {CONST :consttype 25 :consttypmod -1 :constcollid 100 :constlen -1 :constbyval false :constisnull false :location 105 :constvalue 17 [ 68 0 0 0 100 101 102 97 117 108 116 95 118 97 108 117 101 ]})
(1 row)

postgres=#



-- 解析后
postgres=# select pg_get_expr(proargdefaults,'pg_proc'::regclass) from pg_proc where proname = 'test_fun';
       pg_get_expr
--------------------------
 0, 'default_value'::text
(1 row)

-- 或许
postgres=# select proname,pg_get_function_arguments(oid) from pg_proc where proname = 'test_fun';
 proname  |                           pg_get_function_arguments
----------+-------------------------------------------------------------------------------
 test_fun | arg1 integer, arg2 integer DEFAULT 0, arg3 text DEFAULT 'default_value'::text
(1 row)

解析pg_index.indexprs和pg_index.indpred

-- 创立测试表和索引
drop table if exists test_t;
create table test_t(id int,name varchar(100));
create index idx_name on test_t(lower(name)) where id >=100000;

-- 查询
select t3.relname as tablename,
       t1.relname as indexname,
       t2.indexprs,t2.indpred
   from pg_class t1
  join pg_index t2 on t1.oid=t2.indexrelid
  join pg_class t3 on t3.oid=t2.indrelid
where t3.relname = 'test_t';

-- 原值
tablename | test_t
indexname | idx_name
indexprs  | ({FUNCEXPR :funcid 870 :funcresulttype 25 :funcretset false :funcvariadic false :funcformat 0 :funccollid 100 :inputcollid 100 :args ({RELABELTYPE :arg {VAR :varno 1 :varattno 2 :vartype 1043 :vartypmod 104 :varcollid 100 :varlevelsup 0 :varnoold 1 :varoattno 2 :location 38} :resulttype 25 :resulttypmod -1 :resultcollid 100 :relabelformat 2 :location -1}) :location 32})
indpred   | {OPEXPR :opno 525 :opfuncid 150 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 0 :args ({VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 1 :location 51} {CONST :consttype 23 :consttypmod -1 :constcollid 0 :constlen 4 :constbyval true :constisnull false :location 56 :constvalue 4 [ -96 -122 1 0 0 0 00 ]}) :location 54}

-- 解析后的值
select t3.relname as tablename,
       t1.relname as indexname,
       pg_get_expr(t2.indexprs,indrelid),
       pg_get_expr(t2.indpred,indrelid)
   from pg_class t1
  join pg_index t2 on t1.oid=t2.indexrelid
  join pg_class t3 on t3.oid=t2.indrelid
where t3.relname = 'test_t';

 tablename | indexname |     pg_get_expr     |  pg_get_expr
-----------+-----------+---------------------+----------------
 test_t    | idx_name  | lower((name)::text) | (id >= 100000)
(1 row)

解析pg_class.relpartbound

-- 创立分区表
CREATE TABLE test_range_t (id serial,date timestamp(6),data TEXT) PARTITION BY RANGE (date);
CREATE TABLE test_range_2020 PARTITION OF test_range_t FOR VALUES FROM ('2020-01-01') TO ('2021-01-01');
CREATE TABLE test_range_2021 PARTITION OF test_range_t FOR VALUES FROM ('2021-01-01') TO ('2022-01-01');
CREATE TABLE test_range_2022 PARTITION OF test_range_t FOR VALUES FROM ('2022-01-01') TO ('2023-01-01');
CREATE TABLE test_range_2023 PARTITION OF test_range_t FOR VALUES FROM ('2023-01-01') TO ('2024-01-01');

-- 某一个分区的值查询
postgres=# select relname,relpartbound from pg_class where relname = 'test_range_2020';
-[ RECORD 1 ]+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
relname      | test_range_2020
relpartbound | {PARTITIONBOUNDSPEC :strategy r :is_default false :modulus 0 :remainder 0 :listdatums <> :lowerdatums ({PARTITIONRANGEDATUM :kind 0 :value {CONST :consttype 1114 :consttypmod 6 :constcollid 0 :constlen 8 :constbyval true :constisnull false :location -1 :constvalue 8 [ 0 96 -62 -122 7 62 2 0 ]} :location 72}) :upperdatums ({PARTITIONRANGEDATUM :kind 0 :value {CONST :consttype 1114 :consttypmod 6 :constcollid 0 :constlen 8 :constbyval true :constisnull false :location -1 :constvalue 8 [0 -96 -83 48 -54 90 2 0 ]} :location 90}) :location 66}

-- 解析后
postgres=# select relname,pg_get_expr(relpartbound,oid) from pg_class where relname ~ 'test_range_\d+';
     relname     |                            pg_get_expr
-----------------+--------------------------------------------------------------------
 test_range_2020 | FOR VALUES FROM ('2020-01-01 00:00:00') TO ('2021-01-01 00:00:00')
 test_range_2021 | FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2022-01-01 00:00:00')
 test_range_2022 | FOR VALUES FROM ('2022-01-01 00:00:00') TO ('2023-01-01 00:00:00')
 test_range_2023 | FOR VALUES FROM ('2023-01-01 00:00:00') TO ('2024-01-01 00:00:00')
(4 rows)

解析pg_constraint.conbin

drop table if exists test_t;
create table test_t (id int,name varchar(100),check(id>0),check(length(name)>3));

-- 原值查询
select connamespace::regnamespace as schema,
       conrelid::regclass as tablename,
	   contype,
	   conname,
	   conbin
from pg_constraint where conrelid::regclass::text='test_t';
-[ RECORD 1 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
schema    | public
tablename | test_t
contype   | c
conname   | test_t_id_check
conbin    | {OPEXPR :opno 521 :opfuncid 147 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 0 :args ({VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 1 :location 52} {CONST :consttype 23 :consttypmod -1 :constcollid 0 :constlen 4 :constbyval true :constisnull false :location 55 :constvalue 4 [ 0 0 0 0 0 0 0 0 ]}) :location 54}
-[ RECORD 2 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
schema    | public
tablename | test_t
contype   | c
conname   | test_t_name_check
conbin    | {OPEXPR :opno 521 :opfuncid 147 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 0 :args ({FUNCEXPR :funcid 1317 :funcresulttype 23 :funcretset false :funcvariadic false :funcformat 0 :funccollid 0 :inputcollid 100 :args ({RELABELTYPE :arg {VAR :varno 1 :varattno 2 :vartype 1043 :vartypmod 104 :varcollid 100 :varlevelsup 0 :varnoold 1 :varoattno 2 :location 71} :resulttype 25 :resulttypmod -1 :resultcollid 100 :relabelformat 2 :location -1}) :location 64} {CONST :consttype 23 :consttypmod -1 :constcollid 0 :constlen 4 :constbyval true :constisnull false :location 77 :constvalue 4 [ 3 0 0 0 0 0 0 0 ]}) :location 76}


-- 解析后
select connamespace::regnamespace as schema,
       conrelid::regclass as tablename,
	   contype,
	   conname,
	   pg_get_expr(conbin,conrelid)
from pg_constraint where conrelid::regclass::text='test_t';

 schema | tablename | contype |      conname      |        pg_get_expr
--------+-----------+---------+-------------------+----------------------------
 public | test_t    | c       | test_t_id_check   | (id > 0)
 public | test_t    | c       | test_t_name_check | (length((name)::text) > 3)
(2 rows)


-- 或许
select connamespace::regnamespace as schema,
       conrelid::regclass as tablename,
	   contype,
	   conname,
	   pg_get_constraintdef(oid)
from pg_constraint where conrelid::regclass::text='test_t';

 schema | tablename | contype |      conname      |        pg_get_constraintdef
--------+-----------+---------+-------------------+------------------------------------
 public | test_t    | c       | test_t_id_check   | CHECK ((id > 0))
 public | test_t    | c       | test_t_name_check | CHECK ((length((name)::text) > 3))
(2 rows)

解析pg_partitioned_table.partexprs

CREATE TABLE sales (
    id SERIAL,
    sale_date DATE NOT NULL,
    amount NUMERIC NOT NULL,
    region TEXT NOT NULL
) PARTITION BY RANGE (EXTRACT(YEAR FROM sale_date));
CREATE TABLE sales_2022 PARTITION OF sales FOR VALUES FROM (2022) TO (2023);
CREATE TABLE sales_2023 PARTITION OF sales FOR VALUES FROM (2023) TO (2024);
CREATE TABLE sales_2024 PARTITION OF sales FOR VALUES FROM (2024) TO (2025);


-- 原值
postgres=# select partrelid::regclass,partexprs from pg_partitioned_table where partrelid::regclass::text='sales';
-[ RECORD 1 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
partrelid | sales
partexprs | ({FUNCEXPR :funcid 1384 :funcresulttype 701 :funcretset false :funcvariadic false :funcformat 0 :funccollid 0 :inputcollid 100 :args ({CONST :consttype 25 :consttypmod -1 :constcollid 100 :constlen -1 :constbyval false :constisnull false :location 149 :constvalue 8 [ 32 0 0 0 121 101 97 114 ]} {VAR :varno 1 :varattno 2 :vartype 1082 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 2 :location 159}) :location 141})

-- 解析后
postgres=# select partrelid::regclass,pg_get_expr(partexprs,partrelid) from pg_partitioned_table where partrelid::regclass::text='sales';
 partrelid |            pg_get_expr
-----------+------------------------------------
 sales     | date_part('year'::text, sale_date)
(1 row)

 留意:date_part函数等价与extract 

postgres=# select extract(year from now()) as extract,date_part('year'::text,now()) as date_part;
 extract | date_part
---------+-----------
    2024 |      2024
(1 row)

postgres=# select extract(year from current_date) as extract,date_part('year'::text,current_date) as date_part;
 extract | date_part
---------+-----------
    2024 |      2024
(1 row)

解析pg_trigger.tgqual

-- 创立order表
CREATE TABLE orders (
    id SERIAL PRIMARY KEY,
    order_date DATE NOT NULL,
    amount NUMERIC NOT NULL,
    customer_name VARCHAR(100)
);

-- audit_log表
CREATE TABLE audit_log (
    id SERIAL PRIMARY KEY,
    order_id INT,
    action VARCHAR(50),
    log_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

-- 创立触发器函数
CREATE OR REPLACE FUNCTION log_high_value_order()
RETURNS TRIGGER AS $$
BEGIN
    -- 查看订单金额是否超越 1000
    IF NEW.amount > 1000 THEN
        -- 刺进审计日志
        INSERT INTO audit_log (order_id, action) 
        VALUES (NEW.id, 'High Value Order');
    END IF;
    RETURN NEW;
END;
$$ LANGUAGE plpgsql;

-- 创立带有条件的触发器
CREATE TRIGGER high_value_order_trigger
AFTER INSERT ON orders
FOR EACH ROW
WHEN (NEW.amount > 1000)
EXECUTE FUNCTION log_high_value_order();

查询触发器信息

-- 原值
postgres=# select tgrelid::regclass,tgname,tgqual from pg_trigger where tgrelid::regclass::text='orders';
-[ RECORD 1 ]--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
tgrelid 

扫描二维码推送至手机访问。

版权声明:本文由51Blog发布,如需转载请注明出处。

本文链接:https://www.51blog.vip/?id=547

标签: PostgreSQL
分享给朋友:

“PostgreSQL体系表或视图中pg_node_tree类型值解析” 的相关文章

查看mysql版本命令,MySQL版本查看命令详解

查看mysql版本命令,MySQL版本查看命令详解

要查看MySQL的版本,你可以使用以下SQL命令:```sqlSELECT VERSION;```这条命令会返回MySQL数据库的当前版本信息。在MySQL客户端中输入这条命令并执行,即可看到版本信息。MySQL版本查看命令详解MySQL作为一种广泛使用的关系型数据库管理系统,其版本信息的查看对于数...

oracle查询优化,Oracle数据库查询优化技巧与策略详解

oracle查询优化,Oracle数据库查询优化技巧与策略详解

1. 数据库设计: 正确地设计表结构,包括使用合适的数据类型、合理的字段长度等。 使用合适的数据模型,如星型模式或雪花模式,以优化数据仓库查询。 合理地使用分区表,以加快查询速度。2. 查询语句的编写: 使用EXPLAIN PLAN来分析查询语句的执行计划,找出性能瓶颈。...

大数据教育培训班,张璁怎么读

大数据教育培训班,张璁怎么读

1. 传智教育 课程内容:Java大数据培训、大数据开发培训、大数据分析培训、大数据开发工程师培训。 特色:提供企业级真实大数据业务砛n2. 尚硅谷 课程内容:大数据开发培训课程、大数据分析培训课程等。 特色:多年大数据课程培训经验,为企业输送大量大数据工程师人才。 3...

大数据的核心是什么,数据整合与价值挖掘

大数据的核心是什么,数据整合与价值挖掘

大数据的核心在于数据本身以及对其进行的处理和分析。大数据通常指的是规模庞大、类型多样、处理速度要求高的数据集,这些数据集可能来源于互联网、社交媒体、物联网设备、企业内部系统等多种渠道。大数据的核心包括以下几个方面:1. 数据采集:从各种来源收集数据,包括结构化数据(如数据库中的数据)和非结构化数据(...

大数据开发学习路线,大数据开发学习路线概述

大数据开发学习路线,大数据开发学习路线概述

大数据开发是一个涉及多个技术和工具的领域,学习路线可以按照以下步骤进行:1. 基础知识: 学习编程语言:掌握至少一种编程语言,如Python或Java,以便进行数据处理和分析。 数据结构和算法:了解基本的数据结构和算法,以便有效地处理和存储数据。2. 数据处理和存储: 学习关系型数...

北京大学大数据专业,引领时代潮流的智慧教育先锋

北京大学大数据专业,引领时代潮流的智慧教育先锋

北京大学的大数据专业主要涵盖本科和硕士两个层次,以下是详细介绍: 本科阶段北京大学的数据科学与大数据技术专业由信息科学技术学院和计算机学院共同建设。该专业注重数理基础和系统能力,鼓励交叉创新。学生将在前两年主修数学、计算机科学和统计学的基础课程,后两年则可以根据自己的兴趣和能力选修金融、医疗、生物、...