Last week (09/12/2016) was announced the new MySQL 8.0.0 DMR (Development Milestone Release)
It is now available for download at dev.mysql.com
I downloaded and installed it
Following are my first impression on some new features
First of all, when you remember the size of earlier versions, it is more & more gluttonous, see below
mysql-5.0.96-linux-x86_64-glibc23.tar.gz    121.2M
mysql-5.1.72-linux-x86_64-glibc23.tar.gz    127.8M
mysql-5.5.52-linux2.6-x86_64.tar.gz            177.2M
mysql-5.6.33-linux-glibc2.5-x86_64.tar.gz    299.7M
mysql-5.7.15-linux-glibc2.5-x86_64.tar.gz   611.8M
mysql-8.0.0-dmr-linux-glibc2.12-x86_64.tar.gz is around 1Gb and uncompressed 3.6Gb (Oups…)

At first sight , it seems that nothing has changed, same schemas and almost the same tables
– 2 new tables related to roles in the mysql schema : default_roles, role_edges
– 6 new tables in the information_schema & 6 also in the performance_schema

When you scan your Data directory (datadir), you will find new “.SDI” files (Serialized Dictionary Information) for every schema except for MySQL
mysql@MYSQL:/u01/mysqldata/mysqld9/ [mysqld9] ll *.SDI
-rw-r-----. 1 mysql mysql 215 Sep 13 21:34 employees_4.SDI
-rw-r-----. 1 mysql mysql 225 Sep 13 21:37 performance_sche_7.SDI
-rw-r-----. 1 mysql mysql 209 Sep 13 21:34 sys_6.SDI
-rw-r-----. 1 mysql mysql 209 Sep 13 21:34 TBS_3.SDI

If you have a look in one of these files, you will see that they all provide data dictionary information in a serialized form (JSON formatted text)
mysql@MYSQL:/u01/mysqldata/mysqld9/ [mysqld9] cat employees_4.SDI
{
"sdi_version": 1,
"dd_version": 1,
"dd_object_type": "Schema",
"dd_object": {
"name": "employees",
"default_collation_id": 8,
"created": 0,
"last_altered": 0
}

Old “.frm” files containing metadata  have been removed, the same for “.par” file (Partition definition), “.trg file” (Trigger parameter) and “.isl” file (InnoDB Symbolic Link)
When you create a new INNODB table, metadata are stored now in the InnoDB file (.ibd)
For all the other storage engine (memory, CSV,Blackhole, etc…), we get now a new “.SDI” file but more complex
mysql@MYSQL:/u01/mysqldata/mysqld9/Newfeatures/ [mysqld9] cat t3_617.SDI
{
"sdi_version": 1,
"dd_version": 1,
"dd_object_type": "Table",
"dd_object": {
"name": "t3",
"mysql_version_id": 80000,
"created": 20160914075838,
"last_altered": 20160914075838,
"options": "avg_row_length=0;key_block_size=0;keys_disabled=0;pack_record=0;stats_ auto_recalc=0;stats_sample_pages=0;",
"columns": [
{
"name": "c1",
"type": 29,
"is_nullable": true,
"is_zerofill": false,
"is_unsigned": false,
"is_auto_increment": false,
"is_virtual": false,
"hidden": false,
"ordinal_position": 1,
"char_length": 20,
"numeric_precision": 0,
"numeric_scale": 0,
"datetime_precision": 0,
"has_no_default": false,
"default_value_null": true,
"default_value": "",
"default_option": "",
"update_option": "",
"comment": "",
"generation_expression": "",
"generation_expression_utf8": "",
"options": "interval_count=0;",
"se_private_data": "",
"column_key": 1,
"column_type_utf8": "char(20)",
"elements": [],
"collation_id": 8
}
],
"schema_ref": "Newfeatures",
"hidden": false,
"se_private_id": 18446744073709551615,
"engine": "MEMORY",
"comment": "",
"se_private_data": "",
"row_format": 1,
"partition_type": 0,
"partition_expression": "",
"default_partitioning": 0,
"subpartition_type": 0,
"subpartition_expression": "",
"default_subpartitioning": 0,
"indexes": [],
"foreign_keys": [],
"partitions": [],
"collation_id": 8
}

It is possible now to create roles, something we were waiting for years, that means you can define a set of privileges as a role and assign it to a user
mysqld9-(root@localhost) [Newfeatures]>create role tstrole;
mysqld9-(root@localhost) [Newfeatures]>grant all on employees.* to tstrole;
mysqld9-(root@localhost) [Newfeatures]>select host, user from mysql.user;
+---------------+-------------+
| host | user |
+---------------+-------------+
| % | tstrole |

As you can see, roles are stored in the mysql.user table meaning that you can assign a user to another user
mysqld9-(root@localhost) [Newfeatures]>show grants for tstrole;
+----------------------------------------------------------+
| Grants for tstrole@% |
+----------------------------------------------------------+
| GRANT USAGE ON *.* TO `tstrole`@`%` |
| GRANT ALL PRIVILEGES ON `employees`.* TO `tstrole`@`%` |
+----------------------------------------------------------+
mysqld9-(root@localhost) [Newfeatures]>grant tstrole to 'sme'@'localhost';
mysqld9-(root@localhost) [Newfeatures]>show grants for 'sme'@'localhost' using tstrole;
+----------------------------------------------------------------------------------+
| Grants for sme@localhost |
+----------------------------------------------------------------------------------+
| GRANT USAGE ON *.* TO `sme`@`localhost` |
| GRANT ALL PRIVILEGES ON `employees`.* TO `sme`@`localhost` |
| GRANT `tstrole`@`%` TO `sme`@`localhost` |
+----------------------------------------------------------------------------------+

Now we connect as user “sme”
mysql -usme -p
mysql> use mysql
ERROR 1044 (42000): Access denied for user 'sme'@'localhost' to database 'mysql'

It seems to work, as user “sme” has only access to the employees schema

Data dictionary has been improved, almost all the system tables have been moved from MyISAM to the transactional InnoDB storage engine to increase reliability
Data dictionary tables are invisible,  they do not appear in the output of SHOW TABLES and cannot be accessed directly
but in most cases there are corresponding INFORMATION_SCHEMA tables that can be queried instead.

The new feature “Invisible Indexes” is really great.
You can toggle  now the visibility of an index as VISIBLE or INVISIBLE
We know that because of unused indexes, performance of modifications (insert, updates) are reduced
As they are also for the optimizer because they are taken in account for the plan selection
So first check for unused indexes
mysqld9-(root@localhost) [information_schema]>SELECT * FROM sys.schema_unused_indexes;
+------------------+-------------------+---------------+
| object_schema | object_name | index_name |
+------------------+---- --------------+---------------+
| employees | departments | dept_name |
| employees | dept_manager | dept_no |
+------------------+-------------------+---------------+

then
mysqld9-(root@localhost) [employees]>alter table departments alter index dept_name INVISIBLE;

Check in the data dictionary
mysqld9-(root@localhost) [employees]>SELECT * FROM information_schema.statistics WHERE is_visible='NO'G
*************************** 1. row ***************************
TABLE_CATALOG: def
TABLE_SCHEMA: employees
TABLE_NAME: departments
NON_UNIQUE: 0
INDEX_SCHEMA: employees
INDEX_NAME: dept_name
SEQ_IN_INDEX: 1
COLUMN_NAME: dept_name
COLLATION: A
CARDINALITY: NULL
SUB_PART: NULL
PACKED: NULL
NULLABLE:
INDEX_TYPE: BTREE
COMMENT:
INDEX_COMMENT:
IS_VISIBLE: NO

You can make now persistant global variables
select @@max_connections;
+--------------------------+
| @@max_connections |
+--------------------------+
| 151 |
+--------------------------+
SET GLOBAL max_connections=200;

If you restart your Instance, such setting is lost. So now with
SET PERSIST max_connections=200;
This setting now will remain after an instance restart
select @@max_connections;
+--------------------------+
| @@max_connections |
+--------------------------+
| 200 |
+--------------------------+

Last but not least, be carefull when using MySQL 8.0.0.0 in a multi instance environment,
in my case 9 instances with different versions
I found a bug in mysqld_multi when you want to restart your instance 8.0.0.0
First I corrected the still not fixed Bug #77946 (https://bugs.mysql.com/bug.php?id=77946)
in order to be able to stop my instance properly with mysqld_multi
I stopped it and then tried several times to restart it
No way
2016-09-20T23:42:41.466540Z 1 [ERROR] InnoDB: Operating system error number 2 in a file operation.
2016-09-20T23:42:41.466562Z 1 [ERROR] InnoDB: The error means the system cannot find the path specified.
2016-09-20T23:42:41.466568Z 1 [ERROR] InnoDB: If you are installing InnoDB, remember that you must create directories yourself, InnoDB does not create them.
2016-09-20T23:42:41.466574Z 1 [ERROR] InnoDB: File ./ibdata1: 'open' returned OS error 71. Cannot continue operation
2016-09-20T23:42:41.466582Z 1 [ERROR] InnoDB: Cannot continue operation.

As a temporary workaround, you can either start it manually or use the mysqld_multi from a previous version
I reported this bug  to MySQL (https://bugs.mysql.com/83081)