I don’t think it’ll surprise anybody if I say that MariaDB or MySQL server knows a lot more about server system variables, then just their values. Indeed, every variable can be session or global only, read-only or writable, it has an associated help text (that is printed on mysqld --help --verbose), certain variables only accept values from a given set of strings (this set of allowed values is also printed in mysqld --help --verbose since MariaDB 10.1.0), numeric variables have lower and upper range boundaries of valid values (that are never printed anywhere), and so on. I always thought it’s kind of a waste that there is no way to query this information. That could’ve been very convenient, in particular for various GUI clients — they could show the help in tooltips, validate values and so on.

But recently we’ve got our users asking for it — precisely, for system variable metadata, whether a variable is read-only, how it was set and so on. You ask for it — you got it. Let me introduce the INFORMATION_SCHEMA.SYSTEM_VARIABLES table. For every system variable it shows both its global and session values, where the global value comes from (config file or a command line, assigned from SQL, auto-configured by the server, compile-time default), the type and the scope of the variable, its default value, range of values for numeric variables, set of allowed values for ENUM/SET variables, whether a variable is read-only, whether it can be set from the command line. And a help text, of course.
It is said that a picture is worth a thousand words, so here you are:

Note that READ_ONLY only means “cannot be changed run-time”, the variable might still be writable from the command line or a config file. Here’s the list of all truly read-only variables that can not be modified at all:

You might wonder what LOG_BIN is doing in this list. It’s because on the command line you can never specify this boolean read-only variable, what you actually specify is a command-line option --log-bin that takes a string. It happens that this new SYSTEM_VARIABLES table is good at highlighting dark corners in the MariaDB/MySQL internal implementation of system variables.

Introduction

When you e.g. delete rows, these rows are just marked as deleted not really physically deleted from indexes and free space introduced is not returned to operating system for later reuse. Purge thread will physically delete index keys and rows, but still free space introduced is not returned to operating system and this operation can lead holes on page. If you have variable length rows, this could lead to situation where this free space can’t be used for new rows (if these rows are larger than old ones). User may use OPTIMIZE TABLE or ALTER TABLE <table> ENGINE=InnoDB to reconstruct the table.

Unfortunately, running OPTIMIZE TABLE against an InnoDB table stored in the shared table-space file ibdata1 does two things:

  • Makes the table’s data and indexes contiguous inside ibdata1
  • Makes ibdata1 grow because the contiguous data and index pages are appended to ibdata1

New defragmentation

In MariaDB 10.1 we have merged Facebooks defragmentation code prepared for MariaDB by Matt, Seong Uck Lee from Kakao. Only major difference to Facebooks code and Matt’s patch is the fact that in MariaDB we decided not to introduce new literals to SQL and no changes to server code. Instead we use already existing OPTIMIZE TABLE and all code changes are inside InnoDB/XtraDB storage engines. To enable this new feature you need to add following to my.cnf (this requirement is to keep the original behavior of OPTIMIZE TABLE for those users that need it).

This new defragmentation feature works inplace, thus no new tables are created and there is no need to copy data from old table to new table. Instead this feature loads n pages and tries to move records so that pages would be full of records and frees pages that are fully empty after the operation.

New configuration variables

  • innodb_defragment: Enable/disable InnoDB defragmentation. When set to FALSE, all existing defragmentation will be paused. And new defragmentation command will fail. Paused defragmentation commands will resume when this variable is set to TRUE. Default value FALSE.
  • innodb_defragment_n_pages: Number of pages considered at once when merging multiple pages to defragment. Range of 2–32 and default is 7.
  • innodb_defragment_stats_accuracy: How many defragment stats changes there are before the stats are written to persistent storage. Set to 0 meaning disable defragment stats tracking. Default 0.
  • innodb_defragment_fill_factor_n_recs:  How many records of space defragmentation should leave on the page. This variable, together with innodb_defragment_fill_factor, is introduced so defragmentation won’t pack the page too full and cause page split on the next insert on every page. The variable indicating more defragmentation gain is the one effective. Range of 1–100 and default 20.
  • innodb_defragment_fill_factor: A number between [0.7, 1] that tells defragmentation how full it should fill a page. Default is 0.9. Number below 0.7 won’t make much sense. This variable, together with innodb_defragment_fill_factor_n_recs, is introduced so defragmentation won’t pack the page too full and cause page split on the next insert on every page. The variable indicating more defragmentation gain is the one effective.
  • innodb_defragment_frequency: Do not defragment a single index more than this number of time per second.This controls the number of time defragmentation thread can request X_LOCK on an index. Defragmentation thread will check whether 1/defragment_frequency (s) has passed since it worked on this index last time, and put the index back to the queue if not enough time has passed. The actual frequency can only be lower than this given number.

New status variables

  • Innodb_defragment_compression_failures: Number of defragment re-compression failures
  • Innodb_defragment_failures: Number of defragment failures.
  • Innodb_defragment_count: Number of defragment operations.

Example

After CREATE TABLE and INSERT operations we can see following from INFORMATION_SCHEMA:

Now if we delete 3/4 of the records that will leave holes in pages and then we optimize table to execute defragmentation:

After this we can see that some pages are freed and some pages merged:

Links

WebScaleSQL Git repository https://github.com/webscalesql/webscalesql-5.6

Facebook Percona Live presentation: https://www.google.fi/url?sa=t&rct=j&q=&esrc=s&source=web&cd=2&ved=0CCQQFjAB&url=https%3A%2F%2Fwww.percona.com%2Flive%2Fmysql-conference-2014%2Fsites%2Fdefault%2Ffiles%2Fslides%2Fdefragmentation.pdf&ei=UgNKVNnZMcHhywP7qwI&usg=AFQjCNGREUpen21jCcy0bchUa6Ro83ol_A&sig2=MDZU2Ue9sX1kB9OusvdiFA

One of the most popular plugin types both in MariaDB and MySQL is INFORMATION_SCHEMA plugin type. INFORMATION_SCHEMA plugins add new tables to the INFORMATION_SCHEMA. There are lots of INFORMATION_SCHEMA plugins, because they can be used to show just anything to the user and are very easy to write.

MariaDB 10.1.1 comes with nine INFORMATION_SCHEMA plugin:

  • Feedback — shows the anonymised server usage information and can optionally send it to the configured url.
  • Locales — lists compiled-in server locales, implemented by Roberto Spadim
  • METADATA_LOCK_INFO — Lists metadata locks in the server. Implemented by Kentoku Shiba
  • QUERY_CACHE_INFO — Lists queries in the query cache. Originally by Roland Bouman
  • QUERY_RESPONSE_TIME — Shows distribution of query response times. Originally implemented in Percona
  • CLIENT_STATISTICS — part of Percona “userstat” patch
  • USER_STATISTICS — part of Percona “userstat” patch
  • INDEX_STATISTICS — part of Percona “userstat” patch
  • TABLE_STATISTICS — part of Percona “userstat” patch

Also there are many INFORMATION_SCHEMA plugins that come together with storage engines and show various information about them. InnoDB comes with 28 of such plugins. XtraDB — with 32, TokuDB — with 12. And if you google you can find many more INFORMATION_SCHEMA plugins — for example, a plugin that shows various system information or a plugin that lists all created user variables. INFORMATION_SCHEMA plugins are indeed numerous and very popular.

If you look at the these plugins, you can see that there are plugins that display some kind of a current state of something, and there are plugins that accumulate and display some statistics. For this second group of plugins it is sometimes desirable to reset this statistics — but there was no natural way for a user to do that. For status variables (as in SHOW STATUS statement) one can use FLUSH STATUS, but for plugins there was nothing similar. But now MariaDB 10.1.1 extends INFORMATION_SCHEMA plugin API by introducing reset_table callback. For example, look at the QUERY_RESPONSE_TIME plugin initialization function:

See the highlighted line — it sets the reset_table callback to the query_response_time_flush function. When this plugin is loaded, MariaDB will automatically start supporting new statement

and it will invoke this callback that will, in turn, reset query response time statistics. Similarly “userstat” tables CLIENT_STATISTICS, USER_STATISTICS, INDEX_STATISTICS, and TABLE_STATISTICS support the FLUSH statement in a similar way.

MariaDB 10.1.1 also implements another enhancement for the INFORMATION_SCHEMA plugins — the SHOW statement. Indeed, until 10.1.1 only native server INFORMATION_SCHEMA tables could have a SHOW counterpart. To query a plugin INFORMATION_SCHEMA table one would need to type a lengthy SELECT and than see how long lines wrap around in the terminal window, making it impossible to see what column each value belongs to. You all know it very well:

So we’ve introduced a SHOW statement for INFORMATION_SCHEMA plugins that is quick to type and is supposed to provide just enough columns to fit nicely on the screen:

The API is very simple, a plugin does not need to implement anything special to support this. It only needs to decide what subset of columns will be visible in the SHOW statement and specify names for this columns when declaring INFORMATION_SCHEMA table fields. For example, in the LOCALES plugin:

See, the highlighted lines specify column names for the SHOW statement and only these columns are visible in SHOW. It is, of course, a sole responsibility of the plugin writer to pick up a reasonable subset of columns so that the resulting table is not too wide but still contains enough information to be useful. If a plugin does not specify any column names for SHOW, the SHOW statement will not work for this plugin.


An inquisitive reader may note that “userstat” tables CLIENT_STATISTICS, USER_STATISTICS, INDEX_STATISTICS, and TABLE_STATISTICS supported FLUSH and SHOW also in 10.0 and in earlier versions of MariaDB. That’s right, but before 10.1.1 these tables were not plugins, and the syntax support was hard-coded into the server. Now they are plugins which, indeed, required INFORMATION_SCHEMA plugins to support FLUSH and SHOW. That’s why these extensions were implemented.