{"id":178,"date":"2020-10-01T02:00:27","date_gmt":"2020-09-30T18:00:27","guid":{"rendered":"https:\/\/www.mengqingzhong.com\/?p=178"},"modified":"2021-01-01T19:17:37","modified_gmt":"2021-01-01T11:17:37","slug":"postgresql-index-interface-2","status":"publish","type":"post","link":"https:\/\/www.mengqingzhong.com\/2020\/10\/01\/postgresql-index-interface-2\/","title":{"rendered":"PostgreSQL\u7d22\u5f15(2) \u2013 \u63a5\u53e3"},"content":{"rendered":"
\n\u672c\u6587\u7ffb\u8bd1\u81eaEgor Rogov\u7684\u82f1\u6587\u535a\u5ba2<\/a>\uff0c\u4e14\u5df2\u5f81\u5f97Egor Rogov\u7684\u540c\u610f\u3002\u8bd1\u8005\u505a\u4e86\u5c11\u91cf\u4fee\u6539\u3002\n<\/p>\n \n\u5ba1\u6821\uff1a\u7eaa\u6600\u7ea2\uff0c\u4e2d\u56fd\u4eba\u6c11\u5927\u5b66\u4fe1\u606f\u5b66\u9662\u5728\u8bfb\u535a\u58eb\u751f\u3002\n<\/p>\n \u7b2c\u4e00\u7bc7\u6587\u7ae0<\/a>\u4e2d\u63d0\u5230\uff0c\u4e00\u4e2aAM\u5fc5\u987b\u80fd\u591f\u63d0\u4f9b\u5173\u4e8e\u5b83\u81ea\u5df1\u7684\u4fe1\u606f\u3002\u4e0b\u9762\u4ecb\u7ecdAM\u63a5\u53e3\u7684\u7ed3\u6784\u3002<\/p>\n AM\u7684\u6240\u6709\u5c5e\u6027\u90fd\u5b58\u50a8\u5728pg_am(“am”\u662faccess method\u7684\u7b80\u79f0)\u7cfb\u7edf\u8868\u4e2d\u3002\u6211\u4eec\u53ef\u4ee5\u4ece\u8fd9\u5f20\u7cfb\u7edf\u8868\u4e2d\u67e5\u51fa\u6240\u6709\u53ef\u7528\u7684AM\u5217\u8868\uff1a<\/p>\n \u867d\u7136\u987a\u5e8f\u626b\u63cf\u4e5f\u662f\u4e00\u79cdAM\uff0c\u4f46\u7531\u4e8e\u5386\u53f2\u539f\u56e0\uff0c\u5b83\u6ca1\u6709\u88ab\u5217\u5165\u5176\u4e2d\u3002<\/p>\n \u5728PG 9.5\u53ca\u4e4b\u524d\uff0c\u6bcf\u4e2a\u5c5e\u6027\u7528pg_am\u8868\u4e2d\u7684\u4e00\u4e2a\u5b57\u6bb5\u8868\u793a\u3002\u4ecePG 9.6\u5f00\u59cb\uff0c\u9700\u8981\u4f7f\u7528\u7279\u6b8a\u7684\u51fd\u6570\u67e5\u8be2\u8fd9\u4e9b\u5c5e\u6027\uff0c\u5e76\u4e14\u8fd9\u4e9b\u5c5e\u6027\u88ab\u5206\u4e3a\u4e09\u4e2a\u5c42\u6b21\u3002<\/p>\n \u524d\u4e24\u4e2a\u5c42\u6b21\u4e3b\u8981\u4e3a\u672a\u6765\u8003\u8651\uff0c\u76ee\u524d\u540c\u4e00\u79cdAM\u7684\u6240\u6709\u7d22\u5f15\u90fd\u5177\u6709\u76f8\u540c\u7684\u5c5e\u6027\u3002<\/p>\n \u4e0b\u97624\u4e2a\u5c5e\u6027\u662fAM\u5c42\u7684\u5c5e\u6027\uff08\u4ee5btree\u4e3a\u4f8b\uff09\uff1a<\/strong><\/p>\n \u4e0b\u9762\u7684\u5c5e\u6027\u662f\u67d0\u4e2a\u5177\u4f53\u7d22\u5f15\u7684\u5c5e\u6027\uff1a<\/strong><\/p>\n \u4e0b\u9762\u662f\u5177\u4f53\u7d22\u5f15\u4e2d\u67d0\u4e2a\u5217\u7684\u5c5e\u6027\uff1a<\/strong><\/p>\n \u6211\u4eec\u5df2\u7ecf\u8be6\u7ec6\u5730\u8ba8\u8bba\u4e86\u4e00\u4e9b\u5c5e\u6027\u3002\u6709\u4e00\u4e9b\u5c5e\u6027\u4e0e\u5177\u4f53\u7684AM\u76f8\u5173\uff0c\u6211\u4eec\u5c06\u5728\u8ba8\u8bba\u5404\u79cdAM\u65f6\u7ee7\u7eed\u4ecb\u7ecd\u3002<\/p>\n \u9664\u4e86\u4e0a\u6587\u4ecb\u7ecd\u7684AM\u7684\u63a5\u53e3\u4e4b\u540e\uff0c\u8fd8\u9700\u8981\u77e5\u9053\u4e00\u4e2aAM\u53ef\u4ee5\u652f\u6301\u54ea\u4e9b\u6570\u636e\u7c7b\u578b\u548c\u64cd\u4f5c\u7b26\u3002\u4e3a\u4e86\u8fbe\u5230\u8fd9\u4e2a\u76ee\u7684\uff0cPG\u5f15\u5165\u4e86\u64cd\u4f5c\u7b26\u7c7b\uff08operator class\uff09\u548c\u64cd\u4f5c\u7b26\u65cf\uff08operator family\uff09\u7684\u6982\u5ff5\u3002<\/p>\n \u4e00\u4e2a\u64cd\u4f5c\u7b26\u7c7b\u5305\u542b\u4e00\u4e2a\u6700\u5c0f\u7684\u64cd\u4f5c\u7b26\uff08\u53ef\u80fd\u8fd8\u5305\u542b\u4e00\u4e9b\u8f85\u52a9\u51fd\u6570\uff09\u7684\u96c6\u5408\uff0c\u4f7f\u5f97\u7d22\u5f15\u53ef\u4ee5\u64cd\u4f5c\u67d0\u4e2a\u7279\u5b9a\u7684\u6570\u636e\u7c7b\u578b\u3002<\/p>\n \u4e00\u4e2a\u64cd\u4f5c\u7b26\u7c7b\u88ab\u67d0\u4e9b\u64cd\u4f5c\u7b26\u65cf\u5305\u542b\u3002\u66f4\u786e\u5207\u7684\u8bf4\uff0c\u4e00\u4e2a\u64cd\u4f5c\u7b26\u65cf\u53ef\u4ee5\u5305\u542b\u591a\u4e2a\u64cd\u4f5c\u7b26\u7c7b\uff0c\u5982\u679c\u5b83\u4eec\u5177\u6709\u76f8\u540c\u7684\u8bed\u4e49\u3002\u4f8b\u5982\uff0cinteger_ops\u65cf\u5305\u542bint8_ops\u3001int4_ops\u3001int2_ops\u4e09\u4e2a\u7c7b\u3002\u8fd9\u4e09\u4e2a\u7c7b\u5206\u522b\u5bf9\u5e94bigint\u3001integer\u3001smallint\u4e09\u4e2a\u6570\u636e\u7c7b\u578b, \u5b83\u4eec\u7684\u7cbe\u5ea6\u4e0d\u540c\uff0c\u4f46\u662f\u8bed\u4e49\u76f8\u540c\uff1a<\/p>\n \u518d\u4e3e\u4e00\u4f8b\uff1adatetime_ops\u65cf\u5305\u542b\u64cd\u4f5c\u65e5\u671f\u7684\u64cd\u4f5c\u7b26\u7c7b<\/p>\n \u4e00\u4e2a\u64cd\u4f5c\u7b26\u65cf\u53ef\u4ee5\u5305\u542b\u591a\u4e2a\u64cd\u4f5c\u7b26\u7c7b\u7528\u6765\u6bd4\u8f83\u4e0d\u540c\u7c7b\u578b\u7684\u503c\u3002\u5c06\u64cd\u4f5c\u7b26\u7c7b\u6309\u64cd\u4f5c\u7b26\u65cf\u5206\u7ec4\uff0c\u53ef\u4ee5\u4f7f\u5f97\u4f18\u5316\u5668\u5728\u8c13\u8bcd\u6761\u4ef6\u4e2d\u7684\u6570\u636e\u7c7b\u578b\u4e0e\u7d22\u5f15\u5217\u7684\u7c7b\u578b\u4e0d\u5339\u914d\u65f6\u7167\u6837\u53ef\u4ee5\u4f7f\u7528\u7d22\u5f15\u3002\u64cd\u4f5c\u7b26\u65cf\u8fd8\u53ef\u4ee5\u5305\u542b\u5176\u5b83\u8f85\u52a9\u51fd\u6570\u3002<\/p>\n \u5927\u591a\u6570\u60c5\u51b5\u4e0b\uff0c\u6211\u4eec\u65e0\u9700\u4e86\u89e3\u64cd\u4f5c\u7b26\u7c7b\u3001\u64cd\u4f5c\u7b26\u65cf\u3002\u901a\u5e38\u60c5\u51b5\u4e0b\uff0c\u6211\u4eec\u53ea\u9700\u4f7f\u7528\u9ed8\u8ba4\u7684\u64cd\u4f5c\u7b26\u521b\u5efa\u7d22\u5f15\u5373\u53ef\u3002<\/p>\n \u7136\u800c\uff0c\u6709\u65f6\u9700\u8981\u663e\u5f0f\u6307\u5b9a\u5177\u4f53\u7684\u64cd\u4f5c\u7b26\u7c7b\u3002\u4e0b\u9762\u7ed9\u51fa\u4e00\u4e2a\u9700\u8981\u663e\u5f0f\u6307\u5b9a\u7684\u4f8b\u5b50\uff1a\u5728collation\u4e0d\u662fC\u7684\u6570\u636e\u5e93\u4e2d\uff0c\u5e38\u89c4\u7684\u7d22\u5f15\u4e0d\u652f\u6301LIKE\u64cd\u4f5c\uff1a<\/p>\n \u6211\u4eec\u53ef\u4ee5\u4f7f\u7528text_pattern_ops\u64cd\u4f5c\u7b26\u7c7b\u521b\u5efa\u7d22\u5f15\uff0c\u4ece\u800c\u6d88\u9664\u8fd9\u4e2a\u9650\u5236\u3002<\/p>\n \u4f5c\u4e3a\u672c\u6587\u7684\u603b\u7ed3\uff0c\u4e0b\u9762\u5217\u51fa\u4e00\u4e2a\u7b80\u5316\u7684\u7cfb\u7edf\u8868\u7684\u5173\u7cfb\u56fe\uff0c\u5b83\u5c55\u793a\u4e86\u4e0e\u64cd\u4f5c\u7b26\u7c7b\u3001\u64cd\u4f5c\u7b26\u65cf\u76f4\u63a5\u76f8\u5173\u7684\u4e00\u4e9b\u7cfb\u7edf\u8868\u4e4b\u95f4\u7684\u5173\u7cfb\u3002<\/p>\n1. \u5c5e\u6027<\/h1>\n
select amname from pg_am;\n<\/code><\/pre>\n
amname\n--------\n btree\n hash\n gist\n gin\n spgist\n brin\n(6 rows)\n<\/code><\/pre>\n
\n
select a.amname, p.name, pg_indexam_has_property(a.oid,p.name)\nfrom pg_am a,\n unnest(array[\n 'can_order','can_unique','can_multi_col','can_exclude'\n ]) p(name)\nwhere a.amname = 'btree'\norder by a.amname;\n<\/code><\/pre>\n
amname | name | pg_indexam_has_property\n--------+---------------+-------------------------\n btree | can_order | t\n btree | can_unique | t\n btree | can_multi_col | t\n btree | can_exclude | t\n(4 rows)\n<\/code><\/pre>\n
\n
select p.name, pg_index_has_property('t_a_idx'::regclass,p.name)\nfrom unnest(array[\n 'clusterable','index_scan','bitmap_scan','backward_scan'\n ]) p(name);\n<\/code><\/pre>\n
name | pg_index_has_property\n---------------+-----------------------\n clusterable | t\n index_scan | t\n bitmap_scan | t\n backward_scan | t\n(4 rows)\n<\/code><\/pre>\n
\n
select p.name,\n pg_index_column_has_property('t_a_idx'::regclass,1,p.name)\nfrom unnest(array[\n 'asc','desc','nulls_first','nulls_last','orderable',\n 'distance_orderable','returnable','search_array',\n 'search_nulls'\n ]) p(name);\n<\/code><\/pre>\n
name | pg_index_column_has_property\n--------------------+------------------------------\n asc | t\n desc | f\n nulls_first | f\n nulls_last | t\n orderable | t\n distance_orderable | f\n returnable | t\n search_array | t\n search_nulls | t\n(9 rows)\n<\/code><\/pre>\n
\n
\u64cd\u4f5c\u7b26\u7c7b\u548c\u64cd\u4f5c\u7b26\u65cf<\/h1>\n
select opfname, opcname, opcintype::regtype\nfrom pg_opclass opc, pg_opfamily opf\nwhere opf.opfname = 'integer_ops'\nand opc.opcfamily = opf.oid\nand opf.opfmethod = (\n select oid from pg_am where amname = 'btree'\n );\n<\/code><\/pre>\n
opfname | opcname | opcintype\n-------------+----------+-----------\n integer_ops | int2_ops | smallint\n integer_ops | int4_ops | integer\n integer_ops | int8_ops | bigint\n(3 rows)\n<\/code><\/pre>\n
select opfname, opcname, opcintype::regtype\nfrom pg_opclass opc, pg_opfamily opf\nwhere opf.opfname = 'datetime_ops'\nand opc.opcfamily = opf.oid\nand opf.opfmethod = (\n select oid from pg_am where amname = 'btree'\n );\n<\/code><\/pre>\n
opfname | opcname | opcintype \n--------------+-----------------+-----------------------------\n datetime_ops | date_ops | date\n datetime_ops | timestamptz_ops | timestamp with time zone\n datetime_ops | timestamp_ops | timestamp without time zone\n(3 rows)\n<\/code><\/pre>\n
show lc_collate;\n<\/code><\/pre>\n
lc_collate \n-------------\n en_US.UTF-8\n(1 row)\n<\/code><\/pre>\n
explain (costs off) select * from t where b like 'A%';\n<\/code><\/pre>\n
QUERY PLAN \n-----------------------------\n Seq Scan on t\n Filter: (b ~~ 'A%'::text)\n(2 rows)\n<\/code><\/pre>\n
create index on t(b text_pattern_ops);\nexplain (costs off) select * from t where b like 'A%';\n<\/code><\/pre>\n
QUERY PLAN \n----------------------------------------------------------------\n Bitmap Heap Scan on t\n Filter: (b ~~ 'A%'::text)\n -> Bitmap Index Scan on t_b_idx1\n Index Cond: ((b ~>=~ 'A'::text) AND (b ~<~ 'B'::text))\n(4 rows)\n<\/code><\/pre>\n
\u7cfb\u7edf\u8868<\/h1>\n