Bug #37094 Stored Procedure Exec when Replicated makes Replication Slave run very slow.
Submitted: 30 May 2008 8:55 Modified: 27 Nov 2008 14:27
Reporter: Shafraz Thawfeek Email Updates:
Status: No Feedback Impact on me:
None 
Category:MySQL Server: Stored Routines Severity:S1 (Critical)
Version:5.0.45 OS:FreeBSD (FreeBSD 6.2-RELEASE-p7 (HARDADMIN))
Assigned to: CPU Architecture:Any

[30 May 2008 8:55] Shafraz Thawfeek
Description:
We're running MySQL in a production environment for a OLTP billing system. There is a MySQL Master server and a MySQL Replication Slave. There is also a front end Web Interface where the we reads are done 100% on the Slave.

The Database contains a Ratesheet table (ENTRATE) and a Ratesheet History Table (ENTRATE_H). Users are allowed to upload Ratesheets into the ENTRATE table via Web Interface. When a new rate is added into ENTRATE, the corresponding record is moved into the ENTRATE_H (History) table and ENTRATE accepts the new rate. All this is done via a Stored Procedure.

On Average, each Ratesheet upload contains about 12,000 rows.

When executed, Each upload takes about 2-3 minutes to run on the Master Server, however, when replicated to the slave it takes about 25 - 30 minutes to complete and brings the whole OLTP system to a Standstill. As everytime a rate upload occurs, the Slave delay increases upto 30 minutes and users don't have access to realtime data.

Upon noticing the queries run on the slave, We found that the query was slightly different than of what was run on the Master. We saw something like NAME_CONST('xxx',_latin1'xxx'). Perhaps this could be causing the slave to slog?

How to repeat:
Master DB table Definitions:

CREATE TABLE `ENTRATE` (
  `ATRRTID` int(11) NOT NULL auto_increment,
  `ATRRATEID` int(11) NOT NULL default '0',
  `ATRSTDATE` datetime default '2000-01-01 00:00:00',
  `ATRORIG` varchar(40) NOT NULL default '*',
  `ATRDEST` varchar(40) NOT NULL default '00',
  `ATRCMNT` varchar(80) NOT NULL default 'New Destination',
  `ATRBASE` int(1) NOT NULL default '1',
  `ATRRATEM` float(14,8) NOT NULL default '0.00000000',
  `ATRRATEC` float(14,8) NOT NULL default '0.00000000',
  `ATRCURID` int(11) NOT NULL default '1',
  `ATRSTDAY` int(4) NOT NULL default '0',
  `ATRENDAY` int(4) NOT NULL default '6',
  `ATRSTTM` time default '00:00:00',
  `ATRENTM` time default '23:59:59',
  `ATRINCR` int(11) NOT NULL default '1',
  `ATRGRACE` int(11) NOT NULL default '0',
  `ATRMINDUR` int(11) NOT NULL default '1',
  `ATRTERMVOIPACCTID` int(11) NOT NULL default '0',
  `ATRMINUTELENGTH` int(4) unsigned NOT NULL default '60',
  `ATRINVDESTGROUPID` int(11) NOT NULL default '0',
  `ATRMINLENGTH` int(4) NOT NULL default '2',
  `ATRMAXLENGTH` int(4) NOT NULL default '32',
  `ATRDESTENABLE` int(1) NOT NULL default '1',
  PRIMARY KEY  (`ATRRTID`),
  KEY `ATRRATEID` (`ATRRATEID`),
  KEY `currency` (`ATRCURID`),
  KEY `dest` (`ATRDEST`),
  KEY `st_time` (`ATRSTTM`),
  KEY `en_time` (`ATRENTM`),
  KEY `st_day` (`ATRSTDAY`),
  KEY `en_day` (`ATRENDAY`),
  KEY `base` (`ATRBASE`),
  KEY `term_voipacct` (`ATRTERMVOIPACCTID`),
  KEY `ATRRATEID_2` (`ATRRATEID`,`ATRDEST`,`ATRBASE`,`ATRSTDATE`)
) ENGINE=MyISAM AUTO_INCREMENT=21095380 DEFAULT CHARSET=latin1 

CREATE TABLE `ENTRATE_H` (
  `ATRTIMESTAMP` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
  `ATRRTID` int(11) NOT NULL,
  `ATRRATEID` int(11) NOT NULL default '0',
  `ATRSTDATE` datetime default '2000-01-01 00:00:00',
  `ATRORIG` varchar(40) NOT NULL default '*',
  `ATRDEST` varchar(40) NOT NULL default '00',
  `ATRCMNT` varchar(80) NOT NULL default 'New Destination',
  `ATRBASE` int(1) NOT NULL default '1',
  `ATRRATEM` float(14,8) NOT NULL default '0.00000000',
  `ATRRATEC` float(14,8) NOT NULL default '0.00000000',
  `ATRCURID` int(11) NOT NULL default '1',
  `ATRSTDAY` int(4) NOT NULL default '0',
  `ATRENDAY` int(4) NOT NULL default '6',
  `ATRSTTM` time default '00:00:00',
  `ATRENTM` time default '23:59:59',
  `ATRINCR` int(11) NOT NULL default '1',
  `ATRGRACE` int(11) NOT NULL default '0',
  `ATRMINDUR` int(11) NOT NULL default '1',
  `ATRTERMVOIPACCTID` int(11) NOT NULL default '0',
  `ATRMINUTELENGTH` int(4) unsigned NOT NULL default '60',
  `ATRINVDESTGROUPID` int(11) NOT NULL default '0',
  `ATRMINLENGTH` int(4) NOT NULL default '2',
  `ATRMAXLENGTH` int(4) NOT NULL default '32',
  `ATRDESTENABLE` int(1) NOT NULL default '1'
) ENGINE=MyISAM DEFAULT CHARSET=latin1

CREATE DEFINER=`root`@`localhost` PROCEDURE `insert_rate_item`(
  IN _rate_id int(11),
  IN _start_date datetime,
  IN _dest varchar(40),
  IN _comment varchar(80),
  IN _base int(1),
  IN _rate_m float(14,8),
  IN _rate_c float(14,8),
  IN _currency_id int(11),
  IN _st_wday int(4),
  IN _en_wday int(4),
  IN _st_time time,
  IN _en_time time,
  IN _incr int(11),
  IN _grace int(11),
  IN _mindur int(11),
  IN _minflex int(4),
  IN _inv_group int(11),
  IN _mindigits int(4),
  IN _maxdigits int(4),
  IN _enable int(1),
  OUT _new_item_id int(11)
  )
BEGIN
    DECLARE _affected_rows INT;
    
    
    
    INSERT INTO ENTRATE
      (ATRRATEID, ATRSTDATE, ATRDEST, ATRCMNT, ATRBASE, ATRRATEM,
       ATRRATEC, ATRCURID, ATRSTDAY, ATRENDAY, ATRSTTM, ATRENTM, ATRINCR, ATRGRACE,
       ATRMINDUR, ATRMINUTELENGTH, ATRINVDESTGROUPID, ATRMINLENGTH,
       ATRMAXLENGTH, ATRDESTENABLE)
    VALUES 
      (_rate_id, IF(_start_date > now(),_start_date, now() - interval 1 minute), _dest, _comment, _base, _rate_m,
       _rate_c, _currency_id, _st_wday, _en_wday, _st_time, _en_time, _incr, _grace,
       _mindur, _minflex, _inv_group, _mindigits,
       _maxdigits, _enable);
    
    SELECT LAST_INSERT_ID() INTO _new_item_id;
    
    SELECT count(*) INTO _affected_rows
      FROM ENTRATE WHERE ATRRATEID = _rate_id
      AND ATRDEST = _dest AND ATRBASE = 1
      AND ATRSTDATE < now();
    
    
    IF _affected_rows >1 THEN
      
      
      WHILE _affected_rows > 1 DO
        INSERT INTO ENTRATE_H
          (ATRRTID, ATRRATEID, ATRSTDATE, ATRORIG, ATRDEST, ATRCMNT, ATRBASE, ATRRATEM,
          ATRRATEC, ATRCURID, ATRSTDAY, ATRENDAY, ATRSTTM, ATRENTM, ATRINCR, ATRGRACE,
          ATRMINDUR, ATRTERMVOIPACCTID, ATRMINUTELENGTH, ATRINVDESTGROUPID, ATRMINLENGTH,
          ATRMAXLENGTH, ATRDESTENABLE)
        SELECT * FROM ENTRATE
          WHERE ATRRATEID = _rate_id
            AND ATRDEST = _dest 
            AND ATRBASE = 1 
            AND ATRSTDATE < now() 
          ORDER BY ATRSTDATE ASC 
          LIMIT 1; 
        
        DELETE FROM ENTRATE 
          WHERE ATRRATEID = _rate_id
            AND ATRDEST = _dest 
            AND ATRBASE = 1 
            AND ATRSTDATE < now() 
          ORDER BY ATRSTDATE ASC 
          LIMIT 1;
      SET _affected_rows = _affected_rows - 1;
      END WHILE;
    END IF;
  END 

When a rate uplaod is called - this is the kind of stuff I see on the slave process list. Most of the time, its about the ENTRATE_H Table I guess.

INSERT INTO ENTRATE_H (ATRRTID, ATRRATEID, ATRSTDATE, ATRORIG, 
ATRDEST, ATRCMNT, ATRBASE, ATRRATEM, ATRRATEC, ATRCURID, ATRSTDAY, 
ATRENDAY, ATRSTTM, ATRENTM, ATRINCR, ATRGRACE, ATRMINDUR, 
ATRTERMVOIPACCTID, ATRMINUTELENGTH, ATRINVDESTGROUPID, ATRMINLENGTH, 
ATRMAXLENGTH,
ATRDESTENABLE) SELECT * FROM ENTRATE WHERE ATRRATEID =
NAME_CONST('_rate_id',2348) AND ATRDEST =
NAME_CONST('_dest',_latin1'634281') AND ATRBASE = 1 AND ATRSTDATE <
now() ORDER BY ATRSTDATE ASC LIMIT 1:

INSERT INTO ENTRATE_H (ATRRTID, ATRRATEID, ATRSTDATE, ATRORIG, 
ATRDEST, ATRCMNT, ATRBASE, ATRRATEM, ATRRATEC, ATRCURID, ATRSTDAY, 
ATRENDAY, ATRSTTM, ATRENTM, ATRINCR, ATRGRACE, ATRMINDUR, 
ATRTERMVOIPACCTID, ATRMINUTELENGTH, ATRINVDESTGROUPID, ATRMINLENGTH, 
ATRMAXLENGTH, ATRDESTENABLE) SELECT * FROM ENTRATE WHERE ATRRATEID =
NAME_CONST('_rate_id',2348) AND ATRDEST =
NAME_CONST('_dest',_latin1'683') AND ATRBASE = 1 AND ATRSTDATE < now() 
ORDER BY ATRSTDATE ASC LIMIT 1:

Suggested fix:
The Replication slave should execute the statements as fast the Master itself. I am not too sure if the mod NAME_CONST('_dest',_latin1'683') causes any issues. If thats the case, I am looking for a workaround to keep the production environment running smooth.
[27 Oct 2008 14:27] Sveta Smirnova
Thank you for the report.

Please try current version 5.0.67 and inform us if problem still exists: there were several bug related to NAME_CONST fixed since 5.0.45.
[28 Nov 2008 0:00] Bugs System
No feedback was provided for this bug for over a month, so it is
being suspended automatically. If you are able to provide the
information that was originally requested, please do so and change
the status of the bug back to "Open".