I did mean the big query. Are you saying that executing the following:
EXPLAIN select
DISTINCT SAO_INDEX
from
T_SALES_ORDER_ITEM,
T_PROGRAM_PRODUCT,
T_PROPERTY,
T_SCHEDULE_ITEM,
T_SALES_ORDER
where
SOI_LNK_PRODUCT NOT IN (7,8,9)
and PMP_LNK_CHANNEL = 1
and PMP_LNK_PROGRAM = 1
and SOI_LNK_PRODUCT = PMP_LNK_PRODUCT
and SOI_LNK_SALES_ORDER = SAO_INDEX
and PRY_LNK_SALES_ORDER_ITEM = SOI_INDEX
and SCI_LNK_SALES_ORDER_ITEM = SOI_INDEX
and SCI_LNK_MEDIUM IN (1,2)
and SCI_LNK_CHANNEL = 1
and ( ((SCI_START_DATE <= '2004-09-08') and ( SCI_FINISHED_DATE >= '2004-09-08' ))
OR ((SCI_START_DATE >= '2004-09-08') and (SCI_FINISHED_DATE <= '2005-09-06'))
OR (SCI_START_DATE between '2004-09-08' and '2005-09-06'))
ORDER BY PRY_EXPORT_CITY
gave you this:
-----------------------------------
id: 1
select_type: SIMPLE
table: T_PROPERTY
type: index
possible_keys: PRY_LNK_SALES_ORDER_ITEM
key: PRY_LNK_SALES_ORDER_ITEM
key_len: 4
ref: NULL
rows: 5537
Extra: Using index; Using temporary; Using filesort
-----------------------------------
id: 1
select_type: SIMPLE
table: T_SCHEDULE_ITEM
type: ref
possible_keys: SCI_FINISHED_DATE,SCI_START_DATE,SCI_LNK_CHANNEL,SCI_LNK_SALES_ORDER_ITEM,SCI_LNK_MEDIUM
key: SCI_LNK_SALES_ORDER_ITEM
key_len: 4
ref: tvplanner4.T_PROPERTY.PRY_LNK_SALES_ORDER_ITEM
rows: 4
Extra: Using where
-----------------------------------
id: 1
select_type: SIMPLE
table: T_SALES_ORDER_ITEM
type: eq_ref
possible_keys: SOI_INDEX,SOI_LNK_PRODUCT,INDEX_LNK_SOA_PRODUCT
key: SOI_INDEX
key_len: 4
ref: tvplanner4.T_SCHEDULE_ITEM.SCI_LNK_SALES_ORDER_ITEM
rows: 1
Extra: Using where
-----------------------------------
id: 1
select_type: SIMPLE
table: T_SALES_ORDER
type: eq_ref
possible_keys: SAO_INDEX
key: SAO_INDEX
key_len: 4
ref: tvplanner4.T_SALES_ORDER_ITEM.SOI_LNK_SALES_ORDER
rows: 1
Extra: Using index
-----------------------------------
id: 1
select_type: SIMPLE
table: T_PROGRAM_PRODUCT
type:ref
possible_keys: PMP_LNK_PROGRAM,PMP_LNK_CHANNEL,PMP_LNK_PRODUCT
key:PMP_LNK_PRODUCT
key_len : 4
ref: tvplanner4.T_SALES_ORDER_ITEM.SOI_LNK_PRODUCT
rows: 2
Extra: Using where; Distinct
and executing this:
EXPLAIN select
DISTINCT SAO_INDEX
from
T_SALES_ORDER_ITEM,
T_PROGRAM_PRODUCT,
T_PROPERTY,
T_SCHEDULE_ITEM,
T_SALES_ORDER
where
SOI_LNK_PRODUCT NOT IN (7,8,9)
and PMP_LNK_CHANNEL = 1
and PMP_LNK_PROGRAM = 1
and SOI_LNK_PRODUCT = PMP_LNK_PRODUCT
and SOI_LNK_SALES_ORDER = SAO_INDEX
and PRY_LNK_SALES_ORDER_ITEM = SOI_INDEX
and SCI_LNK_SALES_ORDER_ITEM = SOI_INDEX
and SCI_LNK_MEDIUM IN (1,2)
and SCI_LNK_CHANNEL = 1
and ( ((SCI_START_DATE <= '2004-09-08') and ( SCI_FINISHED_DATE >= '2004-09-08' ))
OR ((SCI_START_DATE >= '2004-09-08') and (SCI_FINISHED_DATE <= '2005-09-06'))
OR (SCI_START_DATE between '2004-09-08' and '2005-09-06'))
gave you this?
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: T_PROGRAM_PRODUCT
type: ref
possible_keys: PMP_LNK_PROGRAM,PMP_LNK_CHANNEL,PMP_LNK_PRODUCT
key: PMP_LNK_CHANNEL
key_len: 4
ref: const
rows: 16
Extra: Using where; Using temporary; Using filesort
*************************** 2. row ***************************
id: 1
select_type: SIMPLE
table: T_SALES_ORDER_ITEM
type: ref
possible_keys: SOI_INDEX,SOI_LNK_PRODUCT,INDEX_LNK_SOA_PRODUCT
key: SOI_LNK_PRODUCT
key_len: 4
ref: tvplanner4.T_PROGRAM_PRODUCT.PMP_LNK_PRODUCT
rows: 412
Extra:
*************************** 3. row ***************************
id: 1
select_type: SIMPLE
table: T_SALES_ORDER
type: eq_ref
possible_keys: SAO_INDEX
key: SAO_INDEX
key_len: 4
ref: tvplanner4.T_SALES_ORDER_ITEM.SOI_LNK_SALES_ORDER
rows: 1
Extra: Using index
*************************** 4. row ***************************
id: 1
select_type: SIMPLE
table: T_SCHEDULE_ITEM
type: ref
possible_keys: SCI_FINISHED_DATE,SCI_START_DATE,SCI_LNK_CHANNEL,SCI_LNK_SALES_ORDER_ITEM,SCI_LNK_MEDIUM
key: SCI_LNK_SALES_ORDER_ITEM
key_len: 4
ref: tvplanner4.T_SALES_ORDER_ITEM.SOI_INDEX
rows: 6
Extra: Using where; Distinct
*************************** 5. row ***************************
id: 1
select_type: SIMPLE
table: T_PROPERTY
type: eq_ref
possible_keys: PRY_LNK_SALES_ORDER_ITEM
key: PRY_LNK_SALES_ORDER_ITEM
key_len: 4
ref: tvplanner4.T_SCHEDULE_ITEM.SCI_LNK_SALES_ORDER_ITEM
rows: 1
Extra: Using where; Distinct
If so, then something's really wrong, as the two execution plans have entirely different paths and estimated rows used... ?!
Jay Pipes
Community Relations Manager, North America, MySQL Inc.
Got Cluster?
http://www.mysql.com/cluster
Personal:
http://jpipes.com