Chinaunix首页 | 论坛 | 博客
  • 博客访问: 4156919
  • 博文数量: 240
  • 博客积分: 11504
  • 博客等级: 上将
  • 技术积分: 4277
  • 用 户 组: 普通用户
  • 注册时间: 2006-12-28 14:24
文章分类

全部博文(240)

分类: Mysql/postgreSQL

2014-04-02 19:25:56

我们知道,MySQL 不支持条件索引。 什么是条件索引呢? 条件索引就是在索引列上根据WHERE条件进行一定的过滤后产生的索引。 这样的索引有以下优势:
第一点, 比基于这个列的全部索引占用空间来的小。
第二点, 特别是基于FULL INDEX SCAN 的时候,占用空间小的索引对内存占用也小很多。


PostgreSQL,SqlServer等都支持条件索引,所以我们先来看下条件索引的实际情况。
表结构如下,记录大概有10W行:
  

点击(此处)折叠或打开

  1. Table "ytt.girl1"
  2.  Column | Type | Modifiers
  3. --------+---------+--------------------
  4.  id | integer | not null
  5.  rank | integer | not null default 0
  6. Indexes:
  7.     "girl1_pkey" PRIMARY KEY, btree (id)
  8.     "idx_girl1_rank" btree (rank) WHERE rank >= 10 AND rank <= 100


  9. 执行的查询语句为:
  10. select * from girl1 where rank between 20 and 60 limit 20;


  11. 用了全部索引的查询计划:
  12.                                                            QUERY PLAN
  13. ---------------------------------------------------------------------------------------------------------------------------------
  14.  Limit (cost=0.29..36.58 rows=20 width=8) (actual time=0.024..0.054 rows=20 loops=1)
  15.    -> Index Scan using idx_girl1_rank on girl1 (cost=0.29..421.26 rows=232 width=8) (actual time=0.023..0.044 rows=20 loops=1)
  16.          Index Cond: ((rank >= 20) AND (rank <= 60))
  17.  Total runtime: 0.087 ms
  18. (4 rows)


  19. Time: 1.881 ms
  20. 用了条件索引的查询计划:


  21.                                                            QUERY PLAN
  22. ---------------------------------------------------------------------------------------------------------------------------------
  23.  Limit (cost=0.28..35.54 rows=20 width=8) (actual time=0.036..0.068 rows=20 loops=1)
  24.    -> Index Scan using idx_girl1_rank on girl1 (cost=0.28..513.44 rows=291 width=8) (actual time=0.033..0.061 rows=20 loops=1)
  25.          Index Cond: ((rank >= 20) AND (rank <= 60))
  26.  Total runtime: 0.106 ms
  27. (4 rows)


  28. Time: 0.846 ms



可以看出,在扫描的记录数以及时间上,条件索引的优势都很明显。


接下来,我们在MySQL 模拟下这样的过程。
由于MySQL 不支持这样的索引, 在SQL层面上,只能创建一个索引表来保存对应条件的主键以及索引键。



点击(此处)折叠或打开

  1. ytt>show create table girl1_filtered_index;
  2. +----------------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  3. | Table | Create Table |
  4. +----------------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  5. | girl1_filtered_index | CREATE TABLE `girl1_filtered_index` (
  6.   `id` int(11) NOT NULL,
  7.   `rank` int(11) NOT NULL DEFAULT '0',
  8.   PRIMARY KEY (`id`),
  9.   KEY `idx_rank` (`rank`)
  10. ) ENGINE=InnoDB DEFAULT CHARSET=latin1 |
  11. +----------------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  12. 1 row in set (0.00 sec)






  13. 接下来,对基础表的更新操作做下修改,创建了三个触发器。
  14. DELIMITER $$


  15. USE `t_girl`$$


  16. DROP TRIGGER /*!50032 IF EXISTS */ `filtered_insert`$$


  17. CREATE
  18.     /*!50017 DEFINER = 'root'@'localhost' */
  19.     TRIGGER `filtered_insert` AFTER INSERT ON `girl1`
  20.     FOR EACH ROW BEGIN
  21. IF new.rank BETWEEN 10 AND 100 THEN
  22. INSERT INTO girl1_filtered_index VALUES (new.id,new.rank);
  23. END IF;

  24.     END;
  25. $$


  26. DELIMITER ;




  27. DELIMITER $$


  28. USE `t_girl`$$


  29. DROP TRIGGER /*!50032 IF EXISTS */ `filtered_update`$$


  30. CREATE
  31.     /*!50017 DEFINER = 'root'@'localhost' */
  32.     TRIGGER `filtered_update` AFTER UPDATE ON `girl1`
  33.     FOR EACH ROW BEGIN
  34. IF new.rank BETWEEN 10 AND 100 THEN
  35. REPLACE girl1_filtered_index VALUES (new.id,new.rank);
  36. ELSE
  37. DELETE FROM girl1_filtered_index WHERE id = old.id;
  38. END IF;
  39.     END;
  40. $$


  41. DELIMITER ;




  42. DELIMITER $$


  43. USE `t_girl`$$


  44. DROP TRIGGER /*!50032 IF EXISTS */ `filtered_delete`$$


  45. CREATE
  46.     /*!50017 DEFINER = 'root'@'localhost' */
  47.     TRIGGER `filtered_delete` AFTER DELETE ON `girl1`
  48.     FOR EACH ROW BEGIN
  49. DELETE FROM girl1_filtered_index WHERE id = old.id;
  50.     END;
  51. $$


  52. DELIMITER ;


  53. OK,我们导入测试数据。
  54. ytt>load data infile 'girl1.txt' into table girl1 fields terminated by ',';
  55. Query OK, 100000 rows affected (1.05 sec)
  56. Records: 100000 Deleted: 0 Skipped: 0 Warnings: 0


  57. ytt>select count(*) from girl1;
  58. +----------+
  59. | count(*) |
  60. +----------+
  61. | 100000 |
  62. +----------+
  63. 1 row in set (0.04 sec)


  64. ytt>select count(*) from girl1_filtered_index;
  65. +----------+
  66. | count(*) |
  67. +----------+
  68. | 640 |
  69. +----------+
  70. 1 row in set (0.00 sec)



这里,我们把查询语句修改成基础表和条件索引表的JOIN。



点击(此处)折叠或打开

  1. select a.id,a.rank from girl1 as a where a.id in (select b.id from girl1_filtered_index as b where b.rank between 20 and 60) limit 20;



当然这只是功能上的一个演示。 最终实现得靠MySQL 5.8了。^____^
阅读(5610) | 评论(0) | 转发(1) |
给主人留下些什么吧!~~