概要 †
目次 †参考 †
インデックス †
実行計画 †
--------------------------------------------------------------- |Id |Operation | Name | Rows | Cost | --------------------------------------------------------------- | 0 |SELECT STATEMENT | | 1 | 2 | | 1 | TABLE ACCESS BY INDEX ROWID| EMPLOYEES | 1 | 2 | |*2 | INDEX UNIQUE SCAN | EMPLOYEES_PK | 1 | 1 | --------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("EMPLOYEE_ID"=123) 単一インデックス †
INDEX UNIQUE SCAN - PRIMARY Key †
CREATE TABLE employees ( employee_id NUMBER NOT NULL, first_name VARCHAR2(1000) NOT NULL, last_name VARCHAR2(1000) NOT NULL, CONSTRAINT employees_pk PRIMARY KEY (employee_id) ) SELECT first_name, last_name FROM employees WHERE employee_id = 123 --------------------------------------------------------------- |Id |Operation | Name | Rows | Cost | --------------------------------------------------------------- | 0 |SELECT STATEMENT | | 1 | 2 | | 1 | TABLE ACCESS BY INDEX ROWID| EMPLOYEES | 1 | 2 | |*2 | INDEX UNIQUE SCAN | EMPLOYEES_PK | 1 | 1 | --------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("EMPLOYEE_ID"=123) INDEX RANGE SCAN - 複合インデックス †
CREATE TABLE employees ( employee_id NUMBER NOT NULL, subsidiary_id NUMBER NOT NULL, first_name VARCHAR2(1000) NOT NULL, last_name VARCHAR2(1000) NOT NULL, CONSTRAINT employees_pk PRIMARY KEY (employee_id) ) CREATE UNIQUE INDEX EMPLOYEES_PK ON EMPLOYEES (SUBSIDIARY_ID, EMPLOYEE_ID) SELECT first_name, last_name FROM employees WHERE subsidiary_id = 20 --------------------------------------------------------------- |Id |Operation | Name | Rows | Cost | --------------------------------------------------------------- | 0 |SELECT STATEMENT | | 106 | 75 | | 1 | TABLE ACCESS BY INDEX ROWID| EMPLOYEES | 106 | 75 | |*2 | INDEX RANGE SCAN | EMPLOYEES_PK | 106 | 2 | --------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access("SUBSIDIARY_ID"=20) TABLE ACCESS FULL - インデックスを指定すると探索範囲が限定される †
CREATE TABLE employees ( employee_id NUMBER NOT NULL, subsidiary_id NUMBER NOT NULL, first_name VARCHAR2(1000) NOT NULL, last_name VARCHAR2(1000) NOT NULL, CONSTRAINT employees_pk PRIMARY KEY (employee_id) ) SELECT first_name, last_name, subsidiary_id FROM employees WHERE last_name = 'WINAND' AND subsidiary_id = 30 --------------------------------------------------------------- |Id |Operation | Name | Rows | Cost | --------------------------------------------------------------- | 0 |SELECT STATEMENT | | 1 | 30 | |*1 | TABLE ACCESS BY INDEX ROWID| EMPLOYEES | 1 | 30 | |*2 | INDEX RANGE SCAN | EMPLOYEES_PK | 40 | 2 | --------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("LAST_NAME"='WINAND') 2 - access("SUBSIDIARY_ID"=30) SELECT /*+ NO_INDEX(EMPLOYEES EMPLOYEES_PK) */ first_name, last_name, subsidiary_id FROM employees WHERE last_name = 'WINAND' AND subsidiary_id = 30 ---------------------------------------------------- | Id | Operation | Name | Rows | Cost | ---------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 477 | |* 1 | TABLE ACCESS FULL| EMPLOYEES | 1 | 477 | ---------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("LAST_NAME"='WINAND' AND "SUBSIDIARY_ID"=30) プレイスホルダー †
LIKE 演算子での INDEX RANGE SCAN の ACCESS †
CREATE INDEX emp_up_name ON employees (UPPER(last_name)) SELECT first_name, last_name, date_of_birth FROM employees WHERE UPPER(last_name) LIKE 'WIN%D' --------------------------------------------------------------- |Id | Operation | Name | Rows | Cost | --------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 4 | | 1 | TABLE ACCESS BY INDEX ROWID| EMPLOYEES | 1 | 4 | |*2 | INDEX RANGE SCAN | EMP_UP_NAME | 1 | 2 | --------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - access(UPPER("LAST_NAME") LIKE 'WIN%D') filter(UPPER("LAST_NAME") LIKE 'WIN%D') インデックスは各行に 1 個作るより全部まとめたほうが更新が早い †
部分インデックス †
CREATE INDEX messages_todo ON messages (receiver) WHERE processed = 'N' 結合 †
結合: NESTED LOOPS OUTER †
CREATE TABLE employees ( employee_id NUMBER NOT NULL, subsidiary_id NUMBER NOT NULL, first_name VARCHAR2(1000) NOT NULL, last_name VARCHAR2(1000) NOT NULL, CONSTRAINT employees_pk PRIMARY KEY (employee_id) ) CREATE TABLE SALES ( employee_id NUMBER NOT NULL, subsidiary_id NUMBER NOT NULL, sales_id NUMBER NOT NULL, ) select this_.subsidiary_id as subsidiary1_0_1_ , this_.employee_id as employee2_0_1_ -- MORE this_ columns on employees , sales2_.sale_id as sale1_3_ -- MORE sales2_ columns on sales from employees this_ left outer join sales sales2_ on this_.subsidiary_id=sales2_.subsidiary_id and this_.employee_id=sales2_.employee_id where lower(this_.last_name) like ? --------------------------------------------------------------- |Id |Operation | Name | Rows | Cost | --------------------------------------------------------------- | 0 |SELECT STATEMENT | | 822 | 38 | | 1 | NESTED LOOPS OUTER | | 822 | 38 | | 2 | TABLE ACCESS BY INDEX ROWID| EMPLOYEES | 1 | 4 | |*3 | INDEX RANGE SCAN | EMP_UP_NAME | 1 | | | 4 | TABLE ACCESS BY INDEX ROWID| SALES | 821 | 34 | |*5 | INDEX RANGE SCAN | SALES_EMP | 31 | | --------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - access(UPPER("LAST_NAME") LIKE 'WIN%') filter(UPPER("LAST_NAME") LIKE 'WIN%') 5 - access("E0_"."SUBSIDIARY_ID"="S1_"."SUBSIDIARY_ID"(+) AND "E0_"."EMPLOYEE_ID" ="S1_"."EMPLOYEE_ID"(+)) ORM を開発中に使うときはロギングを ON にしましょう †開発中はSQLのロギングを有効にし、 生成されたSQL文のレビューをしましょう。
$logger = new \Doctrine\DBAL\Logging\EchoSqlLogger; $config->setSQLLogger($logger);
<property name="eclipselink.logging.level" value="FINE"/> <property name="hibernate.show_sql" value="TRUE"/> <property name="openjpa.Log" value="SQL=TRACE"/> 結合: Hashmap †
SELECT * FROM sales s JOIN employees e ON (s.subsidiary_id = e.subsidiary_id AND s.employee_id = e.employee_id ) WHERE s.sale_date > trunc(sysdate) - INTERVAL '6' MONTH -------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost | -------------------------------------------------------------- | 0 | SELECT STATEMENT | | 49244 | 59M| 12049| |* 1 | HASH JOIN | | 49244 | 59M| 12049| | 2 | TABLE ACCESS FULL| EMPLOYEES | 10000 | 9M| 478| |* 3 | TABLE ACCESS FULL| SALES | 49244 | 10M| 10521| -------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("S"."SUBSIDIARY_ID"="E"."SUBSIDIARY_ID" AND "S"."EMPLOYEE_ID" ="E"."EMPLOYEE_ID") 3 - filter("S"."SALE_DATE">TRUNC(SYSDATE@!) -INTERVAL'+00-06' YEAR(2) TO MONTH) CREATE INDEX sales_date ON sales (sale_date) SELECT * FROM sales s JOIN employees e ON (s.subsidiary_id = e.subsidiary_id AND s.employee_id = e.employee_id ) WHERE s.sale_date > trunc(sysdate) - INTERVAL '6' MONTH -------------------------------------------------------------- | Id | Operation | Name | Bytes| Cost| -------------------------------------------------------------- | 0 | SELECT STATEMENT | | 59M| 3252| |* 1 | HASH JOIN | | 59M| 3252| | 2 | TABLE ACCESS FULL | EMPLOYEES | 9M| 478| | 3 | TABLE ACCESS BY INDEX ROWID| SALES | 10M| 1724| |* 4 | INDEX RANGE SCAN | SALES_DATE| | | -------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("S"."SUBSIDIARY_ID"="E"."SUBSIDIARY_ID" AND "S"."EMPLOYEE_ID" ="E"."EMPLOYEE_ID" ) 4 - access("S"."SALE_DATE" > TRUNC(SYSDATE@!) -INTERVAL'+00-06' YEAR(2) TO MONTH) 結合: SORT-MERGE †
他の DB との関係 †MySQL †
+----+-----------+-------+---------+---------+------+-------+ | id | table | type | key | key_len | rows | Extra | +----+-----------+-------+---------+---------+------+-------+ | 1 | employees | const | PRIMARY | 5 | 1 | | +----+-----------+-------+---------+---------+------+-------+ |