zdsg
发布于

oushudb如何查看建表语句

1. 运行如下函数

CREATE OR REPLACE FUNCTION show_create_table(p_table_name varchar)
  RETURNS text AS
$BODY$
DECLARE
    v_table_ddl   text;
    column_record record;
BEGIN
    FOR column_record IN 
        SELECT 
            b.nspname as schema_name,
            b.relname as table_name,
            a.attname as column_name,
            pg_catalog.format_type(a.atttypid, a.atttypmod) as column_type,
            CASE WHEN 
                (SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
                 FROM pg_catalog.pg_attrdef d
                 WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) IS NOT NULL THEN
                'DEFAULT '|| (SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
                              FROM pg_catalog.pg_attrdef d
                              WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef)
            ELSE
                ''
            END as column_default_value,
            CASE WHEN a.attnotnull = true THEN 
                'NOT NULL'
            ELSE
                'NULL'
            END as column_not_null,
            a.attnum as attnum,
            e.max_attnum as max_attnum
        FROM 
            pg_catalog.pg_attribute a
            INNER JOIN 
             (SELECT c.oid,
                n.nspname,
                c.relname
              FROM pg_catalog.pg_class c
                   LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
              WHERE c.relname ~ ('^('||p_table_name||')$')
                AND pg_catalog.pg_table_is_visible(c.oid)
              ORDER BY 2, 3) b
            ON a.attrelid = b.oid
            INNER JOIN 
             (SELECT 
                  a.attrelid,
                  max(a.attnum) as max_attnum
              FROM pg_catalog.pg_attribute a
              WHERE a.attnum > 0 
                AND NOT a.attisdropped
              GROUP BY a.attrelid) e
            ON a.attrelid=e.attrelid
        WHERE a.attnum > 0 
          AND NOT a.attisdropped
        ORDER BY a.attnum
    LOOP
        IF column_record.attnum = 1 THEN
            v_table_ddl:='CREATE TABLE '||column_record.schema_name||'.'||column_record.table_name||' (';
        ELSE
            v_table_ddl:=v_table_ddl||',';
        END IF;
 
        IF column_record.attnum <= column_record.max_attnum THEN
            v_table_ddl:=v_table_ddl||chr(10)||
                     '    '||column_record.column_name||' '||column_record.column_type||' '||column_record.column_default_value||' '||column_record.column_not_null;
        END IF;
    END LOOP;
 
    v_table_ddl:=v_table_ddl||');';
    RETURN v_table_ddl;
END;
$BODY$
  LANGUAGE 'plpgsql';

2. 执行函数查看建表语句

select show_create_table('table_name');
评论(7)
  • 罗名岳
    罗名岳 回复

    补充了一部分,可以把分区表的建表语句也打出来

    CREATE OR REPLACE FUNCTION show_create_table(p_table_name varchar)
      RETURNS text AS
    $BODY$
    DECLARE
        v_table_ddl   text;
    	partition_ddl text;
    	pType 		  text;
    	pCol 		  text;
    	sql1		  text;
        column_record record;
    BEGIN
        FOR column_record IN 
            SELECT 
                b.nspname as schema_name,
                b.relname as table_name,
                a.attname as column_name,
                pg_catalog.format_type(a.atttypid, a.atttypmod) as column_type,
                CASE WHEN 
                    (SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
                     FROM pg_catalog.pg_attrdef d
                     WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) IS NOT NULL THEN
                    'DEFAULT '|| (SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
                                  FROM pg_catalog.pg_attrdef d
                                  WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef)
                ELSE
                    ''
                END as column_default_value,
                CASE WHEN a.attnotnull = true THEN 
                    'NOT NULL'
                ELSE
                    'NULL'
                END as column_not_null,
                a.attnum as attnum,
                e.max_attnum as max_attnum
            FROM 
                pg_catalog.pg_attribute a
                INNER JOIN 
                 (SELECT c.oid,
                    n.nspname,
                    c.relname
                  FROM pg_catalog.pg_class c
                       LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
                  WHERE c.relname ~ ('^('||p_table_name||')$')
                    AND pg_catalog.pg_table_is_visible(c.oid)
                  ORDER BY 2, 3) b
                ON a.attrelid = b.oid
                INNER JOIN 
                 (SELECT 
                      a.attrelid,
                      max(a.attnum) as max_attnum
                  FROM pg_catalog.pg_attribute a
                  WHERE a.attnum > 0 
                    AND NOT a.attisdropped
                  GROUP BY a.attrelid) e
                ON a.attrelid=e.attrelid
            WHERE a.attnum > 0 
              AND NOT a.attisdropped
            ORDER BY a.attnum
        LOOP
            IF column_record.attnum = 1 THEN
                v_table_ddl:='CREATE TABLE '||column_record.schema_name||'.'||column_record.table_name||' (';
            ELSE
                v_table_ddl:=v_table_ddl||',';
            END IF;
     
            IF column_record.attnum <= column_record.max_attnum THEN
                v_table_ddl:=v_table_ddl||chr(10)||
                         '    '||column_record.column_name||' '||column_record.column_type||' '||column_record.column_default_value||' '||column_record.column_not_null;
            END IF;
        END LOOP;
     
        v_table_ddl:=v_table_ddl||')';
        
    	
    	
    	select distinct partitiontype into pType from pg_partitions where tablename=p_table_name;
    	select distinct columnname into pCol from pg_partition_columns where tablename=p_table_name;
    	v_table_ddl = v_table_ddl || ' PARTITION BY '|| pType ||' ('||pCol||') (';
    	for sql1 in (select split_part(partitionboundary,'WITH',1) as pClause from pg_partitions where tablename=p_table_name)
    		loop
    			v_table_ddl := v_table_ddl ||sql1|| ',';
    		end loop;
    	v_table_ddl =  substring(v_table_ddl,1,length(v_table_ddl)-1);
    	v_table_ddl = v_table_ddl || ');';
    	RETURN v_table_ddl;
    END;
    $BODY$
      LANGUAGE 'plpgsql';
    
  • zdsg
    zdsg 回复
    張 zi 浩 張 zi 浩 2022-02-24 18:00:38

    pg_dump -d database -s -t schema.tablename 也可以看呢

    嗯嗯 好的 感谢

  • zdsg
    zdsg 回复
    罗名岳 罗名岳 2022-06-07 15:08:24

    这个函数分区表的建表语句也可以看到么

    如果感兴趣的话,可以研究一下元数据表,看看怎么实现,期待

  • zdsg
    zdsg 回复
    罗名岳 罗名岳 2022-06-07 15:08:24

    这个函数分区表的建表语句也可以看到么

    这个暂时不可以,但是可以使用 pgAdmin3 客户端 查看分区表的建表语句

  • 罗名岳
    罗名岳 回复

    这个函数分区表的建表语句也可以看到么

  • 張 zi 浩
    張 zi 浩 回复

    pg_dump -d database -s -t schema.tablename 也可以看呢

test