Ongoing MariaDB development: filtering and rewrites in mysqlbinlog

The main focus of MariaDB staff has been the MariaDB 5.1.38 release in recent weeks, but this doesn’t mean that we’ve abandoned everything else for it. There are several non-release projects going on, one of which is adding binlog filtering and markup capabilities.

In order to see how the new features fit in, let’s first look at what binlog filtering options are already present in MySQL (and so, MariaDB):

kind Master Slave mysqlbinlog
DB-level filtering –binlog-do-db
–binlog-ignore-db
–replicate-do-db=db
–replicate-ignore-db=db
–database=dbname
Table-level filtering
-
–replicate-do-table=db.tbl
–replicate-ignore-table=db.tbl
–replicate-wild-do-table=pattern
–replicate-wild-ignore-table=pattern
-
Database name rewrite
-
–replicate-rewrite-db=”from->to”
-
Statement-verb filtering
-
-
-

As long as MySQL had only statement-based replication, one could work around the blank space in mysqlbinlog column by processing mysqlbinlog output with perl/awk/etc scripts. With Row-Based Replication, mysqlbinlog’s output contains events that look like this:

BINLOG '
vjrjShMBAAAAJwAAAPcCAAAAABIAAAAAAAAAAmQyAAJ0MgABAwAB
vjrjShkBAAAAIgAAABkDAAAQABIAAAAAAAEAAf/+AgAAAA==
'/*!*/;

which practically prevents one from doing any processing on it with perl/awk or similar tools. We’ve got a request to fix this, and set to add the following filtering capabilities:

kind Master Slave mysqlbinlog
DB-level filtering –binlog-do-db
–binlog-ignore-db
–replicate-do-db=db
–replicate-ignore-db=db
–database=dbname
Table-level filtering
-
–replicate-do-table=db.tbl
–replicate-ignore-table=db.tbl
–replicate-wild-do-table=pattern
–replicate-wild-ignore-table=pattern
MWL#40
Database name rewrite
-
–replicate-rewrite-db=”from->to”
MWL#36
Statement-verb filtering
-
-
MWL#41

At this moment, MWL#36 has already been coded and pushed into mariadb-5.2 tree. The rest of the tasks will hopefully follow.

Some implementation notes

MWL#36’s --replicate-rewrite-db has the same limitations as slave’s --replicate-rewrite-db: cross-database updates and CREATE/DROP/ALTER DATABASE statements are not rewritten. We were lucky that slave’s replicate-rewrite-db had these limitations and we could follow them. The thing is, since the slave parses the queries, it is relatively easily for it to walk the parse tree and rewrite the database name wherever necessary (and thus provide handling all kinds of statements). If this was implemented on the slave, it would be very difficult to repeat in mysqlbinlog, since mysqlbinlog has no SQL parser and so is not able to reliably find references to database name in SQL statement text.

It seems we won’t be able to dodge this problem in MWL#40: Table-level filtering, though. According to the manual, replicate-ignore-table “Tells the slave thread to not replicate any statement that updates the specified table, even if any other tables might be updated by the same statement (source). In order to copy this behaviour, mysqlbinlog will need to be able to tell which tables are affected by each of the statements it processes. As written in the worklog entry, so far we see three reliable ways to do that

  • Include MySQL’s SQL parser into mysqlbinlog
  • Have the master annotate the statements with easily-parseable information about which tables are updated in the statement.
  • Do not try to solve the problem on mysqlbinlog side, delay it until the point where we do understand SQL. As the first option, let the server support @@ignore_tables session variable and then let mysqlbinlog print SET ignore_table=... as the first statement in its output.

All three approaches have certain drawbacks. The first seems like an overkill and will have no potential to ever be able to work for VIEWs. The second will increase the size of binary logs and won’t work for un-annotated binary logs produced by legacy servers. The third approach requires this @@ignore_tableshack in the server and doesn’t really do filtering, which might be a nuisance when one does some additional processing on mysqlbinlog’s output … I’m still swaying.

Posted in Uncategorized on November 8th, 2009 by spetrunia | | 0 Comments

MariaDB 5.1 feature: Table Elimination

MariaDB 5.1 beta is almost out, so it’s time to cover some of its features. The biggest optimizer feature is MWL#17 Table Elimination.

The basic idea behind table elimination is that sometimes it is possible to resolve the query without even accessing some of the tables that the query refers to. One can invent many kinds of such cases, but in Table Elimination we targeted only a certain class of SQL constructs that one ends up writing when they are querying highly-normalized data.

The sample queries were drawn from “Anchor Modeling”, a database modeling technique which takes normalization to the extreme. The slides at anchor modeling website have an in-depth explanation of Anchor modeling and its merits, but the part that’s important for table elimination can be shown with an example.

Suppose the database stores information about actors, together with their names, birthdates, and ratings, where ratings can change over time:


According to anchor modeling, each attribute should go into its own table:

-- the 'anchor' table which has only synthetic primary key
create table  ac_anchor(AC_ID int primary key);

– a table for ‘name’ attribute:
create table ac_name(AC_ID int, ACNAM_name char(N),
                     primary key(AC_ID));

– a table for ‘birthdate’ attribute:
create table ac_dob(AC_ID int,
                    ACDOB_birthdate date,
                    primary key(AC_ID));

– a table for ‘rating’ attribute, which is historized:
create table ac_rating(AC_ID int,
                       ACRAT_rating int,
                       ACRAT_fromdate date,
                       primary key(AC_ID, ACRAT_fromdate));

With this approach it becomes easy to add/change/remove attributes, but this comes at a cost of added complexity in querying the data: in order to answer the simplest, select-star question of displaying actors and their current ratings one has to write outer joins:

-- Display actors, with their names and current ratings
select
  ac_anchor.AC_ID, ACNAM_Name,  ACDOB_birthdate, ACRAT_rating
from
  ac_anchor
  left join ac_name on ac_anchor.AC_ID=ac_name.AC_ID
  left join ac_dob on ac_anchor.AC_ID=ac_dob.AC_ID
  left join ac_rating on (ac_anchor.AC_ID=ac_rating.AC_ID and
                          ac_rating.ACRAT_fromdate = 
                            (select max(sub.ACRAT_fromdate)
                             from ac_rating sub where sub.AC_ID = ac_rating.AC_ID))

Apparently one won’t want to write such join every time they need to access actor’s properties, so they’ll create a view:

create view actors as
  select  ac_anchor.AC_ID, ACNAM_Name,  ACDOB_birthdate, ACRAT_rating
  from <see the select above>

which will allow one to access data as if it was stored in a regular way:

select ACRAT_rating from actors where ACNAM_name='Gary Oldman'

And this is where table elimination will be needed

Table elimination

The first thing the optimizer will do will be to merge the VIEW definition into the query and obtain

select ACRAT_rating
from
  ac_anchor
  left join ac_name on ac_anchor.AC_ID=ac_name.AC_ID
  left join ac_dob on ac_anchor.AC_ID=ac_dob.AC_ID
  left join ac_rating on (ac_anchor.AC_ID=ac_rating.AC_ID and
                          ac_rating.ACRAT_fromdate = 
                            (select max(sub.ACRAT_fromdate)
                             from ac_rating sub where sub.AC_ID = ac_rating.AC_ID))
where
 ACNAM_name=’Gary Oldman’

Now, it’s important to realize that the obtained query has a useless part (highlighted in magenta). Indeed,

  • left join ac_dob on ac_dob.AC_ID=... will produce exactly one matching record:
    • primary key(ac_dob.AC_ID) guarantees that there will be at most one match for any value of ac_anchor.AC_ID,
    • and if there won’t be a match, LEFT JOIN will generate a NULL-complemented “row”,
  • and we don’t care what the matching record is, as table ac_dob is not used anywhere else in the query

This means that the … left join ac_dob on … part can be removed from the query and this is what Table Elimination module does. The detection logic is rather smart, for example it would be able to remove the … left join ac_rating on … part as well, together with the subquery (in the above example it won’t be removed because ac_rating used in the selection list of the query). Table Elimination module can also handle nested outer joins and multi-table outer joins.

User interface

One can check that table elimination is working by looking at the output of EXPLAIN [EXTENDED] and not finding there the tables that were eliminated:


MySQL [test]> explain select ACRAT_rating from actors where ACNAM_name=’Gary Oldman’;
+—-+——————–+———–+——–+—————+———+———+———————-+——+————-+
| id | select_type        | table     | type   | possible_keys | key     | key_len | ref                  | rows | Extra       |
+—-+——————–+———–+——–+—————+———+———+———————-+——+————-+
|  1 | PRIMARY            | ac_anchor | index  | PRIMARY       | PRIMARY | 4       | NULL                 |    2 | Using index |
|  1 | PRIMARY            | ac_name   | eq_ref | PRIMARY       | PRIMARY | 4       | test.ac_anchor.AC_ID |    1 | Using where |
|  1 | PRIMARY            | ac_rating | ref    | PRIMARY       | PRIMARY | 4       | test.ac_anchor.AC_ID |    1 |             |
|  3 | DEPENDENT SUBQUERY | sub       | ref    | PRIMARY       | PRIMARY | 4       | test.ac_rating.AC_ID |    1 | Using index |
+—-+——————–+———–+——–+—————+———+———+———————-+——+————-+
4 rows in set (0.01 sec)

Note that ac_dob table is not in the output. Now let’s try getting birthdate instead:


MySQL [test]> explain select ACDOB_birthdate from actors where ACNAM_name=’Gary Oldman’;
+—-+————-+———–+——–+—————+———+———+———————-+——+————-+
| id | select_type | table     | type   | possible_keys | key     | key_len | ref                  | rows | Extra       |
+—-+————-+———–+——–+—————+———+———+———————-+——+————-+
|  1 | PRIMARY     | ac_anchor | index  | PRIMARY       | PRIMARY | 4       | NULL                 |    2 | Using index |
|  1 | PRIMARY     | ac_name   | eq_ref | PRIMARY       | PRIMARY | 4       | test.ac_anchor.AC_ID |    1 | Using where |
|  1 | PRIMARY     | ac_dob    | eq_ref | PRIMARY       | PRIMARY | 4       | test.ac_anchor.AC_ID |    1 |             |
+—-+————-+———–+——–+—————+———+———+———————-+——+————-+
3 rows in set (0.01 sec)

The ac_dob table is there while ac_rating and the subquery are gone. Now, if we just want to check the name of the actor


MySQL [test]> explain select count(*) from actors where ACNAM_name=’Gary Oldman’;
+—-+————-+———–+——–+—————+———+———+———————-+——+————-+
| id | select_type | table     | type   | possible_keys | key     | key_len | ref                  | rows | Extra       |
+—-+————-+———–+——–+—————+———+———+———————-+——+————-+
|  1 | PRIMARY     | ac_anchor | index  | PRIMARY       | PRIMARY | 4       | NULL                 |    2 | Using index |
|  1 | PRIMARY     | ac_name   | eq_ref | PRIMARY       | PRIMARY | 4       | test.ac_anchor.AC_ID |    1 | Using where |
+—-+————-+———–+——–+—————+———+———+———————-+——+————-+
2 rows in set (0.01 sec)

then it will eliminate both ac_dob and ac_rating tables.

Removing tables from a query is not expected to make the query slower, and it does not cut off any optimization opportunities, so we’ve made table elimination unconditional and don’t plan on having any kind of query hints for it.

I wanted to add an @@optimizer_switch flag anyway, just in case, but Monty was against that and eventually we have agreed that @@optimizer_switch will have table_elimination=on|off switch only in debug builds of the server.

Posted in Uncategorized on November 1st, 2009 by spetrunia | | 7 Comments