MYSQL METADATA LOCK(MDL LOCK) 理论及加锁类型测试

目录
  • MYSQL METADATA LOCK(MDL LOCK)学习 理论知识和加锁类型测试
    • 一、初步了解
    • 二、基础重要的数据结构(类)和概念
      • 1、MDL TYPE
      • 2、MDL NAMESPACE
      • 3、实现分类
      • 4、MDL兼容矩阵
      • 5、MDL duration及MDL持续到什么时候
      • 6、MDL LOCK FAST PATH(unobtrusive) OR SLOW PATH(obtrusive)
      • 7、MDL_request类
      • 7、MDL_key类
      • 8、MDL_ticket
      • 9、MDL_lock
      • 10、MDL_context
      • 11、MDL_wait
      • 12、等待标记
    • 三、增加MDL LOCK打印函数
    • 四、在合适的位置增加打印函数进行观察
      • 1、加锁:MDL_context::acquire_lock
      • 2、降级
      • 3、升级
    • 五、各种MDL LOCK TYPE加锁测试
      • 1、MDL_INTENTION_EXCLUSIVE(IX)
      • 2、MDL_SHARED(S)
      • 3、MDL_SHARED_HIGH_PRIO(SH)
      • 4、MDL_SHARED_READ(SR)
      • 5、MDL_SHARED_WRITE(SW)
      • 6、MDL_SHARED_WRITE_LOW_PRIO(SWL)
      • 7、MDL_SHARED_UPGRADABLE(SU)
      • 8、MDL_SHARED_NO_WRITE(SNW)
      • 9、MDL_SHARED_READ_ONLY(SRO)
      • 10、MDL_SHARED_NO_READ_WRITE(SNRW)
      • 11、MDL_EXCLUSIVE(X)
    • 六、源码注释部分

MYSQL METADATA LOCK(MDL LOCK)学习 理论知识和加锁类型测试

前言:

源码版本:5.7.14
注意MDL和DML术语的不同

一、初步了解

MYSQL中MDL锁一直是一个比较让人比较头疼的问题,我们谈起锁一般更加倾向于INNODB下层的gap lock、next key lock、row lock等,
因为它很好理解,也很好观察,而对于MDL LOCK却了解得很少,因为它实在不好观察,只有出现问题查看show processlist勉强可以看到
简单的所谓的Waiting for table metadata lock之类的状态,其实MDL LOCK是MYSQL上层一个非常复杂的子系统,有自己的死锁检测机制
(无向图?)而大家一般口中的是不是锁表了其实就是指的它,可见的它的关键性和严重性,笔者也是根据自己的需求学习了一些(冰山一角),
而没有能力阅读全部的代码,但是笔者通过增加一个TICKET的打印函数让语句的MDL LOCK加锁流程全部打印出来方便学习研究,下面从
一些基础说起然后告诉大家修改了哪些东西,最后对每种MDL TYPE进行测试和分析,如果大家对基本概念和增加打印函数不感兴趣可
直接参考第五部分加锁测试,但是如果不了解基础知识可能看起来有点困难。 
   刚好最近遇到一次MDL LOCK出现死锁的情况会在下篇文章中给出案例,这里只看理论

----处于层次:MYSQL SERVER层次,实际上早在open_table函数中MDL LOCK就开始获取了,可以说他是最早获取的LOCK结构
----最早获取阶段: THD::enter_stage: 'Opening tables'

调用栈帧:

#0 open_table_get_mdl_lock (thd=0x7fffd0000df0, ot_ctx=0x7fffec06fb00,
    table_list=0x7fffd00067d8, flags=0, mdl_ticket=0x7fffec06f950)
    at /root/mysql5.7.14/percona-server-5.7.14-7/sql/sql_base.cc:2789
#1 0x0000000001516e17 in open_table (thd=0x7fffd0000df0,
    table_list=0x7fffd00067d8, ot_ctx=0x7fffec06fb00)
    at /root/mysql5.7.14/percona-server-5.7.14-7/sql/sql_base.cc:3237

----死锁检测出错码:

{ "ER_LOCK_DEADLOCK", 1213, "Deadlock found when trying to get lock; try restarting transaction" },
ERROR 1213 (40001): Deadlock found when trying to get lock; try restarting transaction

MDL LOCK的死锁抛错和INNODB死锁一模一样不同的只是SHOW ENGINE INNODB 没有死锁信息
----涉及代码:mdl.h mdl.cc

二、基础重要的数据结构(类)和概念

1、MDL TYPE

MDL_INTENTION_EXCLUSIVE(IX)
MDL_SHARED(S)
MDL_SHARED_HIGH_PRIO(SH)
MDL_SHARED_READ(SR)
MDL_SHARED_WRITE(SW)
MDL_SHARED_WRITE_LOW_PRIO(SWL)
MDL_SHARED_UPGRADABLE(SU)
MDL_SHARED_READ_ONLY(SRO)
MDL_SHARED_NO_WRITE(SNW)
MDL_SHARED_NO_READ_WRITE(SNRW)
MDL_EXCLUSIVE(X)

后面会对每种TYPE进行详细的测试,最后也会给出源码中解释

2、MDL NAMESPACE

在MDL中MDL_KEY按照NAMESPACE+DB+OBJECT_NAME的方式进行表示,所谓的namespace也不叫重要
下面是NAMESPACE的分类

- GLOBAL is used for the global read lock.
     - TABLESPACE is for tablespaces.
     - SCHEMA is for schemas (aka databases).
     - TABLE is for tables and views.
     - FUNCTION is for stored functions.
     - PROCEDURE is for stored procedures.
     - TRIGGER is for triggers.
     - EVENT is for event scheduler events.
     - COMMIT is for enabling the global read lock to block commits.
     - USER_LEVEL_LOCK is for user-level locks.
     - LOCKING_SERVICE is for the name plugin RW-lock service

3、实现分类

scope lock:一般对应全局MDL LOCK flush table with read lock namespace space:GLOBAL type:S
object lock:如其名字,对象级别的MDL LOCK,比如TABLE
下面是源码中的注释:

 /**
    Helper struct which defines how different types of locks are handled
    for a specific MDL_lock. In practice we use only two strategies: "scoped"
    lock strategy for locks in GLOBAL, COMMIT, TABLESPACE and SCHEMA namespaces
    and "object" lock strategy for all other namespaces.
  */

4、MDL兼容矩阵

scope lock:    

| Type of active   |
  Request |   scoped lock    |
   type   | IS(*)  IX   S  X |
 ---------+------------------+
 IS       |  +      +   +  + |
 IX       |  +      +   -  - |
 S        |  +      -   +  - |
 X        |  +      -   -  - |

object lock: 

Request  |  Granted requests for lock            |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      S         | +   +   +   +    +    +   +    +    +    -  |
      SH        | +   +   +   +    +    +   +    +    +    -  |
      SR        | +   +   +   +    +    +   +    +    -    -  |
      SW        | +   +   +   +    +    +   -    -    -    -  |
      SWLP      | +   +   +   +    +    +   -    -    -    -  |
      SU        | +   +   +   +    +    -   +    -    -    -  |
      SRO       | +   +   +   -    -    +   +    +    -    -  |
      SNW       | +   +   +   -    -    -   +    -    -    -  |
      SNRW      | +   +   -   -    -    -   -    -    -    -  |
      X         | -   -   -   -    -    -   -    -    -    -  |

5、MDL duration及MDL持续到什么时候

看源码注释:

MDL_STATEMENT:Locks with statement duration are automatically released at the end
              of statement or transaction.
MDL_TRANSACTION: Locks with transaction duration are automatically released at the end
                of transaction
MDL_EXPLICIT:Locks with explicit duration survive the end of statement and transaction.
             They have to be released explicitly by calling MDL_context::release_lock().

6、MDL LOCK FAST PATH(unobtrusive) OR SLOW PATH(obtrusive)

使用两种不同的方式目的在于优化MDL lock的实现,下面是源码的注释

A) "unobtrusive" lock types
            1) Each type from this set should be compatible with all other
               types from the set (including itself).
            2) These types should be common for DML operations
          Our goal is to optimize acquisition and release of locks of this
          type by avoiding complex checks and manipulations on m_waiting/
          m_granted bitmaps/lists. We replace them with a check of and
          increment/decrement of integer counters.
          We call the latter type of acquisition/release "fast path".
          Use of "fast path" reduces the size of critical section associated
          with MDL_lock::m_rwlock lock in the common case and thus increases
          scalability.
          The amount by which acquisition/release of specific type
          "unobtrusive" lock increases/decreases packed counter in
          MDL_lock::m_fast_path_state is returned by this function.
B) "obtrusive" lock types
            1) Granted or pending lock of those type is incompatible with
               some other types of locks or with itself.
            2) Not common for DML operations
          These locks have to be always acquired involving manipulations on
          m_waiting/m_granted bitmaps/lists, i.e. we have to use "slow path"
          for them. Moreover in the presence of active/pending locks from
          "obtrusive" set we have to acquire using "slow path" even locks of
          "unobtrusive" type.

7、MDL_request类

也就是通过语句解析后需要获得的MDL LOCK的需求,然后通过这个类对象在MDL子系统 中进行MDL LOCK申请,大概包含如下一些属性

/** Type of metadata lock. */
  enum enum_mdl_type type; //需求的类型
  /** Duration for requested lock. */
  enum enum_mdl_duration duration; //持续时间
  /**
    Pointers for participating in the list of lock requests for this context.
  */
  MDL_request *next_in_list; //双向链表实现
  MDL_request **prev_in_list;
  /**
    Pointer to the lock ticket object for this lock request.
    Valid only if this lock request is satisfied.
  */
  MDL_ticket *ticket; //注意这里如果申请成功(没有等待),会指向一个实际的TICKET,否则为NULL
  /** A lock is requested based on a fully qualified name and type. */
  MDL_key key;//注意这里是一个MDL_KEY类型,主要的就是前面说的NAMESPACE+DB+OBJECT_NAME

7、MDL_key类

就是实际的NAMESPACE+DB+OBJECT_NAME,整个放到一个char数组里面,他会是MDL_LOCKMDL_REQUEST中出现
private:

  uint16 m_length;
  uint16 m_db_name_length;
  char m_ptr[MAX_MDLKEY_LENGTH];//放到了这里

8、MDL_ticket

如同门票一样,如果获取了MDL LOCK必然给MDL_request返回一张门票,如果等待则不会源码MDL_context::acquire_lock
   可以观察到。当然这也是我主要观察的一个类

/**
    Pointers for participating in the list of lock requests for this context.
    Context private.正如解释这里是context中链表链表的形成,是线程私有的
  */
  MDL_ticket *next_in_context;
  MDL_ticket **prev_in_context;
  /**
    Pointers for participating in the list of satisfied/pending requests
    for the lock. Externally accessible.正如解释这里是MDL_LOCK中链表链表的形成,是全局的
  */
  MDL_ticket *next_in_lock;
  MDL_ticket **prev_in_lock;
/**
    Context of the owner of the metadata lock ticket. Externally accessible.
    很明显这里指向了这个ticket的拥有者也就是MDL_context,它是线程的属性
  */
  MDL_context *m_ctx;

  /**
    Pointer to the lock object for this lock ticket. Externally accessible.
    很明显这里是一个指向MDL_LOCK的一个指针
  */
  MDL_lock *m_lock;

  /**
    Indicates that ticket corresponds to lock acquired using "fast path"
    algorithm. Particularly this means that it was not included into
    MDL_lock::m_granted bitmap/list and instead is accounted for by
    MDL_lock::m_fast_path_locks_granted_counter
    这里就代表了是否是FAST PATH从注释来看fast path方式不会在MDL LOCK中
    占用granted位图和链表取而代之代之的是一个统计器m_fast_path_locks_granted_counter
    这样一来开销肯定更小
  */
  bool m_is_fast_path;

  /**
    Indicates that ticket corresponds to lock request which required
    storage engine notification during its acquisition and requires
    storage engine notification after its release.
  */
  bool m_hton_notified;

9、MDL_lock

每一个MDL_key都会对应一个MDL_lock,其中包含了所谓的GRANTED链表和WAIT链表,考虑它的复杂性,可以直接参考源码注释也非常详细,这里给出我所描述的几个属性。

/** The key of the object (data) being protected. */
  MDL_key key;
/** List of granted tickets for this lock. */
  Ticket_list m_granted;
/** Tickets for contexts waiting to acquire a lock. */
  Ticket_list m_waiting;

10、MDL_context

这是整个MYSQL 线程和MDL lock子系统进行交互的一个所谓的上下文结构其中包含了很多方法和属性,我比较关注的属性如下:

/**
    If our request for a lock is scheduled, or aborted by the deadlock
    detector, the result is recorded in this class.
  */
  MDL_wait m_wait;
/**
    Lists of all MDL tickets acquired by this connection.
    这是一个不同MDL lock持续时间的一个链表数组。实际就是
    MDL_STATEMENT一个链表
    MDL_TRANSACTION一个链表
    MDL_EXPLICIT一个链表
  */
Ticket_list m_tickets[MDL_DURATION_END];
//这是一个父类指针指向子类对象,虚函数重写的典型,实际他就指向了一个线程
/*
class THD :public MDL_context_owner,
           public Query_arena,
           public Open_tables_state
*/
MDL_context_owner *m_owner;

11、MDL_wait

这个类主要是当前ticket获取状态 enum_wait_status m_wait_status;

包含: 

  • EMPTY   初始化
  • GRANTED 获取成功
  • VICTIM  死锁
  • TIMEOUT 超时
  • KILLED  KILLED

12、等待标记

PSI_stage_info MDL_key::m_namespace_to_wait_state_name[NAMESPACE_END]=
{
  {0, "Waiting for global read lock", 0},
  {0, "Waiting for tablespace metadata lock", 0},
  {0, "Waiting for schema metadata lock", 0},
  {0, "Waiting for table metadata lock", 0},
  {0, "Waiting for stored function metadata lock", 0},
  {0, "Waiting for stored procedure metadata lock", 0},
  {0, "Waiting for trigger metadata lock", 0},
  {0, "Waiting for event metadata lock", 0},
  {0, "Waiting for commit lock", 0},
  {0, "User lock", 0}, /* Be compatible with old status. */
  {0, "Waiting for locking service lock", 0},
  {0, "Waiting for backup lock", 0},
  {0, "Waiting for binlog lock", 0}
};

三、增加MDL LOCK打印函数

研究MDL LOCK锁最好的方式当然是能够获取MDL 加锁、升级、降级的流程,因为源码太庞大了,不可能面面俱到
虽然5.7加入了下面方式查看

  • UPDATE performance_schema.setup_consumers SET ENABLED = 'YES' WHERE NAME ='global_instrumentation';
  • UPDATE performance_schema.setup_instruments SET ENABLED = 'YES' WHERE NAME ='wait/lock/metadata/sql/mdl';
  • select * from performance_schema.metadata_locks

但是进行MDL LOCK的查看,如果要观察一个语句到底获取了哪些MDL LOCK还是显得无力所以笔者在mdl.cc中加入了一个函数原型如下

  • /*p_ticket in parameter*/
  • int my_print_ticket(const MDL_ticket* p_ticket)

并且在mdl_ticket类中增加了这个函数原型为友元函数,否则私有成员获取不到,而给出的公有方法比较繁杂
friend int my_print_ticket(const MDL_ticket* p_ticket);

主要获取MDL LOCK的如下信息打印到mysql err日志中:
线程id 通过p_ticket->m_ctx->get_thd(); 获取
mdl lock database name 通过p_ticket->m_lock->key.db_name()获取
mdl lock object name 通过p_ticket->m_lock->key.name()获取
mdl lock namespace 通过p_ticket->m_lock->key.mdl_namespace()获取
mdl lock fast path 通过p_ticket->m_is_fast_path获取判断是则输出否则不输出
mdl lock type 通过p_ticket->m_type获取
mdl lock duration 通过p_ticket->m_duration获取

输出信息如下:

2017-08-03T07:34:21.720583Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T07:34:21.720601Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T07:34:21.720619Z 3 [Note] (-->MDL PRINT) OBJ_name is:test
2017-08-03T07:34:21.720637Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T07:34:21.720655Z 3 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T07:34:21.720673Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_WRITE(SW)
2017-08-03T07:34:21.720692Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION

实际上和metadata_locks中的信息差不多,这是我这里的Thread id show processlist出来的id,但是我可以获得
锁获取的历史信息,我这里同时没有 LOCK_STATUS: GRANTED,但是可以在MDL_context::acquire_lock 逻辑上可以判断出来
mysql>   select * from performance_schema.metadata_locks\G
*************************** 1. row ***************************
          OBJECT_TYPE: TABLE
        OBJECT_SCHEMA: test
          OBJECT_NAME: test
OBJECT_INSTANCE_BEGIN: 140734412907760
            LOCK_TYPE: SHARED_WRITE
        LOCK_DURATION: TRANSACTION
          LOCK_STATUS: GRANTED
               SOURCE: sql_parse.cc:6314
      OWNER_THREAD_ID: 39
       OWNER_EVENT_ID: 241

四、在合适的位置增加打印函数进行观察

既然我们要研究MDL LOCK的加锁\升级\降级、那么我们就必要找到他们的函数入口,然后在合适的位置增加打印函数进行观察,下面标示出打印位置,删除了大部分的源代码,需要参考请自行

查看源码:

1、加锁:MDL_context::acquire_lock

bool
MDL_context::acquire_lock(MDL_request *mdl_request, ulong lock_wait_timeout)
{
  if (mdl_request->ticket) //获取成功获得ticket
  {
    /*
      We have managed to acquire lock without waiting.
      MDL_lock, MDL_context and MDL_request were updated
      accordingly, so we can simply return success.
    */
    //REQUESET获取TICKET成功 此处打印
    return FALSE;
  }
  /*
    Our attempt to acquire lock without waiting has failed.
    As a result of this attempt we got MDL_ticket with m_lock
    member pointing to the corresponding MDL_lock object which
    has MDL_lock::m_rwlock write-locked.
  */
  //获取不成功加入MDL_lock 等待队列
  lock= ticket->m_lock;

  lock->m_waiting.add_ticket(ticket);

  will_wait_for(ticket); //死锁检测

  /* There is a shared or exclusive lock on the object. */
  DEBUG_SYNC(get_thd(), "mdl_acquire_lock_wait");

  find_deadlock();

  //此处打印TICKET进入了等待流程

  if (lock->needs_notification(ticket) || lock->needs_connection_check())
  {
   }
  done_waiting_for();//等待完成对死锁检测等待图进行调整去掉本等待边edge(无向图)

  //当然到这里也是通过等待后获得成功了状态为GRANTED
  DBUG_ASSERT(wait_status == MDL_wait::GRANTED);

  m_tickets[mdl_request->duration].push_front(ticket);

  mdl_request->ticket= ticket;

  mysql_mdl_set_status(ticket->m_psi, MDL_ticket::GRANTED);
  //此处打印通过等待REQUEST获得了TICKET
  return FALSE;
}

2、降级

void MDL_ticket::downgrade_lock(enum_mdl_type new_type)

void MDL_ticket::downgrade_lock(enum_mdl_type new_type)
{

  /* Only allow downgrade from EXCLUSIVE and SHARED_NO_WRITE. */
  DBUG_ASSERT(m_type == MDL_EXCLUSIVE ||
              m_type == MDL_SHARED_NO_WRITE);

//此处打印出降级前的TICKET

  if (m_hton_notified)
  {
    mysql_mdl_set_status(m_psi, MDL_ticket::POST_RELEASE_NOTIFY);
    m_ctx->get_owner()->notify_hton_post_release_exclusive(&m_lock->key);
    m_hton_notified= false;
    mysql_mdl_set_status(m_psi, MDL_ticket::GRANTED);
  }
//函数结尾答应出降级后的TICKET
}

3、升级

MDL_context::upgrade_shared_lock(MDL_ticket *mdl_ticket,enum_mdl_type new_type, ulong lock_wait_timeout)

bool
MDL_context::upgrade_shared_lock(MDL_ticket *mdl_ticket,
                                 enum_mdl_type new_type,
                                 ulong lock_wait_timeout)
{
  MDL_REQUEST_INIT_BY_KEY(&mdl_new_lock_request,
                          &mdl_ticket->m_lock->key, new_type,
                          MDL_TRANSACTION);//构造一个request

 //此处打印出来的TICKET类型

  if (acquire_lock(&mdl_new_lock_request, lock_wait_timeout)) //尝试使用新的LOCK_TYPE进行加锁
    DBUG_RETURN(TRUE);

  is_new_ticket= ! has_lock(mdl_svp, mdl_new_lock_request.ticket);

  lock= mdl_ticket->m_lock;

  //下面进行一系列对MDL_LOCK的维护并且对所谓的合并操作
  /* Code below assumes that we were upgrading to "obtrusive" type of lock. */
  DBUG_ASSERT(lock->is_obtrusive_lock(new_type));

  /* Merge the acquired and the original lock. @todo: move to a method. */
  mysql_prlock_wrlock(&lock->m_rwlock);

  if (is_new_ticket)
  {
    m_tickets[MDL_TRANSACTION].remove(mdl_new_lock_request.ticket);
    MDL_ticket::destroy(mdl_new_lock_request.ticket);
  }
 //此处打印出来的升级后TICKET类型
  DBUG_RETURN(FALSE);
}

当然我现在只是在这些地方进行了打印,以后如果需要在其他地方答应加上函数就可以了。

五、各种MDL LOCK TYPE加锁测试

1、MDL_INTENTION_EXCLUSIVE(IX)

这个锁会在很多操作的时候都会出现比如做任何一个DML/DDL 操作都会触发,实际上
DELTE/UPDATE/INSERT/FOR UPDATE等DML操作会在GLOBAL 上加IX锁 然后才会在本对象上加锁
而DDL 语句至少会在GLOBAL 上加IX锁,对象所属 SCHEMA上加IX锁,本对象加锁

下面是 DELETE 触发的 GLOABL IX MDL LOCK

2017-08-03T18:22:38.092100Z 3 [Note] Test2:open_tables_for_query()
2017-08-03T18:22:38.092205Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T18:22:38.092242Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T18:22:38.092276Z 3 [Note] (--->MDL PRINT) Namespace is:GLOBAL
2017-08-03T18:22:38.092310Z 3 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T18:22:38.092344Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_INTENTION_EXCLUSIVE(IX)
2017-08-03T18:22:38.092380Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_STATEMENT
2017-08-03T18:22:38.092551Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

下面是 ALETER 语句触发的GLOABL  IX MDL LOCK以及SCHEMA级别的MDL LOCK

2017-08-03T18:46:05.894871Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T18:46:05.894915Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T18:46:05.894948Z 3 [Note] (--->MDL PRINT) Namespace is:GLOBAL
2017-08-03T18:46:05.894980Z 3 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T18:46:05.895012Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_INTENTION_EXCLUSIVE(IX)
2017-08-03T18:46:05.895044Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_STATEMENT
2017-08-03T18:46:05.895076Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

2017-08-03T18:46:05.895116Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T18:46:05.895147Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T18:46:05.895206Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T18:46:05.895243Z 3 [Note] (-->MDL PRINT) OBJ_name is:
2017-08-03T18:46:05.895276Z 3 [Note] (--->MDL PRINT) Namespace is:SCHEMA
2017-08-03T18:46:05.895325Z 3 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T18:46:05.895357Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_INTENTION_EXCLUSIVE(IX)
2017-08-03T18:46:05.895390Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T18:46:05.895421Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

所以这个MDL LOCK 无所不在,而只有是否兼容问题,如果不兼容则堵塞。SCOPED 的IX类型一般都是兼容的除非遇到
S类型

2、MDL_SHARED(S)

这把锁一般用在flush tables with read lock中

mysql> flush tables with read lock;
Query OK, 0 rows affected (0.01 sec)

2017-08-03T18:19:11.603911Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T18:19:11.603947Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T18:19:11.603971Z 3 [Note] (--->MDL PRINT) Namespace is:GLOBAL
2017-08-03T18:19:11.603994Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED(S)
2017-08-03T18:19:11.604045Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_EXPLICIT
2017-08-03T18:19:11.604073Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T18:19:11.604133Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T18:19:11.604156Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T18:19:11.604194Z 3 [Note] (--->MDL PRINT) Namespace is:COMMIT
2017-08-03T18:19:11.604217Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED(S)
2017-08-03T18:19:11.604240Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_EXPLICIT
2017-08-03T18:19:11.604310Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

我们注意到其namspace为GLOBAL和COMMIT显然他们是SCOPED LOCK,他们的TYPE为S,那么很显然根据兼容性原则
SCOPED 的MDL IX和MDL S 不兼容, flush tables with read lock; 就会堵塞所有DELTE/UPDATE/INSERT/FOR UPDATE等DML和DDL操作(因为这些操作都需要GLOBAL MDL IX锁)

3、MDL_SHARED_HIGH_PRIO(SH)

这个锁基本上大家也是经常用到只是没感觉到而已,比如我们一般desc操作

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SH        | +   +   +   +    +    +   +    +    +    -  |
mysql> desc test.testsort10;

2017-08-03T19:06:05.843277Z 4 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T19:06:05.843324Z 4 [Note] (>MDL PRINT) Thread id is 4:
2017-08-03T19:06:05.843359Z 4 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:06:05.843392Z 4 [Note] (-->MDL PRINT) OBJ_name is:testsort10
2017-08-03T19:06:05.843425Z 4 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:06:05.843456Z 4 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T19:06:05.843506Z 4 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_HIGH_PRIO(SH)
2017-08-03T19:06:05.843538Z 4 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:06:05.843570Z 4 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

这中类型的优先级比较高,但是其和X不兼容。也很好理解比如在rename 阶段肯定不能进行desc操作。

4、MDL_SHARED_READ(SR)

这把锁一般用在非当前读取的select中

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SR        | +   +   +   +    +          +      +        +    -    -  |
mysql> select * from test.testsort10 limit 1;

2017-08-03T19:13:52.338764Z 4 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T19:13:52.338813Z 4 [Note] (>MDL PRINT) Thread id is 4:
2017-08-03T19:13:52.338847Z 4 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:13:52.338883Z 4 [Note] (-->MDL PRINT) OBJ_name is:testsort10
2017-08-03T19:13:52.338917Z 4 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:13:52.338950Z 4 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T19:13:52.339025Z 4 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_READ(SR)
2017-08-03T19:13:52.339062Z 4 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:13:52.339097Z 4 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

这里还是要提及一下平时我们偶尔会出现select也堵住的情况(比如DDL的某个阶段需要对象MDL X锁)。我们不得不抱怨
MYSQL居然会堵塞select其实这里也就是object mdl lock X 和SR 不兼容的问题(参考前面的兼容矩阵)。

5、MDL_SHARED_WRITE(SW)

这把锁一般用于DELTE/UPDATE/INSERT/FOR UPDATE等操作对table的加锁(当前读),不包含DDL操作,但是要注意DML操作实际上会有一个GLOBAL的IX的锁,前面已经提及过了,这把锁只是对象上的

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SW        | +   +   +   +    +    +   -    -    -    -  |
mysql> select * from test.testsort10 limit 1 for update;

2017-08-03T19:25:41.218428Z 4 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T19:25:41.218461Z 4 [Note] (>MDL PRINT) Thread id is 4:
2017-08-03T19:25:41.218493Z 4 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:25:41.218525Z 4 [Note] (-->MDL PRINT) OBJ_name is:testsort10
2017-08-03T19:25:41.218557Z 4 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:25:41.218588Z 4 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T19:25:41.218620Z 4 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_WRITE(SW)
2017-08-03T19:25:41.218677Z 4 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:25:41.218874Z 4 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

6、MDL_SHARED_WRITE_LOW_PRIO(SWL)

这把锁很少用到源码注释只有

Used by DML statements modifying
tables and using the LOW_PRIORITY clause

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SWLP      | +   +   +   +    +    +   -    -    -    -  |
mysql> update  LOW_PRIORITY  test.testsort10 set id1=1000 where id1= 96282;

2017-08-03T19:32:47.433507Z 4 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T19:32:47.433521Z 4 [Note] (>MDL PRINT) Thread id is 4:
2017-08-03T19:32:47.433533Z 4 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:32:47.433547Z 4 [Note] (-->MDL PRINT) OBJ_name is:testsort10
2017-08-03T19:32:47.433560Z 4 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:32:47.433572Z 4 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T19:32:47.433594Z 4 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_WRITE_LOW_PRIO(SWL)
2017-08-03T19:32:47.433607Z 4 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:32:47.433620Z 4 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

7、MDL_SHARED_UPGRADABLE(SU)

这把锁一般在ALTER TABLE语句中用到,他可以升级为SNW, SNRW,X,同时至少X锁也可以降级为SU
实际上在INNODB ONLINE DDL中非常依赖于他,DML(SW)和SELECT(SR)都不会堵塞

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SU        | +   +   +   +    +    -   +    -    -    -  |

我们有必要研究一下他的兼容性,可以看到 OBJECT LOCK中(SELECT)SR (DML)SW都是允许的,而在SCOPED LOCK中
虽然DML DDL都会在GLOBAL 上锁但是其类型都是IX所以这个SU锁不堵塞DML/SELECT 读写操作进入
INNODB引擎层,它是ONLINE DDL的根基,如果不兼容你都进入不了INNODB引擎层,更谈不上什么ONLINE
DDL,注意我这里说的是ALGORITHM=INPLACE 并且不设置LOCK

(For DDL operations with LOCK=DEFAULT, or with the LOCK clause omitted, MySQL uses the lowest level
of locking that is available for that kind of operation, allowing concurrent queries, DML, or both wherever
possible. This is the setting to use when making pre-planned, pre-tested changes that you know will not
cause any availability problems based on the workload for that table
When an operation on the primary key uses ALGORITHM=INPLACE, even though the data is still copied, it
is more efficient than using ALGORITHM=COPY because:
? No undo logging or associated redo logging is required for ALGORITHM=INPLACE. These operations add
overhead to DDL statements that use ALGORITHM=COPY.
? The secondary index entries are pre-sorted, and so can be loaded in order.
? The change buffer is not used, because there are no random-access inserts into the secondary indexes.
)

如下面的语句

mysql>  alter table testsort12 add column it int not null;
Query OK, 0 rows affected (6.27 sec)
Records: 0  Duplicates: 0  Warnings: 0

简单的分析一下:

2017-08-03T19:46:54.781453Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T19:46:54.781487Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T19:46:54.781948Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:46:54.781990Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T19:46:54.782026Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:46:54.782060Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_UPGRADABLE(SU)
2017-08-03T19:46:54.782096Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:46:54.782175Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T19:46:54.803898Z 3 [Note] (upgrade_shared_lock)THIS MDL LOCK will upgrade
2017-08-03T19:46:54.804201Z 3 [Note] (upgrade_shared_lock)THIS MDL LOCK  upgrade TO
2017-08-03T19:46:54.804240Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T19:46:54.804254Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:46:54.804267Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T19:46:54.804280Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:46:54.804293Z 3 [Note] (----->MDL PRINT) Mdl type :MDL_EXCLUSIVE(X)
2017-08-03T19:46:54.804306Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:46:54.804319Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T19:46:54.855563Z 3 [Note] (downgrade_lock)THIS MDL LOCK will downgrade
2017-08-03T19:46:54.855693Z 3 [Note] (downgrade_lock) to this MDL lock
2017-08-03T19:46:54.855706Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T19:46:54.855717Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:46:54.856053Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T19:46:54.856069Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:46:54.856082Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_UPGRADABLE(SU)
2017-08-03T19:46:54.856094Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:46:54.856214Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T19:47:00.260166Z 3 [Note] (upgrade_shared_lock)THIS MDL LOCK will upgrade
2017-08-03T19:47:00.304057Z 3 [Note] (upgrade_shared_lock)THIS MDL LOCK  upgrade TO
2017-08-03T19:47:00.304090Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T19:47:00.304105Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:47:00.304119Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T19:47:00.304132Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:47:00.304181Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_EXCLUSIVE(X)
2017-08-03T19:47:00.304196Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:47:00.304211Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T19:47:01.032329Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!

首先获得testsort12表上的

2017-08-03T19:46:54.781487 获得 MDL_SHARED_UPGRADABLE(SU)
2017-08-03T19:46:54.804293 升级 MDL_EXCLUSIVE(X)
2017-08-03T19:46:54.855563 降级 MDL_SHARED_UPGRADABLE(SU)
2017-08-03T19:47:00.304057 升级 MDL_EXCLUSIVE(X)

因为不管如何这个alter操作还是比较费时的,从时间我们看到2017-08-03T19:46:54降级完成到2017-08-03T19:47:00这段时间
实际上是最耗时的实际上这里就是实际的COPY操作,但是这个过程实际在MDL SU模式下所以不会堵塞DML/SELECT操作。
这里再给大家提个醒所谓的ONLINE DDL只是在COPY阶段不堵塞DML/SELECT操作,还是尽量在数据库压力小的时候,
比如如果有DML没有提交或者SELECT没有做完这个时候SW SR必然堵塞X,而X能够堵塞一切且为高优先级。这样导致
的现象就是由于DML未提交堵塞DDL操作而DDL操作堵塞一切操作,基本对于这个TABLE的表全部堵塞。

而对于ALGORITHM=COPY 其他部分差不多,但是在COPY阶段用的是SNW锁,接下来我就先来看看SNW锁

8、MDL_SHARED_NO_WRITE(SNW)

SU可以升级为SNW而SNW可以升级为X,如前面所提及用于ALGORITHM=COPY 中,保护数据的一致性。

兼容性:

Request  |  Granted requests for lock                  
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SNW       | +   +   +   -    -    -   +    -    -    -  |

可以看到SR可以但是SW不行,当然也就堵塞了DML(SW)而SELECT(SR)不会堵塞,下面我只是给出了关键部分
mysql>  alter table testsort12 add column ik int not null, ALGORITHM=COPY  ;

2017-08-03T20:07:58.413215Z 3 [Note] (upgrade_shared_lock)THIS MDL LOCK  upgrade TO
2017-08-03T20:07:58.413241Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T20:07:58.413257Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T20:07:58.413273Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T20:07:58.413292Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T20:07:58.413308Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_NO_WRITE(SNW)
2017-08-03T20:07:58.413325Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T20:07:58.413341Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T20:08:25.392006Z 3 [Note] (upgrade_shared_lock)THIS MDL LOCK  upgrade TO
2017-08-03T20:08:25.392024Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T20:08:25.392086Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T20:08:25.392159Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T20:08:25.392199Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T20:08:25.392214Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_EXCLUSIVE(X)
2017-08-03T20:08:25.392228Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T20:08:25.392242Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

2017-08-03T20:07:58.413308 获得了MDL_SHARED_NO_WRITE(SNW)
2017-08-03T20:08:25.392006 升级为MDL_EXCLUSIVE(X)

这2017-08-03T20:07:58.413308到2017-08-03T20:08:25.392006就是实际COPY的时间,可见整个COPY期间只能DML
而不能SELECT,也是ALGORITHM=COPY和ALGORITHM=INPLACE一个关键区别。

9、MDL_SHARED_READ_ONLY(SRO)

用于LOCK TABLES READ 语句

兼容性如下

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SRO       | +   +   +   -    -    +   +    +    -    -  |

堵塞DML(SW)但是SELECT(SR)还是可以的。

mysql> lock table testsort12 read;
Query OK, 0 rows affected (0.01 sec)
2017-08-03T21:08:27.267947Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T21:08:27.267979Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T21:08:27.268009Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T21:08:27.268040Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T21:08:27.268070Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T21:08:27.268113Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_READ_ONLY(SRO)
2017-08-03T21:08:27.268145Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T21:08:27.268175Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

10、MDL_SHARED_NO_READ_WRITE(SNRW)

用于LOCK TABLES WRITE语句

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      SNRW      | +   +   -   -    -    -   -    -    -    -  |

可以看到DML(SW)和SELECT(SR)都被堵塞只有SH还可以,还可以DESC(SH) 。

mysql> lock table testsort12 write;
Query OK, 0 rows affected (0.00 sec)
2017-08-03T21:13:07.113347Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T21:13:07.113407Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T21:13:07.113435Z 3 [Note] (--->MDL PRINT) Namespace is:GLOBAL
2017-08-03T21:13:07.113458Z 3 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T21:13:07.113482Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_INTENTION_EXCLUSIVE(IX)
2017-08-03T21:13:07.113505Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_STATEMENT
2017-08-03T21:13:07.113604Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T21:13:07.113637Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T21:13:07.113660Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T21:13:07.113681Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T21:13:07.113703Z 3 [Note] (-->MDL PRINT) OBJ_name is:
2017-08-03T21:13:07.113725Z 3 [Note] (--->MDL PRINT) Namespace is:SCHEMA
2017-08-03T21:13:07.113746Z 3 [Note] (---->MDL PRINT) Fast path is:(Y)
2017-08-03T21:13:07.113768Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_INTENTION_EXCLUSIVE(IX)
2017-08-03T21:13:07.113791Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T21:13:07.113813Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY
2017-08-03T21:13:07.113842Z 3 [Note] (acquire_lock)THIS MDL LOCK acquire ok!
2017-08-03T21:13:07.113865Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T21:13:07.113887Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T21:13:07.113922Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T21:13:07.113945Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T21:13:07.113975Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_SHARED_NO_READ_WRITE(SNRW)
2017-08-03T21:13:07.113998Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T21:13:07.114021Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

除此之外lock table 还需要GLOBAL和SCHEMA上的IX锁,换句话说flush tables with read lock; 会堵塞lock table testsort12 write;但是lock table testsort12 read 却不会堵塞。

11、MDL_EXCLUSIVE(X)

用于各种DDL操作,注释为CREATE/DROP/RENAME TABLE操作,实际上基本全部的DDL都会涉及到这个锁,如上面分析的
add column操作,但是持续时间一般比较短暂。

兼容性:

Request  |  Granted requests for lock                  |
        type    | S  SH  SR  SW  SWLP  SU  SRO  SNW  SNRW  X  |
      ----------+---------------------------------------------+
      X         | -   -   -   -    -    -   -    -    -    -  |

没有上面意外堵塞一切,也被一切所堵塞
比如刚才的add column操作

2017-08-03T19:46:54.804240Z 3 [Note] (>MDL PRINT) Thread id is 3:
2017-08-03T19:46:54.804254Z 3 [Note] (->MDL PRINT) DB_name is:test
2017-08-03T19:46:54.804267Z 3 [Note] (-->MDL PRINT) OBJ_name is:testsort12
2017-08-03T19:46:54.804280Z 3 [Note] (--->MDL PRINT) Namespace is:TABLE
2017-08-03T19:46:54.804293Z 3 [Note] (----->MDL PRINT) Mdl type is:MDL_EXCLUSIVE(X)
2017-08-03T19:46:54.804306Z 3 [Note] (------>MDL PRINT) Mdl  duration is:MDL_TRANSACTION
2017-08-03T19:46:54.804319Z 3 [Note] (------->MDL PRINT) Mdl  status is:EMPTY

六、源码注释部分

enum enum_mdl_type {
  /*
    An intention exclusive metadata lock. Used only for scoped locks.
    Owner of this type of lock can acquire upgradable exclusive locks on
    individual objects.
    Compatible with other IX locks, but is incompatible with scoped S and
    X locks.
  */
  MDL_INTENTION_EXCLUSIVE= 0,
  /*
    A shared metadata lock.
    To be used in cases when we are interested in object metadata only
    and there is no intention to access object data (e.g. for stored
    routines or during preparing prepared statements).
    We also mis-use this type of lock for open HANDLERs, since lock
    acquired by this statement has to be compatible with lock acquired
    by LOCK TABLES ... WRITE statement, i.e. SNRW (We can't get by by
    acquiring S lock at HANDLER ... OPEN time and upgrading it to SR
    lock for HANDLER ... READ as it doesn't solve problem with need
    to abort DML statements which wait on table level lock while having
    open HANDLER in the same connection).
    To avoid deadlock which may occur when SNRW lock is being upgraded to
    X lock for table on which there is an active S lock which is owned by
    thread which waits in its turn for table-level lock owned by thread
    performing upgrade we have to use thr_abort_locks_for_thread()
    facility in such situation.
    This problem does not arise for locks on stored routines as we don't
    use SNRW locks for them. It also does not arise when S locks are used
    during PREPARE calls as table-level locks are not acquired in this
    case.
  */
  MDL_SHARED,
  /*
    A high priority shared metadata lock.
    Used for cases when there is no intention to access object data (i.e.
    data in the table).
    "High priority" means that, unlike other shared locks, it is granted
    ignoring pending requests for exclusive locks. Intended for use in
    cases when we only need to access metadata and not data, e.g. when
    filling an INFORMATION_SCHEMA table.
    Since SH lock is compatible with SNRW lock, the connection that
    holds SH lock lock should not try to acquire any kind of table-level
    or row-level lock, as this can lead to a deadlock. Moreover, after
    acquiring SH lock, the connection should not wait for any other
    resource, as it might cause starvation for X locks and a potential
    deadlock during upgrade of SNW or SNRW to X lock (e.g. if the
    upgrading connection holds the resource that is being waited for).
  */
  MDL_SHARED_HIGH_PRIO,
  /*
    A shared metadata lock for cases when there is an intention to read data
    from table.
    A connection holding this kind of lock can read table metadata and read
    table data (after acquiring appropriate table and row-level locks).
    This means that one can only acquire TL_READ, TL_READ_NO_INSERT, and
    similar table-level locks on table if one holds SR MDL lock on it.
    To be used for tables in SELECTs, subqueries, and LOCK TABLE ... READ
    statements.
  */
  MDL_SHARED_READ,
  /*
    A shared metadata lock for cases when there is an intention to modify
    (and not just read) data in the table.
    A connection holding SW lock can read table metadata and modify or read
    table data (after acquiring appropriate table and row-level locks).
    To be used for tables to be modified by INSERT, UPDATE, DELETE
    statements, but not LOCK TABLE ... WRITE or DDL). Also taken by
    SELECT ... FOR UPDATE.
  */
  MDL_SHARED_WRITE,
  /*
    A version of MDL_SHARED_WRITE lock which has lower priority than
    MDL_SHARED_READ_ONLY locks. Used by DML statements modifying
    tables and using the LOW_PRIORITY clause.
  */
  MDL_SHARED_WRITE_LOW_PRIO,
  /*
    An upgradable shared metadata lock which allows concurrent updates and
    reads of table data.
    A connection holding this kind of lock can read table metadata and read
    table data. It should not modify data as this lock is compatible with
    SRO locks.
    Can be upgraded to SNW, SNRW and X locks. Once SU lock is upgraded to X
    or SNRW lock data modification can happen freely.
    To be used for the first phase of ALTER TABLE.
  */
  MDL_SHARED_UPGRADABLE,
  /*
    A shared metadata lock for cases when we need to read data from table
    and block all concurrent modifications to it (for both data and metadata).
    Used by LOCK TABLES READ statement.
  */
  MDL_SHARED_READ_ONLY,
  /*
    An upgradable shared metadata lock which blocks all attempts to update
    table data, allowing reads.
    A connection holding this kind of lock can read table metadata and read
    table data.
    Can be upgraded to X metadata lock.
    Note, that since this type of lock is not compatible with SNRW or SW
    lock types, acquiring appropriate engine-level locks for reading
    (TL_READ* for MyISAM, shared row locks in InnoDB) should be
    contention-free.
    To be used for the first phase of ALTER TABLE, when copying data between
    tables, to allow concurrent SELECTs from the table, but not UPDATEs.
  */
  MDL_SHARED_NO_WRITE,
  /*
    An upgradable shared metadata lock which allows other connections
    to access table metadata, but not data.
    It blocks all attempts to read or update table data, while allowing
    INFORMATION_SCHEMA and SHOW queries.
    A connection holding this kind of lock can read table metadata modify and
    read table data.
    Can be upgraded to X metadata lock.
    To be used for LOCK TABLES WRITE statement.
    Not compatible with any other lock type except S and SH.
  */
  MDL_SHARED_NO_READ_WRITE,
  /*
    An exclusive metadata lock.
    A connection holding this lock can modify both table's metadata and data.
    No other type of metadata lock can be granted while this lock is held.
    To be used for CREATE/DROP/RENAME TABLE statements and for execution of
    certain phases of other DDL statements.
  */
  MDL_EXCLUSIVE,
  /* This should be the last !!! */
  MDL_TYPE_END};

/** Duration of metadata lock. */

enum enum_mdl_duration {
  /**
    Locks with statement duration are automatically released at the end
    of statement or transaction.
  */
  MDL_STATEMENT= 0,
  /**
    Locks with transaction duration are automatically released at the end
    of transaction.
  */
  MDL_TRANSACTION,
  /**
    Locks with explicit duration survive the end of statement and transaction.
    They have to be released explicitly by calling MDL_context::release_lock().
  */
  MDL_EXPLICIT,
  /* This should be the last ! */
  MDL_DURATION_END };

/**
    Object namespaces.
    Sic: when adding a new member to this enum make sure to
    update m_namespace_to_wait_state_name array in mdl.

    Different types of objects exist in different namespaces
     - GLOBAL is used for the global read lock.
     - TABLESPACE is for tablespaces.
     - SCHEMA is for schemas (aka databases).
     - TABLE is for tables and views.
     - FUNCTION is for stored functions.
     - PROCEDURE is for stored procedures.
     - TRIGGER is for triggers.
     - EVENT is for event scheduler events.
     - COMMIT is for enabling the global read lock to block commits.
     - USER_LEVEL_LOCK is for user-level locks.
     - LOCKING_SERVICE is for the name plugin RW-lock service
    Note that although there isn't metadata locking on triggers,
    it's necessary to have a separate namespace for them since
    MDL_key is also used outside of the MDL subsystem.
    Also note that requests waiting for user-level locks get special
    treatment - waiting is aborted if connection to client is lost.
  */
  enum enum_mdl_namespace { GLOBAL=0,
                            TABLESPACE,
                            SCHEMA,
                            TABLE,
                            FUNCTION,
                            PROCEDURE,
                            TRIGGER,
                            EVENT,
                            COMMIT,
                            USER_LEVEL_LOCK,
                            LOCKING_SERVICE,
                            BACKUP,
                            BINLOG,
                            /* This should be the last ! */
                            NAMESPACE_END };

以上就是MYSQL METADATA LOCK(MDL LOCK) 理论及加锁类型测试的详细内容,更多关于MYSQL METADATA LOCK(MDL LOCK)的资料请关注我们其它相关文章!

(0)

相关推荐

  • MySQL表结构变更你不可不知的Metadata Lock详解

    前言 想必玩过mysql的人对Waiting for table metadata lock肯定不会陌生,一般都是进行alter操作时被堵住了,导致了我们在show processlist 时,看到线程的状态是在等metadata lock.本文会对MySQL表结构变更的Metadata Lock进行详细的介绍. 在线上进行DDL操作时,相对于其可能带来的系统负载,其实,我们最担心的还是MDL其可能导致的阻塞问题. 一旦DDL操作因获取不到MDL被阻塞,后续其它针对该表的其它操作都会被阻塞.典型

  • MYSQL METADATA LOCK(MDL LOCK)MDL锁问题分析

    一.前言 MYSQL中MDL锁一直是一个比较让人比较头疼的问题,我们谈起锁一般更加倾向于INNODB下层的gap lock.next key lock.row lock等,因为它很好理解,也很好观察,而对于MDL LOCK却了解得很少,因为它实在不好观察,只有出现问题查看show processlist勉强可以看到 简单的所谓的Waiting for table metadata lock之类的状态,其实MDL LOCK是MYSQL上层一个非常复杂的子系统,有自己的死锁检测机制 (无向图?)而大

  • 浅谈MySQL next-key lock 加锁范围

    前言 某天,突然被问到 MySQL 的 next-key lock,我瞬间的反应就是: 这都是啥啥啥??? 这一个截图我啥也看不出来呀? 仔细一看,好像似曾相识,这不是<MySQL 45 讲>里面的内容么? 什么是 next-key lock A next-key lock is a combination of a record lock on the index record and a gap lock on the gap before the index record. 官网的解释大

  • MySQL出现Waiting for table metadata lock的原因方法

    MySQL在进行alter table等DDL操作时,有时会出现Waiting for table metadata lock的等待场景.而且,一旦alter table TableA的操作停滞在Waiting for table metadata lock的状态,后续对TableA的任何操作(包括读)都无法进行,因为他们也会在Opening tables的阶段进入到Waiting for table metadata lock的锁等待队列.如果是产品环境的核心表出现了这样的锁等待队列,就会造成

  • PHP+MySQL高并发加锁事务处理问题解决方法

    本文实例讲述了PHP+MySQL高并发加锁事务处理问题解决方法.分享给大家供大家参考,具体如下: 1.背景: 现在有这样的需求,插入数据时,判断test表有无username为'mraz'的数据,无则插入,有则提示"已插入",目的就是想只插入一条username为'mraz'的记录. 2.一般程序逻辑如下: $conn = mysqli_connect('127.0.0.1', 'root', '111111') or die(mysqli_error()); mysqli_selec

  • MySQL slave 延迟一列 外键检查和自增加锁

    目录 MySQL slave 延迟 外键检查和自增加锁 一.现象 二.pscak 采样 三.自增锁获取逻辑 四.方案 MySQL slave 延迟 外键检查和自增加锁 一.现象 延迟大,大事物. 表结构 无IO SQL THREAD占用CPU 100% 二.pscak 采样 采样30个点 外键检查 占70% 自增锁获取 占30% 三.自增锁获取逻辑 逻辑如下其实也是innodb_autoinc_lock_mode参数的作用 switch (lock_mode) { case AUTOINC_NO

  • MySQL 加锁控制并发的方法

    前言 锁总体可以分为乐观锁和悲观锁,简单说,乐观锁用版本号控制,悲观锁用锁控制. 下面是待会要用来测试的数据 # 添加一个user表 CREATE TABLE `users` ( `id` int(11) NOT NULL AUTO_INCREMENT COMMENT 'ID', `name` varchar(255) NOT NULL COMMENT '姓名', PRIMARY KEY (`id`) ) ENGINE=InnoDB AUTO_INCREMENT=2 DEFAULT CHARSE

  • MYSQL METADATA LOCK(MDL LOCK) 理论及加锁类型测试

    目录 MYSQL METADATA LOCK(MDL LOCK)学习 理论知识和加锁类型测试 一.初步了解 二.基础重要的数据结构(类)和概念 1.MDL TYPE 2.MDL NAMESPACE 3.实现分类 4.MDL兼容矩阵 5.MDL duration及MDL持续到什么时候 6.MDL LOCK FAST PATH(unobtrusive) OR SLOW PATH(obtrusive) 7.MDL_request类 7.MDL_key类 8.MDL_ticket 9.MDL_lock

  • 一文搞懂MySQL元数据锁(MDL)

    目录 一.什么是metadata lock 二.MDL和行锁有什么区别 三.MDL为什么会造成系统崩溃 四.MDL的生命周期有多长 五.如何快速找到阻塞源头 六.本文开始的案例最终如何解决 小结 某日,路上收到用户咨询,为了清除空间,想删除某200多G大表数据,且已经确认此表不再有业务访问,于是执行了一条命令‘delete from bigtable’,但好长时间也没删完,经过咨询后,获知drop table删除表速度快,而且能彻底释放空间,于是又在另外一个session中执行了‘drop ta

  • python中的多线程锁lock=threading.Lock()使用方式

    目录 多线程锁lock=threading.Lock()使用 疑问 解决方法 例子 python多线程中锁的概念 锁可以独立提取出来 概念 线程不安全 线程锁 多线程锁lock=threading.Lock()使用 疑问 多线程任务是同时执行的,如果我们需要先执行线程a,再执行线程b,需要怎么办呢? 解决方法 使用python的多线程锁lock. 例子 未使用多线程锁lock: def a():     for i in range(3):         print('a%d' % (i +

  • mysql慢查询优化之从理论和实践说明limit的优点

    很多时候, 我们预期查询的结果最多是1条记录数据, 那么这个时候, 最好用上limit 1,  当查到这条数据后, mysql会立即终止继续查询, 不进行更多的无用查询, 从而提升了效率. 我们来实际测试一下, 在一个拥有10万的mysql表中, 查找lily的分数(假设系统中只有1个lily, 而我们预期也只需要这条数据).为了显示出时间的差别, 我并不对表的name字段建索引. 先看看表结构: mysql> show create table tb_province; +----------

  • MySQL占用内存较大与CPU过高测试与解决办法

    更改后如下: innodb_buffer_pool_size=576M ->256M InnoDB引擎缓冲区占了大头,首要就是拿它开刀 query_cache_size=100M ->16M 查询缓存 tmp_table_size=102M ->64M 临时表大小 key_buffer_size=256m ->32M 重启mysql服务后,虚拟内存降到200以下. 另外mysql安装目录下有几个文件:my-huge.ini .my-large.ini.my-medium.ini..

  • mysql慢查询操作实例分析【开启、测试、确认等】

    本文实例讲述了mysql慢查询操作.分享给大家供大家参考,具体如下: mysql有些sql会执行很慢,有可能造成服务器负载飙升 首先查询 确定影响负载的是mysql ,使用top命令,ps命令等 其次,进入MySQL,使用show full processlist查询执行中的sql语句,看看问题,使用explain 命令 查看状态 最后找出sql语句杀死或者优化 centos7上面安装mariadb服务 yum -y install mariadb-server mariadb-devel 开启

  • MySQL的从库Seconds_Behind_Master延迟总结

    目录 MySQL从库Seconds_Behind_Master延迟总结 一.延迟分类 1.第一类(成服务器有较高的负载) 2.第二类(不会造成服务器有较高的负载) 二.相关测试 1.Innodb层的行锁造成的延迟 2.MySQL层的MDL LOCK造成的延迟 三.总结 MySQL从库Seconds_Behind_Master延迟总结 一.延迟分类 延迟我们可将其分为两类: 1.第一类(成服务器有较高的负载) 这一类延迟情况可能造成服务器有较高的负载,可能是CPU/IO的负载.因为从库在实际执行E

  • 详细分析mysql MDL元数据锁

    前言: 当你在MySQL中执行一条SQL时,语句并没有在你预期的时间内执行完成,这时候我们通常会登陆到MySQL数据库上查看是不是出了什么问题,通常会使用的一个命令就是 show processlist,看看有哪些session,这些session在做什么事情.当你看到 waiting for table metadata lock 时,那就是遇到MDL元数据锁了.本篇文章将会介绍MDL锁的产生与排查过程. 1.什么是MDL锁 MDL全称为metadata lock,即元数据锁.MDL锁主要作用

  • 详谈innodb的锁(record,gap,Next-Key lock)

    Record lock单条索引记录上加锁,record lock锁住的永远是索引,而非记录本身,即使该表上没有任何索引,那么innodb会在后台创建一个隐藏的聚集主键索引,那么锁住的就是这个隐藏的聚集主键索引.所以说当一条sql没有走任何索引时,那么将会在每一条聚集索引后面加X锁,这个类似于表锁,但原理上和表锁应该是完全不同的. Gap lock在索引记录之间的间隙中加锁,或者是在某一条索引记录之前或者之后加锁,并不包括该索引记录本身.gap lock的机制主要是解决可重复读模式下的幻读问题,关

随机推荐