PG中添加和查询注释comment
COMMENT命令简介
PG中可以使用comment命令为表、列、索引、视图等对象添加注释。
命令
COMMENT ON
{
ACCESS METHOD object_name |
AGGREGATE aggregate_name ( aggregate_signature ) |
CAST (source_type AS target_type) |
COLLATION object_name |
COLUMN relation_name.column_name |
CONSTRAINT constraint_name ON table_name |
CONSTRAINT constraint_name ON DOMAIN domain_name |
CONVERSION object_name |
DATABASE object_name |
DOMAIN object_name |
EXTENSION object_name |
EVENT TRIGGER object_name |
FOREIGN DATA WRAPPER object_name |
FOREIGN TABLE object_name |
FUNCTION function_name [ ( [ [ argmode ] [ argname ] argtype [, ...] ] ) ] |
INDEX object_name |
LARGE OBJECT large_object_oid |
MATERIALIZED VIEW object_name |
OPERATOR operator_name (left_type, right_type) |
OPERATOR CLASS object_name USING index_method |
OPERATOR FAMILY object_name USING index_method |
POLICY policy_name ON table_name |
[ PROCEDURAL ] LANGUAGE object_name |
PROCEDURE procedure_name [ ( [ [ argmode ] [ argname ] argtype [, ...] ] ) ] |
PUBLICATION object_name |
ROLE object_name |
ROUTINE routine_name [ ( [ [ argmode ] [ argname ] argtype [, ...] ] ) ] |
RULE rule_name ON table_name |
SCHEMA object_name |
SEQUENCE object_name |
SERVER object_name |
STATISTICS object_name |
SUBSCRIPTION object_name |
TABLE object_name |
TABLESPACE object_name |
TEXT SEARCH CONFIGURATION object_name |
TEXT SEARCH DICTIONARY object_name |
TEXT SEARCH PARSER object_name |
TEXT SEARCH TEMPLATE object_name |
TRANSFORM FOR type_name LANGUAGE lang_name |
TRIGGER trigger_name ON table_name |
TYPE object_name |
VIEW object_name
} IS 'text'
其中 aggregate_signature 是:
* |
[ argmode ] [ argname ] argtype [ , ... ] |
[ [ argmode ] [ argname ] argtype [ , ... ] ] ORDER BY [ argmode ] [ argname ] argtype [ , ... ]
描述
COMMENT
存储关于一个数据库对象的注释。
对每一个对象只保存一个注释字符串,因此为了修改一段注释,对同一个对象 发出一个新的COMMENT
命令。要移除一段注释,可在文本字符串的位置上写上NULL
。当对象被删除时,其注释 也会被自动删除。
对大部分类型的对象,只有对象的拥有者可以设置注释。角色没有拥有者,因此 COMMENT ON ROLE
的规则是你必须作为一个超级用户来对一个 超级用户角色设置注释,或者具有CREATEROLE
特权来对非超级用 户角色设置注释。同样的,访问方法也没有拥有者,你必须作为一个超级用户来 对一个访问方法设置注释。当然,一个超级用户可以对任何东西设置注释。
使用psql的\d
命令家族可以查看注释。其他检索注释的用户接口可以构建在 psql使用的内建函数之上,即 obj_description
、col_description
以及shobj_description
(见表 9.73)。
参数
-
object_name
relation_name
.column_name
aggregate_name
constraint_name
function_name
operator_name
policy_name
procedure_name
routine_name
rule_name
trigger_name
要被注释的对象的名称。表、聚集、排序方式、转换、域、外部表、函数、 索引、操作符、操作符类、操作符族、存储过程、例程、序列、统计信息、文本搜索对象、类型和视图 的名称可以被模式限定。在注释一列时, *
relation_name
*必须 引用一个表、视图、组合类型或者外部表。 -
table_name
domain_name
当在一个约束、触发器、规则或者策略上创建一段注释时,这些参数指定在其上定义 该对象的表或域的名称。
-
source_type
造型的源数据类型的名称。
-
target_type
造型的目标数据类型的名称。
-
argmode
一个函数,存储过程或者聚集函数的参数的模式:
IN
、OUT
、INOUT
或者VARIADIC
。 如果被省略,默认值是IN
。注意COMMENT
并不真正关心OUT
参数,因为决定函数的身份只需要输入参数。因此 列出IN
、INOUT
和VARIADIC
参数就足够了。 -
argname
一个函数,存储过程或者聚集函数参数的名称。注意
COMMENT
并不真正关心参数名称, 因为决定函数的身份只需要参数数据类型。 -
argtype
一个函数,存储过程或者聚集函数参数的数据类型。
-
large_object_oid
大对象的 OID。
-
left_type
right_type
操作符的参数的数据类型(可以是模式限定的)。对一个前缀后后缀操作符 的缺失参数可以写
NONE
。 -
PROCEDURAL
这是一个噪声词。
-
type_name
该转换的数据类型的名称。
-
lang_name
该转换的语言的名称。
-
text
写成一个字符串的新注释。如果要删除注释,写成
NULL
。
注解
当前对查看注释没有安全机制:任何连接到一个数据库的用户能够看到 该数据库中所有对象的注释。对于数据库、角色、表空间这类共享对象, 注释被全局存储,因此连接到集簇中任何数据库的任何用户可以看到共 享对象的所有注释。因此,不要在注释中放置有安全性风险的信息。
示例
为表mytable
附加一段注释:
COMMENT ON TABLE mytable IS 'This is my table.';
移除它:
COMMENT ON TABLE mytable IS NULL;
更多的一些例子:
COMMENT ON ACCESS METHOD gin IS 'GIN index access method';
COMMENT ON AGGREGATE my_aggregate (double precision) IS 'Computes sample variance';
COMMENT ON CAST (text AS int4) IS 'Allow casts from text to int4';
COMMENT ON COLLATION "fr_CA" IS 'Canadian French';
COMMENT ON COLUMN my_table.my_column IS 'Employee ID number';
COMMENT ON CONVERSION my_conv IS 'Conversion to UTF8';
COMMENT ON CONSTRAINT bar_col_cons ON bar IS 'Constrains column col';
COMMENT ON CONSTRAINT dom_col_constr ON DOMAIN dom IS 'Constrains col of domain';
COMMENT ON DATABASE my_database IS 'Development Database';
COMMENT ON DOMAIN my_domain IS 'Email Address Domain';
COMMENT ON EVENT TRIGGER abort_ddl IS 'Aborts all DDL commands';
COMMENT ON EXTENSION hstore IS 'implements the hstore data type';
COMMENT ON FOREIGN DATA WRAPPER mywrapper IS 'my foreign data wrapper';
COMMENT ON FOREIGN TABLE my_foreign_table IS 'Employee Information in other database';
COMMENT ON FUNCTION my_function (timestamp) IS 'Returns Roman Numeral';
COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee ID';
COMMENT ON LANGUAGE plpython IS 'Python support for stored procedures';
COMMENT ON LARGE OBJECT 346344 IS 'Planning document';
COMMENT ON MATERIALIZED VIEW my_matview IS 'Summary of order history';
COMMENT ON OPERATOR ^ (text, text) IS 'Performs intersection of two texts';
COMMENT ON OPERATOR - (NONE, integer) IS 'Unary minus';
COMMENT ON OPERATOR CLASS int4ops USING btree IS '4 byte integer operators for btrees';
COMMENT ON OPERATOR FAMILY integer_ops USING btree IS 'all integer operators for btrees';
COMMENT ON POLICY my_policy ON mytable IS 'Filter rows by users';
COMMENT ON PROCEDURE my_proc (integer, integer) IS 'Runs a report';
COMMENT ON PUBLICATION alltables IS 'Publishes all operations on all tables';
COMMENT ON ROLE my_role IS 'Administration group for finance tables';
COMMENT ON ROUTINE my_routine (integer, integer) IS 'Runs a routine (which is a function or procedure)';
COMMENT ON RULE my_rule ON my_table IS 'Logs updates of employee records';
COMMENT ON SCHEMA my_schema IS 'Departmental data';
COMMENT ON SEQUENCE my_sequence IS 'Used to generate primary keys';
COMMENT ON SERVER myserver IS 'my foreign server';
COMMENT ON STATISTICS my_statistics IS 'Improves planner row estimations';
COMMENT ON SUBSCRIPTION alltables IS 'Subscription for all operations on all tables';
COMMENT ON TABLE my_schema.my_table IS 'Employee Information';
COMMENT ON TABLESPACE my_tablespace IS 'Tablespace for indexes';
COMMENT ON TEXT SEARCH CONFIGURATION my_config IS 'Special word filtering';
COMMENT ON TEXT SEARCH DICTIONARY swedish IS 'Snowball stemmer for Swedish language';
COMMENT ON TEXT SEARCH PARSER my_parser IS 'Splits text into words';
COMMENT ON TEXT SEARCH TEMPLATE snowball IS 'Snowball stemmer';
COMMENT ON TRANSFORM FOR hstore LANGUAGE plpythonu IS 'Transform between hstore and Python dict';
COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for RI';
COMMENT ON TYPE complex IS 'Complex number data type';
COMMENT ON VIEW my_view IS 'View of departmental costs';
兼容性
SQL 标准中没有COMMENT
命令。
查询注释
表 9.73中展示的函数抽取注释,注释是由COMMENT命令在以前存储的。如果对指定参数找不到注释,则返回空值。
表 9.73. 注释信息函数
函数描述 |
---|
col_description ( table oid , column integer ) → text 返回表列的注释,该注释由该表的OID和列号指定。(obj_description 不能用于表的列,因为列没有自己的oid。) |
obj_description ( object oid , catalog name ) → text 返回OID指定的数据库对象的注释和包含该对象的系统目录的名称。 例如,obj_description(123456, 'pg_class') 将检索OID为123456的表的注释。 |
obj_description ( object oid ) → text 返回仅由其OID指定的数据库对象的注释。 这个已被***弃用(deprecated)***因为无法保证oid在不同的系统目录中是唯一的;因此,可能会返回错误的注释。 |
shobj_description ( object oid , catalog name ) → text 返回共享数据库对象的注释,该对象由其OID和包含的系统编目的名称指定。 这与obj_description 类似,只是它用于检索共享对象(也就是数据库、角色和表空间)上的注释。 有些系统编目对每个集群中的所有数据库都是全局的,其中对象的描述也全局存储。 |
我的示例
注意:::regclass
是oid的别名。
regclass是一种数据类型,它实际上是oid的别名。相当于是oid和对象名之间的双向符号,既可以把oid翻译成表名,也可以把表名翻译成oid。通过使用::regclass
, 我们就不需要通过查询pg_class表来获取对象与oid的对应关系了。
drop table t_hash;
CREATE TABLE t_hash AS
SELECT id, md5(id::text) md5_text
FROM generate_series(1, 500) AS id;
SELECT oid FROM pg_class WHERE relname = 't_hash';
select oid,oid::regclass tbname,relname,reltuples from pg_class where oid='t_hash'::regclass;
comment on table t_hash is 'table t_hash';
comment on column t_hash.id is 'The ID';
comment on column t_hash.md5_text is 'The text';
select
table_catalog,
table_schema,
table_name,
column_name, data_type,
obj_description(table_name::regclass) tb_comment,
col_description(table_name::regclass, ordinal_position::int) col_comment
from information_schema.columns
where table_name = 't_hash';
过程:
postgres=# drop table t_hash;
DROP TABLE
postgres=# CREATE TABLE t_hash AS
postgres-# SELECT id, md5(id::text) md5_text
postgres-# FROM generate_series(1, 500) AS id;
SELECT 500
postgres=#
postgres=# SELECT oid FROM pg_class WHERE relname = 't_hash';
oid
-------
17863
(1 row)
postgres=#
postgres=# select oid,oid::regclass tbname,relname,reltuples from pg_class where oid='t_hash'::regclass;
oid | tbname | relname | reltuples
-------+--------+---------+-----------
17863 | t_hash | t_hash | 0
(1 row)
postgres=# \d+ t_hash
Table "public.t_hash"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
----------+---------+-----------+----------+---------+----------+--------------+-------------
id | integer | | | | plain | |
md5_text | text | | | | extended | |
Access method: heap
postgres=#
postgres=# comment on table t_hash is 'table t_hash';
COMMENT
postgres=# comment on column t_hash.id is 'The ID';
COMMENT
postgres=# comment on column t_hash.md5_text is 'The text';
COMMENT
postgres=# \d+ t_hash
Table "public.t_hash"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
----------+---------+-----------+----------+---------+----------+--------------+-------------
id | integer | | | | plain | | The ID
md5_text | text | | | | extended | | The text
Access method: heap
postgres=#
postgres=# select
postgres-# table_catalog,
postgres-# table_schema,
postgres-# table_name,
postgres-# column_name, data_type,
postgres-# obj_description(table_name::regclass,) tb_comment,
postgres-# col_description(table_name::regclass, ordinal_position::int) col_comment
postgres-# from information_schema.columns
postgres-# where table_name = 't_hash';
table_catalog | table_schema | table_name | column_name | data_type | tb_comment | col_comment
---------------+--------------+------------+-------------+-----------+--------------+-------------
postgres | public | t_hash | id | integer | table t_hash | The ID
postgres | public | t_hash | md5_text | text | table t_hash | The text
(2 rows)
参考
- 点赞
- 收藏
- 关注作者
评论(0)