今天让我们一起跟着韩锋老师的步伐,一起来看看国产集中式数据库 SQL 访问路径究竟是什么样的,和业界老大 Oracle 有啥不一样,通过本文你都可以一目了然。
1).评测对象架构:集中式
2).评测功能标准:Oracle
3).评测产品范围:主流+代表性
4).评测环境&版本
测试环境:采用Docker镜像方式 测试版本:采用官方镜像(可能非最新)见下文 测试数据:自行构造 测试配置:数据库默认配置,未优化
这里主要谈 Oracle 数据的表及索引的访问路径问题。
1).表访问路径
2).索引访问路径
3).Oracle 测试示例
-- 表扫描:全表扫描
SQL> explain plan for select * from emp;
SQL> select * from table(dbms_xplan.display);
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10000 | 273K| 15 (0)| 00:00:01 |
| 1 | TABLE ACCESS FULL| EMP | 10000 | 273K| 15 (0)| 00:00:01 |
--------------------------------------------------------------------------
-- 索引扫描:索引唯一扫描(index unique scan)
SQL> explain plan for select * from emp where emp_id=111;
SQL> select * from table(dbms_xplan.display);
--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 28 | 2 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 28 | 2 (0)| 00:00:01 |
|* 2 | INDEX UNIQUE SCAN | EMP_PK | 1 | | 1 (0)| 00:00:01 |
--------------------------------------------------------------------------------------
-- 索引扫描:索引范围扫描(index range scan)
SQL> explain plan for select * from emp where emp_id<100;
SQL> select * from table(dbms_xplan.display);
--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 99 | 2772 | 3 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| EMP | 99 | 2772 | 3 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | EMP_PK | 99 | | 2 (0)| 00:00:01 |
--------------------------------------------------------------------------------------
-- 索引扫描:索引快速全扫描(index fast full scan)
SQL> explain plan for select emp_name from emp;
SQL> select * from table(dbms_xplan.display);
-------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10000 | 80000 | 14 (0)| 00:00:01 |
| 1 | INDEX FAST FULL SCAN| IDX_EMP_NAME | 10000 | 80000 | 14 (0)| 00:00:01 |
-------------------------------------------------------------------------------------
-- 索引扫描:索引全扫描(index full scan)
SQL> exec dbms_stats.set_table_stats(ownname=>'TESTUSER',tabname=>'EMP',numrows=>1000000,numblks=>5000);
SQL> select num_rows,blocks from user_tables where table_name='EMP';
NUM_ROWS BLOCKS
---------- ----------
1000000 5000
//通过伪造统计信息,放大表扫描的成本,让优化器选择使用索引全扫描
SQL> explain plan for select emp_name from emp order by 1;
SQL> select * from table(dbms_xplan.display);
---------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1000K| 7812K| 46 (0)| 00:00:01 |
| 1 | INDEX FULL SCAN | IDX_EMP_NAME | 1000K| 7812K| 46 (0)| 00:00:01 |
---------------------------------------------------------------------------------
-- 索引扫描:索引跳跃扫描(index skip scan)
SQL> create table t as select 1 id,object_name from dba_objects;
SQL> insert into t select 2 ,object_name from dba_objects;
SQL> insert into t select 3 ,object_name from dba_objects;
SQL> insert into t select 4 ,object_name from dba_objects;
SQL> create index idx_t on t(id,object_name);
SQL> exec dbms_stats.gather_table_stats(user,'t',cascade=>true);
SQL> explain plan for select * from t where object_name='TEST';
SQL> select * from table(dbms_xplan.display);
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 7 | 189 | 6 (0)| 00:00:01 |
|* 1 | INDEX SKIP SCAN | IDX_T | 7 | 189 | 6 (0)| 00:00:01 |
--------------------------------------------------------------------------
1).MySQL
-- 表扫描:全表扫描
mysql> explain select * from emp;
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
| 1 | SIMPLE | emp | NULL | ALL | NULL | NULL | NULL | NULL | 9796 | 100.00 | NULL |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------+
-- 索引扫描:索引单键扫描
mysql> explain select * from emp where emp_id=111;
+----+-------------+-------+------------+-------+---------------+---------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+-------+---------------+---------+---------+-------+------+----------+-------+
| 1 | SIMPLE | emp | NULL | const | PRIMARY | PRIMARY | 4 | const | 1 | 100.00 | NULL |
+----+-------------+-------+------------+-------+---------------+---------+---------+-------+------+----------+-------+
-- 索引扫描:索引范围扫描
mysql> explain select * from emp where emp_id<100;
+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
| 1 | SIMPLE | emp | NULL | range | PRIMARY | PRIMARY | 4 | NULL | 99 | 100.00 | Using where |
+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+
-- 索引扫描:索引扫描
mysql> explain select emp_name from emp;
+----+-------------+-------+------------+-------+---------------+--------------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+-------+---------------+--------------+---------+------+------+----------+-------------+
| 1 | SIMPLE | emp | NULL | index | NULL | idx_emp_name | 33 | NULL | 9796 | 100.00 | Using index |
+----+-------------+-------+------------+-------+---------------+--------------+---------+------+------+----------+-------------+
-- 索引扫描:索引跳跃扫描
mysql> create table t as select * from information_schema.tables;
mysql> insert into t select * from t;
...
mysql> insert into t select * from t;
mysql> alter table t add id int;
mysql> create index idx_tmp on t(table_type,table_name);
mysql> analyze table t;
mysql> explain select table_type,table_name from t where table_name='COLLATIONS';
+----+-------------+-------+------------+-------+---------------+---------+---------+------+-------+----------+----------------------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+-------+---------------+---------+---------+------+-------+----------+----------------------------------------+
| 1 | SIMPLE | t | NULL | range | idx_tmp | idx_tmp | 195 | NULL | 18045 | 100.00 | Using where; Using index for skip scan |
+----+-------------+-------+------------+-------+---------------+---------+---------+------+-------+----------+----------------------------------------+
2).DM
-- 表扫描:全表扫描
SQL> explain select * from emp;
1 #NSET2: [1, 10000, 163]
2 #PRJT2: [1, 10000, 163]; exp_num(6), is_atom(FALSE)
3 #CSCN2: [1, 10000, 163]; INDEX33555484(EMP); btr_scan(1)
-- 索引扫描:索引唯一扫描
SQL> explain select * from emp where emp_id=111;
1 #NSET2: [1, 1, 163]
2 #PRJT2: [1, 1, 163]; exp_num(6), is_atom(FALSE)
3 #BLKUP2: [1, 1, 163]; INDEX33555485(EMP)
4 #SSEK2: [1, 1, 163]; scan_type(ASC), INDEX33555485(EMP), scan_range[exp_cast(111),exp_cast(111)], is_global(0)
* 没有唯一扫描方式,DM都认为是范围扫描
-- 索引扫描:索引范围扫描
SQL> explain select * from emp where emp_id<100;
1 #NSET2: [1, 99, 163]
2 #PRJT2: [1, 99, 163]; exp_num(6), is_atom(FALSE)
3 #BLKUP2: [1, 99, 163]; INDEX33555485(EMP)
4 #SSEK2: [1, 99, 163]; scan_type(ASC), INDEX33555485(EMP), scan_range(null2,exp_cast(100)), is_global(0)
* 被认为是从NULL到指定数值的范围扫描
-- 索引扫描:索引全扫描
SQL> explain select emp_name from emp;
1 #NSET2: [1, 10000, 60]
2 #PRJT2: [1, 10000, 60]; exp_num(2), is_atom(FALSE)
3 #SSCN: [1, 10000, 60]; IDX_EMP_NAME(EMP); btr_scan(1); is_global(0)
* 直接使用索引扫描,不用再回表查
-- 索引扫描:索引跳跃扫描(index skip scan)
SQL> create table t as select 1 id,object_name from dba_objects;
SQL> insert into t select 2 ,object_name from dba_objects;
SQL> insert into t select 3 ,object_name from dba_objects;
SQL> insert into t select 4 ,object_name from dba_objects;
SQL> create index idx_t on t(id,object_name);
SQL> CALL SP_TAB_INDEX_STAT_INIT ('TESTUSER', 'T');
SQL> explain select * from t where object_name='TEST';
1 #NSET2: [1, 109, 64]
2 #PRJT2: [1, 109, 64]; exp_num(3), is_atom(FALSE)
3 #SLCT2: [1, 109, 64]; T.OBJECT_NAME = 'TEST'
4 #SSCN: [1, 109, 64]; IDX_T(T); btr_scan(1); is_global(0)
* 直接使用索引扫描,实现了跳跃扫描功能
3).KingBase
-- 表扫描:全表扫描
TEST=# explain select * from emp;
QUERY PLAN
----------------------------------------------------------
Seq Scan on emp (cost=0.00..192.00 rows=10000 width=39)
* 表的顺序扫描
-- 索引扫描:索引唯一扫描
TEST=# explain select * from emp where emp_id=111;
QUERY PLAN
-------------------------------------------------------------------
Index Scan using EMP_PK on emp (cost=0.29..8.30 rows=1 width=39)
Index Cond: (emp_id = '111'::numeric)
* 标准索引扫描
-- 索引扫描:索引范围扫描
TEST=# explain select * from emp where emp_id<100;
QUERY PLAN
---------------------------------------------------------------------
Index Scan using EMP_PK on emp (cost=0.29..93.77 rows=99 width=39)
Index Cond: (emp_id < '100'::numeric)
* 标准索引扫描
-- 索引扫描:索引全扫描
TEST=# explain select emp_name from emp;
QUERY PLAN
----------------------------------------------------------
Seq Scan on emp (cost=0.00..192.00 rows=10000 width=13)
* 默认走了全表扫描(即使增加到100万的记录也是如此)
TEST=# set enable_hint=on;
TEST=# explain analyze verbose select /*+IndexOnlyScan(emp idx_emp_name)*/ emp_name from emp;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
Index Only Scan using idx_emp_name on public.emp (cost=0.42..69579.87 rows=1000000 width=15) (actual time=0.209..151.571 rows=1000000 loops=1)
Output: emp_name
Heap Fetches: 1100000
Planning Time: 0.123 ms
Execution Time: 172.407 ms
* 尝试强制走索引扫描,成本更高。
-- 索引扫描:索引跳跃扫描(index skip scan)
TEST=# create table t as select 1 id,attname, atttypid, attstattarget, attlen, attnum, attndims, attcacheoff, atttypmod from pg_attribute;
TEST=# insert into t select 2 ,attname, atttypid, attstattarget, attlen, attnum, attndims, attcacheoff, atttypmod from pg_attribute;
...
TEST=# create index idx_t on t(id,attname );
TEST=# analyze verbose t;
TEST=# explain select * from t where attname ='TEST';
QUERY PLAN
-------------------------------------------------------------------
Index Scan using idx_t on t (cost=0.29..889.09 rows=11 width=92)
Index Cond: (attname = 'TEST'::name)
* 直接使用索引扫描,实现了跳跃扫描功能
4).YashanDB
-- 表扫描:全表扫描
SQL> explain plan for select * from emp;
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| 0 | SELECT STATEMENT | | | | | |
| 1 | TABLE ACCESS FULL | EMP | TESTUSER | 10000| 41( 0)| |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
-- 索引扫描:索引唯一扫描(index unique scan)
SQL> explain select * from emp where emp_id=111;
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| 0 | SELECT STATEMENT | | | | | |
| 1 | TABLE ACCESS BY INDEX ROWID | EMP | TESTUSER | 1| 1( 0)| |
|* 2 | INDEX UNIQUE SCAN | EMP_PK | TESTUSER | 1| 1( 0)| |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
-- 索引扫描:索引范围扫描(index range scan)
SQL> explain select * from emp where emp_id<100;
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| 0 | SELECT STATEMENT | | | | | |
| 1 | TABLE ACCESS BY INDEX ROWID | EMP | TESTUSER | 100| 1( 0)| |
|* 2 | INDEX RANGE SCAN | EMP_PK | TESTUSER | 100| 1( 0)| |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
-- 索引扫描:索引快速全扫描(index fast full scan)
SQL> explain select emp_name from emp;
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| 0 | SELECT STATEMENT | | | | | |
| 1 | INDEX FAST FULL SCAN | IDX_EMP_NAME | TESTUSER | 10000| 29( 0)| |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
-- 索引扫描:索引全扫描(index full scan)
exec dbms_stats.set_table_stats('TESTUSER','EMP',null,1000000,5000,34);
//通过伪造统计信息,放大表扫描的成本,让优化器选择使用索引全扫描
SQL> explain select emp_name from emp order by 1;
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| 0 | SELECT STATEMENT | | | | | |
| 1 | INDEX FULL SCAN | IDX_EMP_NAME | TESTUSER | 1000000| 29( 0)| |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
-- 索引扫描:索引跳跃扫描(index skip scan)
SQL> create table t as select 1 id,object_name from dba_objects;
SQL> insert into t select 2 ,object_name from dba_objects;
...
SQL> create index idx_t on t(id,object_name);
SQL> exec dbms_stats.gather_table_stats(user,'t',cascade=>true);
SQL> explain select * from t where object_name='TEST';
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| Id | Operation type | Name | Owner | Rows | Cost(%CPU) | Partition info |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
| 0 | SELECT STATEMENT | | | | | |
|* 1 | INDEX SKIP SCAN | IDX_T | TESTUSER | 1| 3( 0)| |
+----+--------------------------------+----------------------+------------+----------+-------------+--------------------------------+
5).Vastbase
-- 表扫描:全表扫描
vastbase=> explain select * from emp;
QUERY PLAN
----------------------------------------------------------
Seq Scan on emp (cost=0.00..218.00 rows=10000 width=44)
* 表的顺序扫描
-- 索引扫描:索引唯一扫描
vastbase=> explain select * from emp where emp_id=111;
QUERY PLAN
-------------------------------------------------------------------
Index Scan using emp_pk on emp (cost=0.00..8.27 rows=1 width=44)
Index Cond: (emp_id = 111::number)
* 标准索引扫描
-- 索引扫描:索引范围扫描
vastbase=> explain select * from emp where emp_id<100;
QUERY PLAN
--------------------------------------------------------------------
Index Scan using emp_pk on emp (cost=0.00..9.13 rows=50 width=44)
Index Cond: (emp_id < 100::number)
* 标准索引扫描
-- 索引扫描:索引全扫描
vastbase=> explain select emp_name from emp;
QUERY PLAN
----------------------------------------------------------
Seq Scan on emp (cost=0.00..218.00 rows=10000 width=12)
* 默认走了全表扫描(即使增加到100万的记录也是如此)
vastbase=> explain analyze verbose select /*+IndexOnlyScan(emp idx_emp_name)*/ emp_name from emp;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------
Index Only Scan using idx_emp_name on testuser.emp (cost=0.00..671.02 rows=10000 width=12) (actual time=0.610..5.090 rows=10000 loops=1)
Output: emp_name
Heap Fetches: 10000
Total runtime: 5.580 ms
* 尝试强制走索引扫描,成本更高。
-- 索引扫描:索引跳跃扫描(index skip scan)
vastbase=> create table t as select 1 id,attname, atttypid, attstattarget, attlen, attnum, attndims, attcacheoff, atttypmod from pg_attribute;
vastbase=> insert into t select 2 ,attname, atttypid, attstattarget, attlen, attnum, attndims, attcacheoff, atttypmod from pg_attribute;
...
vastbase=> create index idx_t on t(id,attname );
vastbase=> analyze verbose t;
vastbase=> explain select * from t where attname ='TEST';
QUERY PLAN
---------------------------------------------------------------------
Index Scan using idx_t on t (cost=0.00..1331.40 rows=13 width=156)
Index Cond: (attname = 'TEST'::name)
* 直接使用索引扫描,实现了跳跃扫描功能
分享几个数据库备份脚本
一文搞懂 Oracle 统计信息
我的 Oracle ACE 心路历程
MOP 系列|MOP 三种主流数据库索引简介
Oracle 主流版本不同架构下的静默安装指南
关机重启导致 ASM 磁盘丢失数据库无法启动
Oracle SQL 性能分析(SPA)原理与实战演练
Oracle 11g 升级到 19c 需要关注的几个问题
Windows 10 环境下 MySQL 8.0.33 安装指南
SQL 大全(四)|数据库迁移升级时常用 SQL 语句
OGG|使用 OGG19c 迁移 Oracle11g 到 19C(第二版)
Oracle 大数据量导出工具——sqluldr2 的安装与使用
Oracle ACE 视角下的国产数据库现状与选型及应对策略
从国产数据库调研报告中你都能了解哪些信息及我的总结建议
使用数据泵利用 rowid 分片导出导入 lob 大表及最佳实践
在归档模式下直接 rm dbf 数据文件并重启数据库还有救吗?
——————————————————————————
公众号:JiekeXu DBA之路
墨天轮:https://www.modb.pro/u/4347
CSDN :https://blog.csdn.net/JiekeXu
ITPUB:https://blog.itpub.net/69968215
腾讯云:https://cloud.tencent.com/developer/user/5645107——————————————————————————