MySQL Forums
Forum List  »  Performance

Re: Index Not being used.
Posted by: Rick James
Date: June 04, 2016 05:14PM

    SELECT  l.ORD_Item, l.ORD_Desc, l.ORD_Item_Class, SUM(l.ORD_Qty),
            SUM(ROUND(l.ORD_Qty * l.ORD_Price, 2))
        FROM  pos_ord_headers AS h
        JOIN  pos_ord_lines AS l  ON l.ORD_ID = h.ORD_ID
        WHERE  h.ORD_Date>='2015-01-01'
          AND  h.ORD_DATE <'2015-01-01' + INTERVAL 1 YEAR;

    headers: INDEX(ORD_DATE, ORD_ID) -- 'covering index' is much smaller and faster

Changing to InnoDB would speed things up, too. This is because of the PRIMARY KEY(ORD_ID, ...) being 'clustered'. Caveat: Changing to InnoDB would double or triple the disk footprint of the tables. See http://mysql.rjweb.org/doc.php/myisam2innodb for notes on conversion.

You have an accuracy issue... FLOAT can contain only 6-7 significant digits. If you had the monetary value of 987654.32, the 0.32 would be messed up. Also, FLOAT incurs an extra rounding when reading and writing; this can lead to other errors. Recommend DECIMAL instead of FLOAT. (Note: FLOAT occupies 4 bytes; DECIMAL(15,4) takes 7; DECIMAL(9,4) takes 5.)

Another solution is to build "summary tables". You could summarize each day (or week or month) into another table, then do this 'report' from that table. The speedup might be 10x. More discussion: http://mysql.rjweb.org/doc.php/summarytables

Options: ReplyQuote


Subject
Views
Written By
Posted
2889
May 26, 2016 02:29PM
1309
May 26, 2016 03:53PM
1147
May 27, 2016 12:45AM
1059
May 27, 2016 07:05AM
1056
May 27, 2016 11:29PM
1171
May 31, 2016 07:04AM
1011
May 31, 2016 09:26PM
1064
June 01, 2016 05:40AM
876
June 01, 2016 11:29AM
1115
June 01, 2016 11:41AM
Re: Index Not being used.
1047
June 04, 2016 05:14PM
1067
May 27, 2016 10:14AM


Sorry, you can't reply to this topic. It has been closed.

Content reproduced on this site is the property of the respective copyright holders. It is not reviewed in advance by Oracle and does not necessarily represent the opinion of Oracle or any other party.