GA

2014/05/20

InnoDBオンラインALTER TABLEではIndex_lengthが更新されない

そのままなんですが。


インデックス張ってからロードしたとき。

mysql> CREATE TABLE t1 (num int unsigned, val varchar(32), upd datetime default current_timestamp);
mysql> ALTER TABLE t1 ADD KEY (val, upd), ADD KEY (upd);
mysql> LOAD DATA INFILE '/data/tmp/md5.tsv' INTO TABLE t1(num, val);

$ ls -ls /data/tmp/mysql/d1/t1.ibd
1754804 -rw-rw---- 1 mysql mysql 1795162112 May 20 14:41 /data/tmp/mysql/d1/t1.ibd

mysql> SHOW TABLE STATUS\G
*************************** 1. row ***************************
           Name: t1
         Engine: InnoDB
        Version: 10
     Row_format: Compact
           Rows: 9705549
 Avg_row_length: 74
    Data_length: 727711744
Max_data_length: 0
   Index_length: 1027342336
      Data_free: 6291456
 Auto_increment: NULL
    Create_time: 2014-05-20 14:38:32
    Update_time: NULL
     Check_time: NULL
      Collation: utf8_general_ci
       Checksum: NULL
 Create_options:
        Comment:
1 row in set (0.00 sec)


ALTER TABLE .. ALGORITHM= COPY
mysql> CREATE TABLE t1 (num int unsigned, val varchar(32), upd datetime default current_timestamp);
mysql> LOAD DATA INFILE '/data/tmp/md5.tsv' INTO TABLE t1(num, val);
mysql> ALTER TABLE t1 ADD KEY (val, upd), ADD KEY (upd), ALGORITHM= COPY;

$ ll -s /data/tmp/mysql/d1/t1.ibd
1754804 -rw-rw---- 1 mysql mysql 1795162112 May 20 15:37 /data/tmp/mysql/d1/t1.ibd

mysql> SHOW TABLE STATUS\G
*************************** 1. row ***************************
           Name: t1
         Engine: InnoDB
        Version: 10
     Row_format: Compact
           Rows: 9188260
 Avg_row_length: 75
    Data_length: 691011584
Max_data_length: 0
   Index_length: 965476352
      Data_free: 6291456
 Auto_increment: NULL
    Create_time: 2014-05-20 15:37:16
    Update_time: NULL
     Check_time: NULL
      Collation: utf8_general_ci
       Checksum: NULL
 Create_options:
        Comment:
1 row in set (0.00 sec)


ALTER TABLE .. ALGORITHM= INPLACE 暗黙のデフォルト、いわゆるオンラインALTER TABLE

mysql> CREATE TABLE t1 (num int unsigned, val varchar(32), upd datetime default current_timestamp);
mysql> LOAD DATA INFILE '/data/tmp/md5.tsv' INTO TABLE t1(num, val);
mysql> ALTER TABLE t1 ADD KEY (val, upd), ADD KEY (upd);

$ ll -s /data/tmp/mysql/d1/t1.ibd
1394004 -rw-rw---- 1 mysql mysql 1426063360 May 20 14:45 /data/tmp/mysql/d1/t1.ibd

mysql> SHOW TABLE STATUS\G
*************************** 1. row ***************************
           Name: t1
         Engine: InnoDB
        Version: 10
     Row_format: Compact
           Rows: 9704565
 Avg_row_length: 75
    Data_length: 729808896
Max_data_length: 0
   Index_length: 0
      Data_free: 0
 Auto_increment: NULL
    Create_time: 2014-05-20 14:45:40
    Update_time: NULL
     Check_time: NULL
      Collation: utf8_general_ci
       Checksum: NULL
 Create_options:
        Comment:
1 row in set (0.00 sec)

mysql> ANALYZE TABLE t1;
+-------+---------+----------+----------+
| Table | Op      | Msg_type | Msg_text |
+-------+---------+----------+----------+
| d1.t1 | analyze | status   | OK       |
+-------+---------+----------+----------+
1 row in set (0.01 sec)

mysql> SHOW TABLE STATUS\G
*************************** 1. row ***************************
           Name: t1
         Engine: InnoDB
        Version: 10
     Row_format: Compact
           Rows: 9704565
 Avg_row_length: 75
    Data_length: 729808896
Max_data_length: 0
   Index_length: 690749440
      Data_free: 0
 Auto_increment: NULL
    Create_time: 2014-05-20 15:42:26
    Update_time: NULL
     Check_time: NULL
      Collation: utf8_general_ci
       Checksum: NULL
 Create_options:
        Comment:
1 row in set (0.00 sec)


information_schema.tablesやSHOW TABLE STATUSを見張っている場合は要注意…:(;゙゚'ω゚'):

0 件のコメント :

コメントを投稿