Looking Inside the MySQL 5.7 Document Store
In this blog, we’ll look at the MySQL 5.7 document store feature, and how it is implemented.
Join the DZone community and get the full member experience.
Join For FreeDocument Store
MySQL 5.7.12 is a major new release, as it contains quite a number of new features:
- Document store and "MongoDB" like NoSQL interface to JSON storage
- Protocol X / X Plugin, which can be used for asynchronous queries (I will write about it as well)
- New MySQL shell
Peter already wrote the document store overview; in this post, I will look deeper into the document store implementation. In my next post, I will demonstrate how to use document store for Internet of Things (IoT) and event logging.
Older MySQL 5.7 versions already have a JSON data type, and an ability to create virtual columns that can be indexed. The new document store feature is based on the JSON datatype.
So, what is the document store anyway? It is an add-on to a normal MySQL table with a JSON field. Let’s take a deep dive into it and see how it works.
First of all: one can interface with the document store’s collections using the X Plugin (default port: 33060). To do that:
1. Enable X Plugin and install MySQL shell.
2. Login to a shell:
mysqlsh--uri root@localhost
3. Run commands (JavaScript mode, can be switched to SQL or Python):
mysqlsh--uri root@localhost
Creating anXSession toroot@localhost:33060
Enter password:
No defaultschema selected.
Welcome toMySQL Shell1.0.3Development Preview
Copyright(c)2016,Oracle and/orits affiliates.All rights reserved.
Oracle isaregistered trademark of Oracle Corporation and/orits
affiliates.Other names may be trademarks of their respective
owners.
Type'help','h'or'?'forhelp.
Currently inJavaScript mode.Usesql toswitchtoSQL mode andexecute queries.
mysql-js>db=session.getSchema('world_x')<Schema:world_x>
mysql-js>db.getCollections()
"CountryInfo":<Collection:CountryInfo>
Now, how is the document store’s collection different from a normal table? To find out, I’ve connected to a normal MySQL shell:
mysqlworld_x
Readingtableinformationforcompletionoftableandcolumnnames
Youcanturnoffthisfeaturetogetaquickerstartupwith-A
WelcometotheMySQLmonitor.Commandsendwith;org.
YourMySQLconnectionidis2396
Serverversion:5.7.12MySQLCommunityServer(GPL)
Copyright(c)2000,2016,Oracleand/oritsaffiliates.Allrightsreserved.
OracleisaregisteredtrademarkofOracleCorporationand/orits
affiliates.Othernamesmaybetrademarksoftheirrespective
owners.
Type'help;'or'h'forhelp.Type'c'toclearthecurrentinputstatement.
mysql>showcreatetableCountryInfo
***************************1.row***************************
Table:CountryInfo
CreateTable:CREATETABLE`CountryInfo`(
`doc`jsonDEFAULTNULL,
`_id`varchar(32)GENERATEDALWAYSAS(json_unquote(json_extract(`doc`,'$._id')))STOREDNOT NULL,
PRIMARY KEY(`_id`)
)ENGINE=InnoDBDEFAULTCHARSET=utf8
1rowinset(0.00sec)
mysql>showtables;
+-------------------+
|Tables_in_world_x|
+-------------------+
|City|
|Country|
|CountryInfo|
|CountryLanguage|
+-------------------+
4rowsinset(0.00sec)
So the document store is actually an InnoDB table with one field: doc
json + Primary key, which is a generated column.
As we can also see, there are four tables in the world_x database, but db.getCollections() only shows one. So how does MySQL distinguish between a “normal” table and a “document store” table? To find out, we can enable the general query log and see which query is being executed:
$mysql-e'set global general_log=1'
$tail/var/log/general.log
2016-05-17T20:53:12.772114Z186Query SELECT table_name,COUNT(table_name)cFROM information_schema.columnsWHERE((column_name='doc'anddata_type='json')OR(column_name='_id'andgeneration_expression='json_unquote(json_extract(`doc`,''$._id''))'))ANDtable_schema='world_x'GROUP BY table_name HAVINGc=2
2016-05-17T20:53:12.773834Z186Query SHOW FULL TABLES FROM`world_x`
As you can see, every table that has a specific structure (doc JSON or specific generation_expression) is considered to be a JSON store. Now, how does MySQL translate the .find or .add constructs to actual MySQL queries? Let’s run a sample query:
mysql-js>db.getCollection("CountryInfo").find('Name= "United States"').limit(1)
"GNP":8510700,
"IndepYear":1776,
"Name":"United States",
"_id":"USA",
"demographics":{
"LifeExpectancy":77.0999984741211,
"Population":278357000
"geography":{
"Continent":"North America",
"Region":"North America",
"SurfaceArea":9363520
"government":{
"GovernmentForm":"Federal Republic",
"HeadOfState":"George W. Bush",
"HeadOfState_title":"President"
1documentinset(0.02sec)
And now, look at the slow query log again:
2016-05-17T21:02:21.213899Z186Query SELECT doc FROM`world_x`.`CountryInfo`WHERE(JSON_EXTRACT(doc,'$.Name')='United States')LIMIT1
We can verify that MySQL translates all document store commands to SQL. That also means that it is 100% transparent to the existing MySQL storage level and will work with other storage engines. Let’s verify that, just for fun:
mysql>alter table CountryInfo engine=MyISAM;
Query OK,239rows affected(0.06sec)
Records:239Duplicates:0Warnings:0
mysql-js>db.getCollection("CountryInfo").find('Name= "United States"').limit(1)
"GNP":8510700,
"IndepYear":1776,
"Name":"United States",
"_id":"USA",
"demographics":{
"LifeExpectancy":77.0999984741211,
"Population":278357000
"geography":{
"Continent":"North America",
"Region":"North America",
"SurfaceArea":9363520
"government":{
"GovernmentForm":"Federal Republic",
"HeadOfState":"George W. Bush",
"HeadOfState_title":"President"
1document inset(0.00sec)
2016-05-17T21:09:21.074726Z2399Query alter table CountryInfo engine=MyISAM
2016-05-17T21:09:41.037575Z2399Quit
2016-05-17T21:09:43.014209Z186Query SELECT doc FROM`world_x`.`CountryInfo`WHERE(JSON_EXTRACT(doc,'$.Name')='United States')LIMIT1
Worked fine!
Now, how about the performance? We can simply take the SQL query and run explain:
mysql>explain SELECT doc FROM`world_x`.`CountryInfo`WHERE(JSON_EXTRACT(doc,'$.Name')='United States')LIMIT1
***************************1.row***************************
id:1
select_type:SIMPLE
table:CountryInfo
partitions:NULL
type:ALL
possible_keys:NULL
key:NULL
key_len:NULL
ref:NULL
rows:239
filtered:100.00
Extra:Using where
1row inset,1warning(0.00sec)
Hmm, it looks like it is not using an index. That’s because there is no index on Name. Can we add one? Sure, we can add a virtual column and then index it:
mysql>altertableCountryInfoaddcolumnNamevarchar(255)
->GENERATEDALWAYSAS(json_unquote(json_extract(`doc`,'$.Name')))VIRTUAL;
QueryOK,0rowsaffected(0.12sec)
Records:0Duplicates:0Warnings:0
mysql>altertableCountryInfoaddkey(Name);
QueryOK,0rowsaffected(0.02sec)
Records:0Duplicates:0Warnings:0
mysql>explainSELECTdocFROM`world_x`.`CountryInfo`WHERE(JSON_EXTRACT(doc,'$.Name')='United States')LIMIT1
***************************1.row***************************
id:1
select_type:SIMPLE
table:CountryInfo
partitions:NULL
type:ref
possible_keys:name
key:name
key_len:768
ref:const
rows:1
filtered:100.00
Extra:NULL
1rowinset,1warning(0.00sec)
That is really cool! We have added an index, and now the original query starts using it. Note that we do not have to reference the new field, the MySQL optimizer is smart enough to translate the (JSON_EXTRACT(doc,'$.Name')='United States' to an index scan on the virtual column.
But please note: JSON attributes are case-sensitive. If you will use (doc,'$.name') instead of (doc,'$.Name') it will not generate an error, but will simply break the search and all queries looking for “Name” will return 0 rows.
Finally, if you looked closely at the output of db.getCollection("CountryInfo").find('Name= "United States"').limit(1) , you noticed that the database has outdated info:
"government":{
"GovernmentForm":"Federal Republic",
"HeadOfState":"George W. Bush",
"HeadOfState_title":"President"
Let’s change “George W. Bush” to “Barack Obama” using the .modify clause:
mysql-js>db.CountryInfo.modify("Name = 'United States'").set("government.HeadOfState","Barack Obama");
Query OK,1item affected(0.02sec)
mysql-js>db.CountryInfo.find('Name= "United States"')
"GNP":8510700,
"IndepYear":1776,
"Name":"United States",
"_id":"USA",
"demographics":{
"LifeExpectancy":77.0999984741211,
"Population":278357000
"geography":{
"Continent":"North America",
"Region":"North America",
"SurfaceArea":9363520
"government":{
"GovernmentForm":"Federal Republic",
"HeadOfState":"Barack Obama",
"HeadOfState_title":"President"
1documentinset(0.00sec)
Conclusion
Document store is an interesting concept and a good add-on on top of the existing MySQL JSON feature. Using the new .find/.add/.modify methods instead of the original SQL statements can be convenient in some cases.
Some might ask, “why do you want to use document store and store information in JSON inside the database if it is relational anyway?” Storing data in JSON can be quite useful in some cases, for example:
- You already have a JSON (i.e., from external feeds) and need to store it anyway. Using the JSON datatype will be more convenient and more efficient.
- You have a flexible schema, typical for the Internet of Things for example, where some sensors might only send temperature data, some might send temperature/humidity/light (but light information is only recorded during the day), etc. Storing it in the JSON format can be more convenient so that you do not have to declare all possible fields in advance, and do not have to run “alter table” if a new sensor starts sending new types of data.
In the next two blog posts, I will show how to use document store for Internet of Things / event streaming, and how to use X Protocol for asynchronous queries in MySQL.
Published at DZone with permission of Alexander Rubin, DZone MVB. See the original article here.
Opinions expressed by DZone contributors are their own.
Comments