暂无图片
暂无图片
3
暂无图片
暂无图片
暂无图片

pageinspect模块详解

PostgreSQL数据库工作学习随笔 2022-03-26
2309

    pageinspect模块提供函数让你从低层次观察数据库页面的内容,这对于调试目的很有用。要求所有这些函数只能被超级用户使用。

    通用函数

    get_raw_page(relname text,fork text,blkon int) 返回bytea

    如果只读取主分支信息可以写成:

    get_raw_page(relname text,blkon int) 返回bytea

        get_raw_page读取提及的关系中的指定块并且以一个bytea值的形式返回一个拷贝。这允许得到该块的一个单一的时间一致的拷贝。对于主数据库分支,fork应该是"main",对于空闲空间映射应该是"fsm",对于可见性映射应该是"vm",对于初始化分支应该时"init"。

    每个关系(relation) 可能会有四种分支,分支编号分别为0,1,2,3,0号分支main为关系数据文件本体,1号分支fsm保存了main分支中空闲空间的信息,2号分支vm保存了main分支中可见性的信息,3号分支init是很少见的特殊分支,通常用于不被日志记录(unlogged)的表与索引。   

    postgres=# create table test (id int,name varchar);
    CREATE TABLE
    postgres=# insert into test values (1,'tom');
    INSERT 0 1
    postgres=# insert into test values (2,'lucy');
    INSERT 0 1
    postgres=# select * from get_raw_page('test','main',0);
    -[ RECORD 1 ]+---------------------
    get_raw_page | \x050000...0009746f6d
    postgres=# select * from get_raw_page('test','fsm',0);
    -[ RECORD 1 ]+---------------------
    get_raw_page | \x050000...00000000
    postgres=# select * from get_raw_page('test','vm',0);
    -[ RECORD 1 ]+---------------------
    get_raw_page | \x05000...0000000
    postgres=# select * from get_raw_page('test','init',0);
    ERROR:  could not open file "base/13593/1081011_init": No such file or directory
    postgres=# select pg_relation_filepath('test');
    pg_relation_filepath
    ----------------------
     base/13593/1081013
    postgres=# \q
    [pg12@k8s2 pgdata]$ ll base/13593/1081011
    1081013      1081013_fsm  1081013_vm
    [pg12@k8s2 pgdata]
    创建unlogged表
    postgres=# create unlogged table test1 (id int);
    CREATE TABLE
    postgres=# insert into test1 values (1);
    INSERT 0 1
    postgres=# insert into test1 values (2);
    INSERT 0 1
    postgres=# insert into test1 values (3);
    INSERT 0 1
    postgres=# vacuum test1;
    VACUUM
    postgres=# select pg_relation_filepath('test1');
    pg_relation_filepath
    ----------------------
    base/13593/1081016
    (1 row)
    postgres=# \q
    [pg12@k8s2 pgdata]$ ll base/13593/1081016
    1081016 1081016_fsm 1081016_init 1081016_vm
    [pg12@k8s2 pgdata]$

    page_header(page bytea) 返回record

        page_header显示所有PostgreSQL堆和索引页面的公共域(可以看到unlogged 创建的表没有记录wal日志,所以lsn为0/0)。

        用get_raw_page获得的一个页面影像作为参数传递。

      postgres=# select * from page_header(get_raw_page('test',0));
      lsn | checksum | flags | lower | upper | special | pagesize | version | prune_xid
      ------------+----------+-------+-------+-------+---------+----------+---------+-----------
      5/4C8A8688 | 0 | 4 | 32 | 8120 | 8192 | 8192 | 4 | 0
      (1 row)

      postgres=#

      postgres=# select * from page_header(get_raw_page('test1',0));
      lsn | checksum | flags | lower | upper | special | pagesize | version | prune_xid
      -----+----------+-------+-------+-------+---------+----------+---------+-----------
      0/0 | 0 | 4 | 36 | 8096 | 8192 | 8192 | 4 | 0
      (1 row)

      postgres=#
      详见src/include/storage/bufpage.h。

      任何页面通用的空间管理信息

          pd_lsn - 标识此页面的最后更改的 xlog 记录。

          pd_checksum - 页面校验和。

          pd_flags - 标志位。

          pd_lower - 到可用空间开始的偏移量,指向最后一个指针末尾。

          pd_upper - 到可用空间末尾的偏移量,指向最新元组的起始位置。

          pd_special - 特殊空间开始的偏移量。

          pd_pagesize_version - 字节大小和页面布局版本号。

          pd_prune_xid - 页面上可能可修剪的元组中最旧的 XID。

          checksum域时存放在页面中的校验和,如果页面被损坏它可能是不正确的值。查看实例是否启用数据校验和(1是开启,0是关闭),如果没有启用存储这个值没有意义。

        [pg12@k8s2 ~]$ pg_controldata |grep checksum
        Data page checksum version: 1
        [pg12@k8s2 ~]$

        page_checksum(page bytea,blkon int) returns smallint

            page_checksum为页面计算校验和,就像它被放置在给定块上一样。

            应该将get_raw_page获得的页面映像作为参数传入。

            注意校验和取决于块号,因此应该将匹配的块号传入。

            用这个函数计算的校验和可以和函数page_header的结果域checksum进行比较。如果为这个实例启用了数据校验和,则两个值应该相等。

          postgres=# select * from page_header(get_raw_page('tbl_test',0));
          lsn | checksum | flags | lower | upper | special | pagesize | version | prune_xid
          ------------+----------+-------+-------+-------+---------+----------+---------+-----------
          5/4C87FD98 | 10445 | 5 | 452 | 7544 | 8192 | 8192 | 4 | 0
          (1 row)

          postgres=# select * from page_checksum(get_raw_page('tbl_test',0),0);
          page_checksum
          ---------------
          10445
          (1 row)

          postgres=# select * from page_header(get_raw_page('tbl_test',2));
          lsn | checksum | flags | lower | upper | special | pagesize | version | prune_xid
          ------------+----------+-------+-------+-------+---------+----------+---------+-----------
          5/4C12DF40 | 32692 | 4 | 452 | 488 | 8192 | 8192 | 4 | 0
          (1 row)

          postgres=# select * from page_checksum(get_raw_page('tbl_test',2),2);
          page_checksum
          ---------------
          32692
          (1 row)

          postgres=#

          fsm_page_contents(page bytea) returns text

              fsm_page_contents显示FSM页面的内部节点结构。

              输出为多行字符串,页面中的二进制树中每个节点有一行。仅有不为0的节点会被打印。所谓的"next"指针,指向页面中下一个要返回的槽,也会被打印。

            postgres=# select * from fsm_page_contents(get_raw_page('test','fsm',0));
            fsm_page_contents
            -------------------
            0: 252 +
            1: 252 +
            3: 252 +
            7: 252 +
            15: 252 +
            31: 252 +
            63: 252 +
            127: 252 +
            255: 252 +
            511: 252 +
            1023: 252 +
            2047: 252 +
            4095: 252 +
            fp_next_slot: 0 +

            (1 row)

            postgres=#

            HEAP函数

                

            heap_page_items(page bytea) returns setof record

                heap_page_items显示一个堆页面上所有的行指针。对那些使用中的行指针,元组头部和元组原始数据也会被显示。不管元组对拷贝原始页面的MVCC快照是否可见。他们都会被显示。

                用get_raw_page获得的一个堆页面映像应该作为参数传递。

              postgres=# select * from heap_page_items(get_raw_page('test2',0));
              lp | lp_off | lp_flags | lp_len | t_xmin | t_xmax | t_field3 | t_ctid | t_infomask2 | t_infomask | t_hoff | t_bits | t_oid | t_data
              ----+--------+----------+--------+--------+--------+----------+--------+-------------+------------+--------+--------+-------+------------
              1 | 8160 | 1 | 28 | 704481 | 0 | 0 | (0,1) | 1 | 2304 | 24 | | | \x01000000
              2 | 8128 | 1 | 28 | 704482 | 0 | 0 | (0,2) | 1 | 2048 | 24 | | | \x02000000
              3 | 8096 | 1 | 28 | 704483 | 0 | 0 | (0,3) | 1 | 2048 | 24 | | | \x03000000
              (3 rows)

              postgres=

              详见src/include/storage/itemid.h和src/include/access/htup_details.h

              lp_off 到元组的偏移量(从页面开始)

              lp_flags 行指针状态

                  0 未使用

                  1 已使用

                  2 HOT 重定向

                  3 死元组

              lp_len 元组的字节长度

              t_xmin inserting xact ID 

              t_xmax deleting or locking xact ID

              t_field3 插入或删除命令ID(t_cid)和旧版本VACUUM FULL xact ID

              t_ctid current TID of this or newer tuple (or a speculative insertion token) 

              t_infomask2 number of attributes + various flags

              t_infomask various flag bits

                  记录提交状态事物提交状态解析

              t_hoff  sizeof header incl. bitmap, padding 

              t_bits bitmap of NULLs

              tuple_data_split(rel_oid oid,t_data bytea,t_infomask integer,t_informask2 integer,t_bits text[,do_detoast bool)] returns bytea[]

                  tuple_data_split以后端内部的相同方式将元组数据拆解成属性。

                postgres=# select tuple_data_split('test'::regclass,t_data,t_infomask,t_infomask2,t_bits) from heap_page_items(get_raw_page('test',0));
                tuple_data_split
                ---------------------------------
                {"\\x01000000","\\x09746f6d"}
                {"\\x02000000","\\x0b6c756379"}
                (2 rows)

                postgres=#

                heap_page_item_attrs(page bytea,rel_oid regclass [,do_detoast boool]) returns setof record

                    heap_page_item_attrs等效于heap_page_items,不过它会把元组原始数据返回为属性的数组,如果do_detoast为真(默认为false),这些数据会被反toast。

                    应该把用get_raw_page得到的一个堆页面映像作为参数传入。

                  postgres=# select * from heap_page_item_attrs(get_raw_page('test2',0),'test2'::regclass);
                  lp | lp_off | lp_flags | lp_len | t_xmin | t_xmax | t_field3 | t_ctid | t_infomask2 | t_infomask | t_hoff | t_bits | t_oid | t_attrs
                  ----+--------+----------+--------+--------+--------+----------+--------+-------------+------------+--------+--------+-------+-----------------
                  1 | 8160 | 1 | 28 | 704481 | 0 | 0 | (0,1) | 1 | 2304 | 24 | | | {"\\x01000000"}
                  2 | 8128 | 1 | 28 | 704482 | 0 | 0 | (0,2) | 1 | 2304 | 24 | | | {"\\x02000000"}
                  3 | 8096 | 1 | 28 | 704483 | 0 | 0 | (0,3) | 1 | 2304 | 24 | | | {"\\x03000000"}
                  (3 rows)

                  postgres=# s

                  B树函数

                  bt_metap(relname text) returns record

                      bt_metap返回关于一个B树索引元页的信息。

                    postgres=# select * from bt_metap('test2_pkey');
                    -[ RECORD 1 ]-----------+-------
                    magic | 340322
                    version | 4
                    root | 1
                    level | 0
                    fastroot | 1
                    fastlevel | 0
                    oldest_xact | 0
                    last_cleanup_num_tuples | 3

                    postgres=#
                    详见src/include/access/nbtxlog.

                    bt_page_stats(relname text,blkno int) returns record

                        bt_page_stats返回有关B-树索引单一页面的总计信息。

                      postgres=# select * from bt_page_stats('test2_pkey',1);
                      -[ RECORD 1 ]-+-----
                      blkno | 1
                      type | l
                      live_items | 3
                      dead_items | 0
                      avg_item_size | 16
                      page_size | 8192
                      free_size | 8088
                      btpo_prev | 0
                      btpo_next | 0
                      btpo | 0
                      btpo_flags | 3

                      postgres=#

                      bt_page_items(relname text,blkon int) returns setof record

                          bt_page_items返回一个B-树索引页面上的所有细节信息,也可以把页面以bytea值的形式传递给bt_page_items。

                          可以通过bt_page_items来学习HOT。

                        postgres=# select * from bt_page_items('test2_pkey',1);
                        itemoffset | ctid | itemlen | nulls | vars | data
                        ------------+-------+---------+-------+------+-------------------------
                        1 | (0,1) | 16 | f | f | 01 00 00 00 00 00 00 00
                        2 | (0,2) | 16 | f | f | 02 00 00 00 00 00 00 00
                        3 | (0,3) | 16 | f | f | 03 00 00 00 00 00 00 00
                        (3 rows)

                        postgres=# select * from bt_page_items(get_raw_page('test2_pkey',1));
                        itemoffset | ctid | itemlen | nulls | vars | data
                        ------------+-------+---------+-------+------+-------------------------
                        1 | (0,1) | 16 | f | f | 01 00 00 00 00 00 00 00
                        2 | (0,2) | 16 | f | f | 02 00 00 00 00 00 00 00
                        3 | (0,3) | 16 | f | f | 03 00 00 00 00 00 00 00
                        (3 rows)

                        postgres=#

                        BRIN函数

                        brin_page_type(page bytea) returns text

                            brin_page_type返回一个给定的BRIN索引页面的页面类型,如果该页面不是一个合法的BRIN页面则抛出错误。

                          postgres=# select brin_page_type(get_raw_page('test2_pkey',0));
                          brin_page_type
                          ----------------
                          unknown (00)
                          (1 row)
                                                                    ^
                          postgres=# create index brin_test2_idx on test2 using brin (name);
                          CREATE INDEX
                          postgres=# select brin_page_type(get_raw_page('brin_test2_idx',0));
                          brin_page_type
                          ----------------
                          meta
                          (1 row)

                          postgres=#

                          brin_metapage_info(page bytea) returns record

                              brin_metapage_info返回有关一个BRIN索引页面的详细信息。

                            postgres=# select * from brin_metapage_info(get_raw_page('brin_test2_idx',0));
                            magic | version | pagesperrange | lastrevmappage
                            ------------+---------+---------------+----------------
                            0xA8109CFA | 1 | 128 | 1
                            (1 row)

                            postgres=#

                            brin_revmap_data(page bytea) returns setof tid

                                brin_revmap_data返回一个BRIN索引范围映射页面中元组标识符的表。


                              postgres=# select * from brin_revmap_data(get_raw_page('brin_test2_idx',1)) limit 5;
                              pages
                              -------
                              (2,1)
                              (0,0)
                              (0,0)
                              (0,0)
                              (0,0)
                              (5 rows)

                              postgres=#

                              brin_page_items(page bytea,index oid) returns setof record

                                  brin_page_items返回存在BRIN数据页面中存储的数据。

                                postgres=# select * from brin_page_items(get_raw_page('brin_test2_idx',2),'brin_test2_idx');
                                itemoffset | blknum | attnum | allnulls | hasnulls | placeholder | value
                                ------------+--------+--------+----------+----------+-------------+---------------
                                1 | 0 | 1 | f | t | f | {lucy .. tom}
                                (1 row)

                                postgres=#
                                详见src/include/access/brin_tuple.h

                                GIN函数

                                gin_metapage_info(page bytea) returns record

                                    gin_metapage_info返回有关一个GIN索引元页的信息。

                                  postgres=# select * from gin_metapage_info(get_raw_page('gin_tbl_idx',0));
                                  -[ RECORD 1 ]----+-----------
                                  pending_head | 4294967295
                                  pending_tail | 4294967295
                                  tail_free_size | 0
                                  n_pending_pages | 0
                                  n_pending_tuples | 0
                                  n_total_pages | 1151
                                  n_entry_pages | 1134
                                  n_data_pages | 16
                                  n_entries | 4624
                                  version | 2

                                  postgres=#

                                  gin_page_opaque_info(page bytea) returns record

                                      gin_page_opaque_info返回有关一个GIN索引不透明区域的信息,如页面类型等。

                                    postgres=# select * from gin_page_opaque_info(get_raw_page('gin_tbl_idx',2));
                                    rightlink | maxoff | flags
                                    ------------+--------+------------------------
                                    4294967295 | 0 | {data,leaf,compressed}
                                    (1 row)

                                    postgres=#

                                    gin_leafpage_items(page bytea) returns setof record

                                        gin_leafpage_items返回有关储存在一个GIN叶子页面中的数据信息。

                                      postgres=# SELECT first_tid, nbytes, tids[0:5] AS some_tids FROM gin_leafpage_items(get_raw_page('gin_tbl_idx', 2));
                                      first_tid | nbytes | some_tids
                                      -----------+--------+------------------------------------------------------------
                                      (0,101) | 376 | {"(0,101)","(0,107)","(1,17)","(1,24)","(1,72)"}
                                      (50,78) | 376 | {"(50,78)","(50,86)","(51,11)","(51,22)","(51,29)"}
                                      (100,5) | 376 | {"(100,5)","(100,59)","(100,74)","(100,98)","(101,8)"}
                                      (150,68) | 376 | {"(150,68)","(150,77)","(150,88)","(150,104)","(150,107)"}
                                      (199,23) | 375 | {"(199,23)","(199,25)","(199,26)","(199,28)","(199,34)"}
                                      (250,13) | 376 | {"(250,13)","(250,17)","(250,35)","(250,36)","(250,41)"}
                                      (297,88) | 376 | {"(297,88)","(297,103)","(297,105)","(298,16)","(298,39)"}
                                      (347,80) | 376 | {"(347,80)","(348,7)","(348,8)","(348,21)","(348,41)"}
                                      (396,79) | 376 | {"(396,79)","(396,96)","(396,104)","(397,9)","(397,19)"}
                                      (444,58) | 376 | {"(444,58)","(444,62)","(444,72)","(444,98)","(445,26)"}
                                      (498,69) | 376 | {"(498,69)","(498,76)","(498,78)","(498,86)","(498,87)"}
                                      (547,81) | 375 | {"(547,81)","(548,17)","(548,34)","(548,45)","(548,74)"}
                                      (594,8) | 376 | {"(594,8)","(594,24)","(594,61)","(594,63)","(594,82)"}
                                      (644,98) | 376 | {"(644,98)","(645,6)","(645,14)","(645,19)","(645,26)"}
                                      (693,84) | 376 | {"(693,84)","(693,95)","(693,99)","(693,102)","(694,3)"}
                                      (741,87) | 376 | {"(741,87)","(741,89)","(741,106)","(741,107)","(742,12)"}
                                      (789,62) | 376 | {"(789,62)","(789,75)","(789,102)","(789,103)","(790,5)"}
                                      (840,44) | 376 | {"(840,44)","(840,107)","(841,19)","(841,21)","(841,39)"}
                                      (888,2) | 375 | {"(888,2)","(888,5)","(888,8)","(888,16)","(888,21)"}
                                      (19 rows)

                                      postgres=#

                                      HASH函数

                                      hash_page_type(page bytea) returns text

                                          hash_page_type返回给定的hash索引页面的页面类型。

                                        postgres=# create index hash_tbl_idx on tbl_test using hash (info);
                                        CREATE INDEX
                                        postgres=# select * from hash_page_type(get_raw_page('hash_tbl_idx',0));
                                        hash_page_type
                                        ----------------
                                        metapage
                                        (1 row)

                                        postgres=#

                                        hash_page_stats(page bytea) returns setof record

                                            hash_page_stats返回有关一个HASH索引的桶页或者溢出页的信息。

                                          postgres=# select * from hash_page_stats(get_raw_page('hash_tbl_idx',1));
                                          -[ RECORD 1 ]---+-----------
                                          live_items | 201
                                          dead_items | 0
                                          page_size | 8192
                                          free_size | 4128
                                          hasho_prevblkno | 511
                                          hasho_nextblkno | 4294967295
                                          hasho_bucket | 0
                                          hasho_flag | 2
                                          hasho_page_id | 65408
                                          postgres=#

                                          hash_page_items(page bytea) returns setof record

                                              hash_page_items返返回有关一个HASH索引的桶页或者溢出页中存储的数据的信息。

                                            postgres=# select * from hash_page_items(get_raw_page('hash_tbl_idx',1)) limit 6;
                                            itemoffset | ctid | data
                                            ------------+-----------+----------
                                            1 | (587,81) | 6690304
                                            2 | (599,40) | 30260224
                                            3 | (568,84) | 42152960
                                            4 | (112,12) | 45416960
                                            5 | (322,79) | 50068480
                                            6 | (793,103) | 53645824
                                            (6 rows)

                                            postgres=# select * from hash_page_items(get_raw_page('hash_tbl_idx',2)) limit 6;
                                            itemoffset | ctid | data
                                            ------------+-----------+-----------
                                            1 | (684,51) | 53047809
                                            2 | (361,72) | 69544449
                                            3 | (348,103) | 100082177
                                            4 | (505,63) | 107412993
                                            5 | (771,48) | 117727233
                                            6 | (525,87) | 141176833
                                            (6 rows)

                                            postgres=#

                                            hash_bitmap_info(index oid,blkno int) returns record

                                                hash_bitmap_info返回HASH所以一个特定溢出页在位图页中的位的状态(没搞懂这个溢出页场景,以后有机会遇到了再补上)。

                                              postgres=# select * from hash_bitmap_info('hash_test2_idx',0);
                                              ERROR: invalid overflow block number 0
                                              postgres=#

                                              hash_metapage_info(page bytea) returns record

                                                  hash_metapage_info返回一个HASH索引的元页中存放的信息。

                                                postgres=# select * from hash_metapage_info(get_raw_page('hash_test2_idx',0));
                                                -[ RECORD 1 ]--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
                                                magic | 105121344
                                                version | 4
                                                ntuples | 3
                                                ffactor | 307
                                                bsize | 8152
                                                bmsize | 4096
                                                bmshift | 15
                                                maxbucket | 1
                                                highmask | 3
                                                lowmask | 1
                                                ovflpoint | 1
                                                firstfree | 0
                                                nmaps | 1
                                                procid | 400
                                                spares | {0,1,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0}
                                                mapp | {3,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0}

                                                postgres=#

                                                文章转载自PostgreSQL数据库工作学习随笔,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

                                                评论