### [PostgreSQL函数:用以查询某表的详细 包含表字段的注释信息](http://lovejuan1314.iteye.com/blog/1167680)**
**博客分类:** - [数据库(Oracle/Postgresql/Hypertable等)](http://lovejuan1314.iteye.com/category/32183)
感谢PostgreSQL论坛阿弟
Sql代码 [![收藏代码](http://lovejuan1314.iteye.com/images/icon_star.png)](# "收藏这段代码")
1. CREATE OR REPLACE FUNCTION pgsql_type(a_type varchar) RETURNS varchar AS
1. $BODY$
1. DECLARE
1. v_type varchar;
1. BEGIN
1. IF a_type='int8' THEN
1. v_type:='bigint';
1. ELSIF a_type='int4' THEN
1. v_type:='integer';
1. ELSIF a_type='int2' THEN
1. v_type:='smallint';
1. ELSIF a_type='bpchar' THEN
1. v_type:='char';
1. ELSE
1. v_type:=a_type;
1. END IF;
1. RETURN v_type;
1. END;
1. $BODY$
1. LANGUAGE PLPGSQL;
1.
1. CREATE TYPE "public"."tablestruct" AS (
1. "fields_key_name" varchar(100),
1. "fields_name" VARCHAR(200),
1. "fields_type" VARCHAR(20),
1. "fields_length" BIGINT,
1. "fields_not_null" VARCHAR(10),
1. "fields_default" VARCHAR(500),
1. "fields_comment" VARCHAR(1000)
1. );
1.
1. CREATE OR REPLACE FUNCTION "public"."table_msg" (a_schema_name varchar, a_table_name varchar) RETURNS SETOF "public"."tablestruct" AS
1. $body$
1. DECLARE
1. v_ret tablestruct;
1. v_oid oid;
1. v_sql varchar;
1. v_rec RECORD;
1. v_key varchar;
1. BEGIN
1. SELECT
1. pg_class.oid INTO v_oid
1. FROM
1. pg_class
1. INNER JOIN pg_namespace ON (pg_class.relnamespace = pg_namespace.oid AND lower(pg_namespace.nspname) = a_schema_name)
1. WHERE
1. pg_class.relname=a_table_name;
1. IF NOT FOUND THEN
1. RETURN;
1. END IF;
1.
1. v_sql='
1. SELECT
1. pg_attribute.attname AS fields_name,
1. pg_attribute.attnum AS fields_index,
1. pgsql_type(pg_type.typname::varchar) AS fields_type,
1. pg_attribute.atttypmod-4 as fields_length,
1. CASE WHEN pg_attribute.attnotnull THEN ''not null''
1. ELSE ''''
1. END AS fields_not_null,
1. pg_attrdef.adsrc AS fields_default,
1. pg_description.description AS fields_comment
1. FROM
1. pg_attribute
1. INNER JOIN pg_class ON pg_attribute.attrelid = pg_class.oid
1. INNER JOIN pg_type ON pg_attribute.atttypid = pg_type.oid
1. LEFT OUTER JOIN pg_attrdef ON pg_attrdef.adrelid = pg_class.oid AND pg_attrdef.adnum = pg_attribute.attnum
1. LEFT OUTER JOIN pg_description ON pg_description.objoid = pg_class.oid AND pg_description.objsubid = pg_attribute.attnum
1. WHERE
1. pg_attribute.attnum > 0
1. AND attisdropped <> ''t''
1. AND pg_class.oid = ' || v_oid || '
1. ORDER BY pg_attribute.attnum' ;
1.
1. FOR v_rec IN EXECUTE v_sql LOOP
1. v_ret.fields_name=v_rec.fields_name;
1. v_ret.fields_type=v_rec.fields_type;
1. IF v_rec.fields_length > 0 THEN
1. v_ret.fields_length:=v_rec.fields_length;
1. ELSE
1. v_ret.fields_length:=NULL;
1. END IF;
1. v_ret.fields_not_null=v_rec.fields_not_null;
1. v_ret.fields_default=v_rec.fields_default;
1. v_ret.fields_comment=v_rec.fields_comment;
1. SELECT constraint_name INTO v_key FROM information_schema.key_column_usage WHERE table_schema=a_schema_name AND table_name=a_table_name AND column_name=v_rec.fields_name;
1. IF FOUND THEN
1. v_ret.fields_key_name=v_key;
1. ELSE
1. v_ret.fields_key_name='';
1. END IF;
1. RETURN NEXT v_ret;
1. END LOOP;
1. RETURN ;
1. END;
1. $body$
1. LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
1.
1. COMMENT ON FUNCTION "public"."table_msg"(a_schema_name varchar, a_table_name varchar)
1. IS '获得表信息';
1.
1. ---重载一个函数
1. CREATE OR REPLACE FUNCTION "public"."table_msg" (a_table_name varchar) RETURNS SETOF "public"."tablestruct" AS
1. $body$
1. DECLARE
1. v_ret tablestruct;
1. BEGIN
1. FOR v_ret IN SELECT * FROM table_msg('public',a_table_name) LOOP
1. RETURN NEXT v_ret;
1. END LOOP;
1. RETURN;
1. END;
1. $body$
1. LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
1.
1. COMMENT ON FUNCTION "public"."table_msg"(a_table_name varchar)
1. IS '获得表信息';
Sql代码 [![收藏代码](http://lovejuan1314.iteye.com/images/icon_star.png)](# "收藏这段代码")
1. 例子
1.
1. CREATE TABLE "public"."login_log" (
1. "auto_bh" BIGSERIAL,
1. "yhm" VARCHAR(20) NOT NULL,
1. "dlsj" TIMESTAMP WITHOUT TIME ZONE DEFAULT date_trunc('second'::text, ('now'::text)::timestamp(6) with time zone) NOT NULL,
1. "dlip" VARCHAR(30) NOT NULL,
1. "dcsj" TIMESTAMP WITHOUT TIME ZONE DEFAULT date_trunc('second'::text, ('now'::text)::timestamp(6) with time zone) NOT NULL,
1. "zc" CHAR(4) NOT NULL,
1. "zxsj" VARCHAR(20) DEFAULT '00:00:00'::character varying,
1. CONSTRAINT "login_log_pkey" PRIMARY KEY("auto_bh", "dlsj")
1. ) WITH OIDS;
1.
1. COMMENT ON TABLE "public"."login_log"
1. IS '用户登录日记档';
1.
1. COMMENT ON COLUMN "public"."login_log"."auto_bh"
1. IS '系统编号';
1.
1. COMMENT ON COLUMN "public"."login_log"."yhm"
1. IS '用户名';
1.
1. COMMENT ON COLUMN "public"."login_log"."dlsj"
1. IS '登录时间';
1.
1. COMMENT ON COLUMN "public"."login_log"."dlip"
1. IS '登录IP';
1.
1. COMMENT ON COLUMN "public"."login_log"."dcsj"
1. IS '登出时间';
1.
1. COMMENT ON COLUMN "public"."login_log"."zc"
1. IS '进出';
1.
1. COMMENT ON COLUMN "public"."login_log"."zxsj"
1. IS '在线时间';
1.
1. select * from table_msg('public','login_log');
1. 或
1. select * from table_msg('login_log');
1.
1. 结果
1. fields_key_name | fields_name | fields_type | fields_length | fields_not_null | fields_default | fields_comment
1. -----------------+-------------+-------------+---------------+-----------------+------------------------------------------------------------------------+----------------
1. login_log_pkey | auto_bh | bigint | | not null | nextval('public.login_log_auto_bh_seq'::text) | 系统编号
1. | yhm | varchar | 20 | not null | | 用户名
1. | dlsj | timestamp | | not null | date_trunc('second'::text, ('now'::text)::timestamp(6) with time zone) | 登录时间
1. | dlip | varchar | 30 | not null | | 登录IP
1. | dcsj | timestamp | | not null | date_trunc('second'::text, ('now'::text)::timestamp(6) with time zone) | 登出时间
1. | zc | char | 4 | not null | | 进出
1. | zxsj | varchar | 20 | | '00:00:00'::character varying | 在线时间
1. (7 rows)
分享到: [![](http://lovejuan1314.iteye.com/images/sina.jpg)](# "分享到新浪微博") [![](http://lovejuan1314.iteye.com/images/tec.jpg)](# "分享到腾讯微博")
- 数据表
- 模式Schema
- 表的继承和分区
- 常用数据类型
- 函数和操作符-一
- 函数和操作符-二
- 函数和操作符-三
- 索引
- 事物隔离
- 性能提升技巧
- 服务器配置
- 角色和权限
- 数据库管理
- 数据库维护
- 系统表
- 系统视图
- SQL语言函数
- PL-pgSQL过程语言
- PostgreSQL 序列(SEQUENCE)
- PostgreSQL的时间-日期函数使用
- PostgreSQL 查看数据库,索引,表,表空间大小
- 用以查询某表的详细 包含表字段的注释信息
- PostgreSQL 系统表查看系统信息
- postgre存储过程简单实用方法
- PostgreSQL实用日常维护SQL
- PostgreSQL的时间函数使用整理
- 命令
- pg_ctl控制服务器
- initdb 初始化数据库簇
- createdb创建数据库
- dropdb 删除数据库
- createuser创建用户
- dropuser 删除用户
- psql交互式工具
- psql命令手册
- pg_dump 数据库转储
- pg_restore恢复数据库
- vacuumdb 清理优化数据库
- reindexdb 数据库重创索引
- createlang 安装过程语言
- droplang 删除过程语言
- pg_upgrade 升级数据库簇
- 调试存储过程
- 客户端命令-一
- 客户端命令-二
- 使用技巧
- PostgreSQL删除重复数据
- postgresql 小技巧
- PostgreSQL的10进制与16进制互转
- PostgreSQL的汉字转拼音
- Postgres重复数据的更新一例
- PostgreSQL使用with一例
- PostgreSQL在函数内返回returning
- PostgreSQL中的group_concat使用
- PostgreSQL数据库切割和组合字段函数
- postgresql重复数据的删除
- PostgreSQL的递归查询(with recursive)
- PostgreSQL函数如何返回数据集
- PostgreSQL分区表(Table Partitioning)应用 - David_Tang - 博客园
- PostgreSQL: function 返回结果集多列和单列的例子
- 利用pgAgent创建定时任务
- 浅谈 PostgreSQL 类型转换类似Oracle
- postgresql在windows(包括win7)下的安装配置
- PostgreSQL简介、安装、用户管理、启动关闭、创建删除数据库 (2010-11-08 12-52-51)转载▼标签: 杂谈分类: PostgreSQL
- PostgreSQL的generate_series函数应用
- PostgreSQL 8.3.1 全文检索(Full Text Search)
- postgresql record 使用
- 备份恢复
- PostgreSQL基于时间点恢复(PITR)
- Postgresql基于时间点恢复PITR案例(二)
- Postgres逻辑备份脚本
- Postgres invalid command \N数据恢复处理