PostgreSQL 如何确定某个opclass支持哪些操作符(支持索引),JOIN方法,排序

简介:

标签

PostgreSQL , 索引接口 , 操作符 , am , family , opclass , operator , function , order by


背景

PostgreSQL有很多的索引接口,同时索引接口还支持用户扩展,当扩展索引时,需要提供opclass。

那么每一个扩展的opclass,支持什么操作符,支持什么JOIN方法,支持排序吗,是默认的OPCLASS吗?

以btree_gin扩展包为例,它扩展了标准类型的GIN索引接口。那么扩展后支持哪些呢?

create extension btree_gin;  

如何查询某个扩展的opclass支持哪些索引方法

比如int4_ops是扩展的opclass。

postgres=# select * from pg_opclass where opcname='int4_ops';  
 opcmethod | opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+----------+--------------+----------+-----------+-----------+------------+------------  
       403 | int4_ops |           11 |       10 |      1976 |        23 | t          |          0  
       405 | int4_ops |           11 |       10 |      1977 |        23 | t          |          0  
      2742 | int4_ops |         2200 |       10 |     45744 |        23 | t          |          0  
(3 rows)  
  
关联pg_opclass.opcmethod, pg_am.oid  
(opckeytype表示索引里面存的KEY是什么类型,0表示与opcintype一致)  
  
postgres=# select oid,* from pg_am;  
 oid  | amname |  amhandler  | amtype   
------+--------+-------------+--------  
  403 | btree  | bthandler   | i  
  405 | hash   | hashhandler | i  
  783 | gist   | gisthandler | i  
 2742 | gin    | ginhandler  | i  
 4000 | spgist | spghandler  | i  
 3580 | brin   | brinhandler | i  
(6 rows)  

int4_ops分别支持btree, hash, gin索引方法。

如何查询某个扩展的opclass支持哪些类型

postgres=# select * from pg_opclass where opcname='int4_ops';  
 opcmethod | opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+----------+--------------+----------+-----------+-----------+------------+------------  
       403 | int4_ops |           11 |       10 |      1976 |        23 | t          |          0  
       405 | int4_ops |           11 |       10 |      1977 |        23 | t          |          0  
      2742 | int4_ops |         2200 |       10 |     45744 |        23 | t          |          0  
(3 rows)  
  
关联pg_opclass.opcintype, pg_type.oid  
  
postgres=# select oid,typname from pg_type where oid in (23);  
 oid | typname   
-----+---------  
  23 | int4  
(1 row)  

如何查询某个扩展的opclass支持哪些操作符

postgres=# select * from pg_opclass where opcname='int4_ops';  
 opcmethod | opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+----------+--------------+----------+-----------+-----------+------------+------------  
       403 | int4_ops |           11 |       10 |      1976 |        23 | t          |          0  
       405 | int4_ops |           11 |       10 |      1977 |        23 | t          |          0  
      2742 | int4_ops |         2200 |       10 |     45744 |        23 | t          |          0  
(3 rows)  
  
关联pg_opclass.opcfamily, pg_amop.amopfamily  
  
postgres=# select * from pg_amop where amopfamily=45744;  
 amopfamily | amoplefttype | amoprighttype | amopstrategy | amoppurpose | amopopr | amopmethod | amopsortfamily   
------------+--------------+---------------+--------------+-------------+---------+------------+----------------  
      45744 |           23 |            23 |            1 | s           |      97 |       2742 |              0  
      45744 |           23 |            23 |            2 | s           |     523 |       2742 |              0  
      45744 |           23 |            23 |            3 | s           |      96 |       2742 |              0  
      45744 |           23 |            23 |            4 | s           |     525 |       2742 |              0  
      45744 |           23 |            23 |            5 | s           |     521 |       2742 |              0  
(5 rows)  
  
关联pg_operator.oid, pg_amop.amopopr  
  
postgres=# select oprname from pg_operator where oid in (select amopopr from pg_amop where amopfamily=45744);  
 oprname   
---------  
 <=  
 >  
 =  
 <  
 >=  
(5 rows)  

如何查询某个扩展的opclass是否为默认OPCLASS

postgres=# select * from pg_opclass where opcname='int4_ops';  
 opcmethod | opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+----------+--------------+----------+-----------+-----------+------------+------------  
       403 | int4_ops |           11 |       10 |      1976 |        23 | t          |          0  
       405 | int4_ops |           11 |       10 |      1977 |        23 | t          |          0  
      2742 | int4_ops |         2200 |       10 |     45744 |        23 | t          |          0  
(3 rows)  

opcdefault=t表示这个opcname是opcintype这个类型在opcmethod这个索引接口中的默认opclass.

如何查询某个扩展的opclass支持哪些JOIN方法

实际上JOIN方法与操作符有关,而操作符是否支持索引与索引接口实现有关。

所以这个问题可以定义为一个索引接口支持的操作符,支持哪些JOIN方法。

postgres=# select * from pg_opclass where opcname='int4_ops';  
 opcmethod | opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+----------+--------------+----------+-----------+-----------+------------+------------  
       403 | int4_ops |           11 |       10 |      1976 |        23 | t          |          0  
       405 | int4_ops |           11 |       10 |      1977 |        23 | t          |          0  
      2742 | int4_ops |         2200 |       10 |     45744 |        23 | t          |          0  
(3 rows)  
  
关联pg_opclass.opcfamily, pg_amop.amopfamily  
  
postgres=# select * from pg_amop where amopfamily=45744;  
 amopfamily | amoplefttype | amoprighttype | amopstrategy | amoppurpose | amopopr | amopmethod | amopsortfamily   
------------+--------------+---------------+--------------+-------------+---------+------------+----------------  
      45744 |           23 |            23 |            1 | s           |      97 |       2742 |              0  
      45744 |           23 |            23 |            2 | s           |     523 |       2742 |              0  
      45744 |           23 |            23 |            3 | s           |      96 |       2742 |              0  
      45744 |           23 |            23 |            4 | s           |     525 |       2742 |              0  
      45744 |           23 |            23 |            5 | s           |     521 |       2742 |              0  
(5 rows)  
  
关联pg_operator.oid, pg_amop.amopopr  
  
postgres=# select * from pg_operator where oid in (select amopopr from pg_amop where amopfamily=45744);  
 oprname | oprnamespace | oprowner | oprkind | oprcanmerge | oprcanhash | oprleft | oprright | oprresult | oprcom | oprnegate | oprcode |   oprrest   |     oprjoin       
---------+--------------+----------+---------+-------------+------------+---------+----------+-----------+--------+-----------+---------+-------------+-----------------  
 <=      |           11 |       10 | b       | f           | f          |      23 |       23 |        16 |    525 |       521 | int4le  | scalarltsel | scalarltjoinsel  
 >       |           11 |       10 | b       | f           | f          |      23 |       23 |        16 |     97 |       523 | int4gt  | scalargtsel | scalargtjoinsel  
 =       |           11 |       10 | b       | t           | t          |      23 |       23 |        16 |     96 |       518 | int4eq  | eqsel       | eqjoinsel  
 <       |           11 |       10 | b       | f           | f          |      23 |       23 |        16 |    521 |       525 | int4lt  | scalarltsel | scalarltjoinsel  
 >=      |           11 |       10 | b       | f           | f          |      23 |       23 |        16 |    523 |        97 | int4ge  | scalargtsel | scalargtjoinsel  
(5 rows)  

oprcanmerge是否支持MERGE JOIN。

oprcanhash是否支持HASH JOIN。

如何查询某个扩展的opclass是否支持排序

postgres=# select * from pg_opclass where opcname='int4_ops';  
 opcmethod | opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+----------+--------------+----------+-----------+-----------+------------+------------  
       403 | int4_ops |           11 |       10 |      1976 |        23 | t          |          0  
       405 | int4_ops |           11 |       10 |      1977 |        23 | t          |          0  
      2742 | int4_ops |         2200 |       10 |     45744 |        23 | t          |          0  
(3 rows)  
  
关联pg_opclass.opcfamily, pg_amop.amopfamily  
  
postgres=# select * from pg_amop where amopfamily=45744;  
 amopfamily | amoplefttype | amoprighttype | amopstrategy | amoppurpose | amopopr | amopmethod | amopsortfamily   
------------+--------------+---------------+--------------+-------------+---------+------------+----------------  
      45744 |           23 |            23 |            1 | s           |      97 |       2742 |              0  
      45744 |           23 |            23 |            2 | s           |     523 |       2742 |              0  
      45744 |           23 |            23 |            3 | s           |      96 |       2742 |              0  
      45744 |           23 |            23 |            4 | s           |     525 |       2742 |              0  
      45744 |           23 |            23 |            5 | s           |     521 |       2742 |              0  
(5 rows)  
  
  
amopsortfamily  
The B-tree operator family this entry sorts according to, if an ordering operator; zero if a search operator.  
  
0 表示这是个搜索的操作符  
  
其他表示这个是排序操作符  

例如这个是knn排序的操作符

postgres=# select * from pg_amop where amopsortfamily<>0;  
 amopfamily | amoplefttype | amoprighttype | amopstrategy | amoppurpose | amopopr | amopmethod | amopsortfamily   
------------+--------------+---------------+--------------+-------------+---------+------------+----------------  
       1029 |          600 |           600 |           15 | o           |     517 |        783 |           1970  
       2594 |          604 |           600 |           15 | o           |    3289 |        783 |           1970  
       2595 |          718 |           600 |           15 | o           |    3291 |        783 |           1970  
(3 rows)  
  
postgres=# select * from pg_opclass where opcfamily=1029;  
 opcmethod |  opcname  | opcnamespace | opcowner | opcfamily | opcintype | opcdefault | opckeytype   
-----------+-----------+--------------+----------+-----------+-----------+------------+------------  
       783 | point_ops |           11 |       10 |      1029 |       600 | t          |        603  
(1 row)  
  
postgres=# select * from pg_operator where oid=517;  
 oprname | oprnamespace | oprowner | oprkind | oprcanmerge | oprcanhash | oprleft | oprright | oprresult | oprcom | oprnegate |    oprcode     | oprrest | oprjoin   
---------+--------------+----------+---------+-------------+------------+---------+----------+-----------+--------+-----------+----------------+---------+---------  
 <->     |           11 |       10 | b       | f           | f          |     600 |      600 |       701 |    517 |         0 | point_distance | -       | -  
(1 row)  
  
postgres=# select * from pg_operator where oid=3289;  
 oprname | oprnamespace | oprowner | oprkind | oprcanmerge | oprcanhash | oprleft | oprright | oprresult | oprcom | oprnegate |  oprcode   | oprrest | oprjoin   
---------+--------------+----------+---------+-------------+------------+---------+----------+-----------+--------+-----------+------------+---------+---------  
 <->     |           11 |       10 | b       | f           | f          |     604 |      600 |       701 |   3276 |         0 | dist_polyp | -       | -  
(1 row)  
  
postgres=# select * from pg_operator where oid=3291;  
 oprname | oprnamespace | oprowner | oprkind | oprcanmerge | oprcanhash | oprleft | oprright | oprresult | oprcom | oprnegate |   oprcode   | oprrest | oprjoin   
---------+--------------+----------+---------+-------------+------------+---------+----------+-----------+--------+-----------+-------------+---------+---------  
 <->     |           11 |       10 | b       | f           | f          |     718 |      600 |       701 |   1522 |         0 | dist_cpoint | -       | -  
(1 row)  

如果创建了postgis插件,则可以看到有更多的支持距离排序的操作符,还有btree_gist,rum,pg_trgm等插件都支持距离排序。

postgres=# create extension postgis;
CREATE EXTENSION
postgres=# create extension btree_gist;
CREATE EXTENSION
postgres=# create extension rum;
CREATE EXTENSION
postgres=# create extension pg_trgm;
CREATE EXTENSION

postgres=# select oprleft::regtype,oprright::regtype,oprresult::regtype,oprname,oprkind,oprcode from pg_operator where oid in (select amopopr  from pg_amop where amopsortfamily<>0);  
           oprleft           |          oprright           |    oprresult     | oprname | oprkind |              oprcode               
-----------------------------+-----------------------------+------------------+---------+---------+------------------------------------
 point                       | point                       | double precision | <->     | b       | point_distance
 circle                      | point                       | double precision | <->     | b       | dist_cpoint
 polygon                     | point                       | double precision | <->     | b       | dist_polyp
 geometry                    | geometry                    | double precision | <->     | b       | geometry_distance_centroid
 geometry                    | geometry                    | double precision | <#>     | b       | geometry_distance_box
 geometry                    | geometry                    | double precision | <<->>   | b       | geometry_distance_centroid_nd
 geometry                    | geometry                    | double precision | |=|     | b       | geometry_distance_cpa
 geography                   | geography                   | double precision | <->     | b       | geography_distance_knn
 interval                    | interval                    | interval         | <->     | b       | interval_dist
 oid                         | oid                         | oid              | <->     | b       | oid_dist
 time without time zone      | time without time zone      | interval         | <->     | b       | time_dist
 timestamp without time zone | timestamp without time zone | interval         | <->     | b       | ts_dist
 money                       | money                       | money            | <->     | b       | cash_dist
 date                        | date                        | integer          | <->     | b       | date_dist
 real                        | real                        | real             | <->     | b       | float4_dist
 double precision            | double precision            | double precision | <->     | b       | float8_dist
 smallint                    | smallint                    | smallint         | <->     | b       | int2_dist
 integer                     | integer                     | integer          | <->     | b       | int4_dist
 bigint                      | bigint                      | bigint           | <->     | b       | int8_dist
 timestamp with time zone    | timestamp with time zone    | interval         | <->     | b       | tstz_dist
 tsvector                    | tsquery                     | real             | <=>     | b       | public.rum_ts_distance
 timestamp without time zone | timestamp without time zone | double precision | <=>     | b       | rum_timestamp_distance
 timestamp without time zone | timestamp without time zone | double precision | <=|     | b       | rum_timestamp_left_distance
 timestamp without time zone | timestamp without time zone | double precision | |=>     | b       | rum_timestamp_right_distance
 timestamp with time zone    | timestamp with time zone    | double precision | <=>     | b       | rum_timestamptz_distance
 timestamp with time zone    | timestamp with time zone    | double precision | <=|     | b       | rum_timestamptz_left_distance
 timestamp with time zone    | timestamp with time zone    | double precision | |=>     | b       | rum_timestamptz_right_distance
 smallint                    | smallint                    | double precision | <=>     | b       | rum_int2_distance
 smallint                    | smallint                    | double precision | <=|     | b       | rum_int2_left_distance
 smallint                    | smallint                    | double precision | |=>     | b       | rum_int2_right_distance
 integer                     | integer                     | double precision | <=>     | b       | rum_int4_distance
 integer                     | integer                     | double precision | <=|     | b       | rum_int4_left_distance
 integer                     | integer                     | double precision | |=>     | b       | rum_int4_right_distance
 bigint                      | bigint                      | double precision | <=>     | b       | rum_int8_distance
 bigint                      | bigint                      | double precision | <=|     | b       | rum_int8_left_distance
 bigint                      | bigint                      | double precision | |=>     | b       | rum_int8_right_distance
 real                        | real                        | double precision | <=>     | b       | rum_float4_distance
 real                        | real                        | double precision | <=|     | b       | rum_float4_left_distance
 real                        | real                        | double precision | |=>     | b       | rum_float4_right_distance
 double precision            | double precision            | double precision | <=>     | b       | rum_float8_distance
 double precision            | double precision            | double precision | <=|     | b       | rum_float8_left_distance
 double precision            | double precision            | double precision | |=>     | b       | rum_float8_right_distance
 money                       | money                       | double precision | <=>     | b       | rum_money_distance
 money                       | money                       | double precision | <=|     | b       | rum_money_left_distance
 money                       | money                       | double precision | |=>     | b       | rum_money_right_distance
 oid                         | oid                         | double precision | <=>     | b       | rum_oid_distance
 oid                         | oid                         | double precision | <=|     | b       | rum_oid_left_distance
 oid                         | oid                         | double precision | |=>     | b       | rum_oid_right_distance
 anyarray                    | anyarray                    | double precision | <=>     | b       | rum_anyarray_distance
 text                        | text                        | real             | <->     | b       | similarity_dist
 text                        | text                        | real             | <->>    | b       | word_similarity_dist_commutator_op
(51 rows)

代码层面理解

https://www.postgresql.org/docs/devel/static/xindex.html

pic

例子

CREATE OPERATOR FAMILY integer_ops USING btree;

CREATE OPERATOR CLASS int8_ops
DEFAULT FOR TYPE int8 USING btree FAMILY integer_ops AS
  -- standard int8 comparisons
  OPERATOR 1 < ,
  OPERATOR 2 <= ,
  OPERATOR 3 = ,
  OPERATOR 4 >= ,
  OPERATOR 5 > ,
  FUNCTION 1 btint8cmp(int8, int8) ,
  FUNCTION 2 btint8sortsupport(internal) ,
  FUNCTION 3 in_range(int8, int8, int8, boolean, boolean) ;

CREATE OPERATOR CLASS int4_ops
DEFAULT FOR TYPE int4 USING btree FAMILY integer_ops AS
  -- standard int4 comparisons
  OPERATOR 1 < ,
  OPERATOR 2 <= ,
  OPERATOR 3 = ,
  OPERATOR 4 >= ,
  OPERATOR 5 > ,
  FUNCTION 1 btint4cmp(int4, int4) ,
  FUNCTION 2 btint4sortsupport(internal) ,
  FUNCTION 3 in_range(int4, int4, int4, boolean, boolean) ;

CREATE OPERATOR CLASS int2_ops
DEFAULT FOR TYPE int2 USING btree FAMILY integer_ops AS
  -- standard int2 comparisons
  OPERATOR 1 < ,
  OPERATOR 2 <= ,
  OPERATOR 3 = ,
  OPERATOR 4 >= ,
  OPERATOR 5 > ,
  FUNCTION 1 btint2cmp(int2, int2) ,
  FUNCTION 2 btint2sortsupport(internal) ,
  FUNCTION 3 in_range(int2, int2, int2, boolean, boolean) ;

ALTER OPERATOR FAMILY integer_ops USING btree ADD
  -- cross-type comparisons int8 vs int2
  OPERATOR 1 < (int8, int2) ,
  OPERATOR 2 <= (int8, int2) ,
  OPERATOR 3 = (int8, int2) ,
  OPERATOR 4 >= (int8, int2) ,
  OPERATOR 5 > (int8, int2) ,
  FUNCTION 1 btint82cmp(int8, int2) ,

  -- cross-type comparisons int8 vs int4
  OPERATOR 1 < (int8, int4) ,
  OPERATOR 2 <= (int8, int4) ,
  OPERATOR 3 = (int8, int4) ,
  OPERATOR 4 >= (int8, int4) ,
  OPERATOR 5 > (int8, int4) ,
  FUNCTION 1 btint84cmp(int8, int4) ,

  -- cross-type comparisons int4 vs int2
  OPERATOR 1 < (int4, int2) ,
  OPERATOR 2 <= (int4, int2) ,
  OPERATOR 3 = (int4, int2) ,
  OPERATOR 4 >= (int4, int2) ,
  OPERATOR 5 > (int4, int2) ,
  FUNCTION 1 btint42cmp(int4, int2) ,

  -- cross-type comparisons int4 vs int8
  OPERATOR 1 < (int4, int8) ,
  OPERATOR 2 <= (int4, int8) ,
  OPERATOR 3 = (int4, int8) ,
  OPERATOR 4 >= (int4, int8) ,
  OPERATOR 5 > (int4, int8) ,
  FUNCTION 1 btint48cmp(int4, int8) ,

  -- cross-type comparisons int2 vs int8
  OPERATOR 1 < (int2, int8) ,
  OPERATOR 2 <= (int2, int8) ,
  OPERATOR 3 = (int2, int8) ,
  OPERATOR 4 >= (int2, int8) ,
  OPERATOR 5 > (int2, int8) ,
  FUNCTION 1 btint28cmp(int2, int8) ,

  -- cross-type comparisons int2 vs int4
  OPERATOR 1 < (int2, int4) ,
  OPERATOR 2 <= (int2, int4) ,
  OPERATOR 3 = (int2, int4) ,
  OPERATOR 4 >= (int2, int4) ,
  OPERATOR 5 > (int2, int4) ,
  FUNCTION 1 btint24cmp(int2, int4) ,

  -- cross-type in_range functions
  FUNCTION 3 in_range(int4, int4, int8, boolean, boolean) ,
  FUNCTION 3 in_range(int4, int4, int2, boolean, boolean) ,
  FUNCTION 3 in_range(int2, int2, int8, boolean, boolean) ,
  FUNCTION 3 in_range(int2, int2, int4, boolean, boolean) ;

小结

从本例来看,使用btree_gin接口,可以实现标准类型在GIN索引中的范围扫描。

参考

https://www.postgresql.org/docs/10/static/catalogs.html

51.3. pg_am  
51.4. pg_amop  
51.5. pg_amproc  
  
51.33. pg_opclass  
51.34. pg_operator  
51.35. pg_opfamily  
相关实践学习
使用PolarDB和ECS搭建门户网站
本场景主要介绍如何基于PolarDB和ECS实现搭建门户网站。
阿里云数据库产品家族及特性
阿里云智能数据库产品团队一直致力于不断健全产品体系,提升产品性能,打磨产品功能,从而帮助客户实现更加极致的弹性能力、具备更强的扩展能力、并利用云设施进一步降低企业成本。以云原生+分布式为核心技术抓手,打造以自研的在线事务型(OLTP)数据库Polar DB和在线分析型(OLAP)数据库Analytic DB为代表的新一代企业级云原生数据库产品体系, 结合NoSQL数据库、数据库生态工具、云原生智能化数据库管控平台,为阿里巴巴经济体以及各个行业的企业客户和开发者提供从公共云到混合云再到私有云的完整解决方案,提供基于云基础设施进行数据从处理、到存储、再到计算与分析的一体化解决方案。本节课带你了解阿里云数据库产品家族及特性。
目录
相关文章
|
5月前
|
存储 SQL 关系型数据库
mysql底层原理:索引、慢查询、 sql优化、事务、隔离级别、MVCC、redolog、undolog(图解+秒懂+史上最全)
mysql底层原理:索引、慢查询、 sql优化、事务、隔离级别、MVCC、redolog、undolog(图解+秒懂+史上最全)
mysql底层原理:索引、慢查询、 sql优化、事务、隔离级别、MVCC、redolog、undolog(图解+秒懂+史上最全)
|
5月前
|
存储 关系型数据库 MySQL
MySQL数据库索引的数据结构?
MySQL中默认使用B+tree索引,它是一种多路平衡搜索树,具有树高较低、检索速度快的特点。所有数据存储在叶子节点,非叶子节点仅作索引,且叶子节点形成双向链表,便于区间查询。
202 4
|
7月前
|
存储 关系型数据库 MySQL
阿里面试:MySQL 一个表最多 加几个索引? 6个?64个?还是多少?
阿里面试:MySQL 一个表最多 加几个索引? 6个?64个?还是多少?
阿里面试:MySQL 一个表最多 加几个索引? 6个?64个?还是多少?
|
6月前
|
存储 监控 关系型数据库
B-tree不是万能药:PostgreSQL索引失效的7种高频场景与破解方案
在PostgreSQL优化实践中,B-tree索引虽承担了80%以上的查询加速任务,但因多种原因可能导致索引失效,引发性能骤降。本文深入剖析7种高频失效场景,包括隐式类型转换、函数包裹列、前导通配符等,并通过实战案例揭示问题本质,提供生产验证的解决方案。同时,总结索引使用决策矩阵与关键原则,助你让索引真正发挥作用。
432 0
|
9月前
|
关系型数据库 MySQL 数据库
Mysql的索引
MYSQL索引主要有 : 单列索引 , 组合索引和空间索引 , 用的比较多的就是单列索引和组合索引 , 空间索引我这边没有用到过 单列索引 : 在MYSQL数据库表的某一列上面创建的索引叫单列索引 , 单列索引又分为 ● 普通索引:MySQL中基本索引类型,没有什么限制,允许在定义索引的列中插入重复值和空值,纯粹为了查询数据更快一点。 ● 唯一索引:索引列中的值必须是唯一的,但是允许为空值 ● 主键索引:是一种特殊的唯一索引,不允许有空值 ● 全文索引: 只有在MyISAM引擎、InnoDB(5.6以后)上才能使⽤用,而且只能在CHAR,VARCHAR,TEXT类型字段上使⽤用全⽂文索引。
|
5月前
|
存储 SQL 关系型数据库
MySQL 核心知识与索引优化全解析
本文系统梳理了 MySQL 的核心知识与索引优化策略。在基础概念部分,阐述了 char 与 varchar 在存储方式和性能上的差异,以及事务的 ACID 特性、并发事务问题及对应的隔离级别(MySQL 默认 REPEATABLE READ)。 索引基础部分,详解了 InnoDB 默认的 B+tree 索引结构(多路平衡树、叶子节点存数据、双向链表支持区间查询),区分了聚簇索引(数据与索引共存,唯一)和二级索引(数据与索引分离,多个),解释了回表查询的概念及优化方法,并分析了 B+tree 作为索引结构的优势(树高低、效率稳、支持区间查询)。 索引优化部分,列出了索引创建的六大原则
148 2
|
6月前
|
存储 关系型数据库 MySQL
MySQL覆盖索引解释
总之,覆盖索引就像是图书馆中那些使得搜索变得极为迅速和简单的工具,一旦正确使用,就会让你的数据库查询飞快而轻便。让数据检索就像是读者在图书目录中以最快速度找到所需信息一样简便。这样的效率和速度,让覆盖索引成为数据库优化师傅们手中的尚方宝剑,既能够提升性能,又能够保持系统的整洁高效。
176 9
|
9月前
|
关系型数据库 测试技术 Linux
PostgreSQL配置文件修改及启用方法
总的来说,修改和启用PostgreSQL的配置文件是一个直接而简单的过程。只需要找到配置文件,修改你想要改变的选项,然后重启服务器即可。但是,你需要注意的是,不正确的配置可能会导致服务器性能下降,甚至导致服务器无法启动。因此,在修改配置文件之前,你应该充分理解每个选项的含义和影响,如果可能的话,你应该在测试环境中先进行试验。
727 72
|
7月前
|
机器学习/深度学习 关系型数据库 MySQL
对比MySQL全文索引与常规索引的互异性
现在,你或许明白了这两种索引的差异,但任何技术决策都不应仅仅基于理论之上。你可以创建你的数据库实验环境,尝试不同类型的索引,看看它们如何影响性能,感受它们真实的力量。只有这样,你才能熟悉它们,掌握什么时候使用全文索引,什么时候使用常规索引,以适应复杂多变的业务需求。
205 12
|
11月前
|
存储 关系型数据库 MySQL
MySQL索引学习笔记
本文深入探讨了MySQL数据库中慢查询分析的关键概念和技术手段。
735 81

相关产品

  • 云原生数据库 PolarDB
  • 云数据库 RDS PostgreSQL 版
  • 推荐镜像

    更多