While most of the talk recently has mostly been around the new changes in MySQL 5.6 (and that is understandable), I have had lately some very interesting cases to deal with, with respect to the Metadata Locking related changes that were introduced in MySQL 5.5.3. It appears that the implications of Metadata Locking have not been covered well, and since there are still a large number of MySQL 5.0 and 5.1 installations that would upgrade or are in the process of upgrading to MySQL 5.5, I thought it necessary to discuss what these implications exactly are.

To read what Metadata Locking exactly is please read this section here in the MySQL manual.

Let’s start off with having a look at the Meta Data Locking behavior prior to MySQL 5.5.3

Metadata Locking behavior prior to MySQL 5.5.3

Prior to MySQL 5.5.3 a statement that opened a table only held meta data locks till the end of the statement and not the end of the transaction. This meant that transaction was not really isolated, because the same query could return different results if executed twice and if a DDL was executed between the query invocations. Let me give you an example via a simple test case where I will add a new column to the table while a transaction in REPEATABLE-READ isolation mode is ACTIVE.

And you can see how isolation is broken because the SELECT was not repeatable although transaction isolation level of REPEATABLE-READ was used. This behavior of versions prior to 5.5 also means that queries could be written in different order to the binary log breaking locking semantics and contrary to serialization concepts. For example take a look at the following excerpt from the binary log of a case when an UPDATE transaction is mixed with an ALTER:

Note how ALTER is logged before the UPDATE, because ALTER did not block waiting for the transaction to commit.

For the reasons described above the implementation of Metadata Locking was changed, starting MySQL 5.5.3. Let’s see how this works now.

Metadata Locking behavior starting MySQL 5.5.3

Starting with 5.5.3 DDL statements that modify the table metadata are executed in an isolated fashion consistent with transactional behavior. This means that any open transaction will hold metadata locks on the table it has accessed for as long as the transaction is open. Since an open transaction retains metadata locks on all tables that were opened by the transaction, hence any DDL operation cannot commence till all the transactions that accessed that table are open. Let’s see this in affect via a simple test case:

You can see how the ALTER blocks, because the transaction in session1 is still open and once the transaction in session1 is closed, the ALTER proceeds through successfully:

Let’s see where the ALTER spent most of its time:

So the ALTER waited on the meta data locks just after the table with the new structure had been created and populated with data but before the old table was swapped with the new one. Note that ALTER is a multi-step process, the old table is locked in shared mode and then something similar to the following steps are taken: a new table with the new structure is created and then INSERT INTO new_table SELECT * FROM old_table is done and then RENAME old_table to tmp_table, new_table to old_table and finally DROP tmp_table.
Let’s see another example, this time trying a RENAME:

And you can see that the RENAME is also blocked, because a transaction that accessed the table “test” is still open.

So we have an interesting conclusion here that the ALTER waits only at the last stages when its making changes to the table metadata, a table ALTER that alters a big table can keep executing without any hindrance, copying rows from the table with the old structure to the table with the new structure and will only wait at the last step when its about to make changes to table metadata.

Let’s see another interesting side-affect of metadata locking.

When can ALTER render the table inaccessible?

Now there is another interesting side-affect, and that is that when the ALTER comes at the state where it needs to wait for metadata locks, at that point the ALTER simply blocks any type of queries to the table, we know that writes would be blocked anyhow for the entire duration of the ALTER, but reads would be blocked as well at the time when the ALTER is waiting for metadata locks. Let’s see this in action via another test case:

And you can see that the table is blocked for any kind of operation. Let’s see the profiling information for one of the queries that was blocked to see where the query spent most of its time:

And you can see how the query spent nearly all its time waiting in the “Opening tables” state. Now this behavior with respect to ALTER making the table inaccessible in some cases is not really documented and as such I have reported a bug: http://bugs.mysql.com/bug.php?id=67647

Metadata locking behaves differently for queries that are serviced from the Query Cache, let’s see what happens in that case.

Metadata Locking and Query Cache

How does metadata locking behave with query_cache? That is an important question. If Query Cache is enabled and the SELECT can be serviced from the Query Cache then the SELECT will not block on the ALTER even though the ALTER is waiting for meta data locks. Why? Because in such a case no table open operation has to be performed. Let’s see this scenario via a test case:

The query proceeds without being blocked on anything while the RENAME is still waiting for metadata locks. Let’s see the profiling information for this query:

You can see that no table open operation was performed and hence no wait.

Does the fact that the table has already been opened and table object is in the table_cache change anything with respect to metadata locks.

Metadata Locking and Table Cache

No matter if a connection accesses a table that is already in the Table Cache, any query to a table that has a DDL operation waiting, will block. Why? Because MySQL sees that the old entries in the Table Cache have to be invalidated, and any query that accesses the table will have to reopen the modified table and there will be new entries in the Table Cache. Let’s see this phenomenon in action:

As you can see that the SELECT query still blocks, and the status counter Opened_tables is also incremented once the query finishes.

So much for the explanation, now let’s take a look at the consequences.

Consequences

The consequences of these changes in metadata locking is that, if you have some really hot tables, for example in web applications its typical to see a “sessions” table that is accessed on every request, then care should be taken when you have to ALTER the table otherwise it can easily cause a stall as many threads can get piled up waiting for table metadata lock bringing down the MySQL server or causing all the connections to get depleted.

There are some other interesting consequences as well for application that use MySQL versions prior to 5.5:

  • I remember a customer case where there is a reporting slave that daily runs a long running transaction, this transactions tends to run for hours. Now everyday one of the tables was renamed and swapped and that table was the one that is read from by the long running transaction. As the slave tried to execute the rename query it would simply block waiting for the long running transaction to finish, this would cause the slave to lag for hours waiting for the transaction to be completed, as you know that the slave is single-threaded so it cannot really apply any other event. This was never an issue when the application was using MySQL version
  • There was another interesting case this time with how Active MQ uses MySQL when in HA mode. In HA mode there are two Active MQ servers, both try to do something similar to the following sequence of events:

    When using MySQL 5.1 the second CREATE would just fail immediately with the error “ERROR 1050 (42S01): Table ‘t1’ already exists”, but because of how meta data locking works in 5.5 this is no longer the case, the second CREATE will simply block with unintended consequences. A workaround here would be to set lock_wait_timeout variable to a very low value and then execute the CREATE TABLE, this will make sure that the CREATE fails immediately (however due to a different reason):

    However, I feel that the CREATE TABLE should fail in such a case when the table already exists and there is no other DDL like a DROP table waiting to run on the same table, and as such I have reported the bug: http://bugs.mysql.com/bug.php?id=67873

10 Comments
Oldest
Newest Most Voted
Inline Feedbacks
View all comments
marc castrovinci

The above scenario is when you would see the “Waiting for table metadata lock” status, right?

I’ve encountered this issue about every time I have to do a production DDL change. After a few times fighting it, I now have a script that will kill all sleeping threads over 1 second for the database i’m working on. If not the DDL hangs on a sleeping thread, and the reads after the DDL also hang.

Patryk Pomykalski

Bug #67873 is fixed in MariaDB 5.5.29, but CREATE doesn’t wait for DROP TABLE. https://mariadb.atlassian.net/browse/MDEV-3941

Mark Callaghan

Does pt-osc need to get updated because of these changes?
https://code.launchpad.net/~percona-toolkit-dev/percona-toolkit/pt-osc-2.1.1

Ovais Tariq

Marc,

Yes when queries are waiting for metadata locks, the thread state is “Waiting for table metadata lock” in the processlist. Probably we can have a new feature in Percona Server to tackle the issue that you face during DDLs.

Ovais Tariq

Mark,

Indeed the current version of pt-osc needs to be updated because it does not currently tackle the condition where it has to wait on metadata locks, and hence I have reported the bug: https://bugs.launchpad.net/percona-toolkit/+bug/1113301

Ovais Tariq

Patryk,

Thanks, for letting me know I will test out MariaDB 5.5.29

zuoxingyu

Ovais ,i’m very interesting in why you could get the “Note how ALTER is logged before the UPDATE, because ALTER did not block waiting for the transaction to commit.” example case but i can’t.

zuoxingyu

For my test,server version : 5.1.48-community-log ,table engine=innodb
My steps :
session1 session2

mysql> start transaction;
Query OK, 0 rows affected (0.00 sec)

mysql> update t1 set id=30 where id=3;
Query OK, 1 row affected (0.00 sec)
Rows matched: 1 Changed: 1 Warnings: 0
alter table t1 add column title2 varchar(30) default ‘ook’; (hang)

mysql> commit;
Query OK, 0 rows affected (0.01 sec)
mysql> alter table t1 add column title2 varchar(30) default ‘ook’;
Query OK, 3 rows affected (24.20 sec)
Records: 3 Duplicates: 0 Warnings: 0

Events in binlog

Info
————————————————————————
Server ver: 5.1.48-community-log, Binlog ver: 4
BEGIN
use bruce; update t1 set id=30 where id=3
COMMIT /* xid=18 */
use bruce; alter table t1 add column title3 varchar(30) default ‘oook’

As you see,alter table is logged after update,that’s correct.
How can i get the same result as you ? Is there something wrong in my steps?

Ovais Tariq

Hi zuoxingyu,

If you follow my test case you will see that I have started a transaction and issued a SELECT query and not a query that would hold any row lock. The point was to show the implications of a transaction not holding metadata locks on tables that have been queried in the transaction, which causes problems by breaking isolation.

However, in your case what you are doing is that by executing an update query on the table, the transaction holds row locks on row with the id=3, which is what is preventing the ALTER from going through. So you are facing a different scenario in that you have row locks blocking the ALTER, while the post deals with metadata locks. If you can enable the InnoDB plugin on your 5.1 installation instead of using the built-in InnoDB, then you can further clarify to yourself that the ALTER in your test case is waiting on InnoDB row locks by setting innodb_lock_wait_timeout to 1 and then issuing the ALTER:

— session 1
start transaction;
select * from t1 where id=3 for update;

— session 2
set innodb_lock_wait_timeout=1;
alter table t1 engine=innodb;

And the alter will timeout after approximately a second with the following error:
ERROR 1205 (HY000): Lock wait timeout exceeded; try restarting transaction

Amar

Hi Ovais Tariq,

Could please help us in understanding better on queries could be written in different order to the binary log breaking locking semantics and contrary to serialization before MySQL 5.5.3

Thanks,
Amar