My personal and professional life

2018-10-23

New development features in MySQL 8.0.13

Ah, what a week already and it's not over! First, Oracle released Oracle XE 18c (as I wrote on Sunday) and yesterday (October 22-nd) MySQL 8.0.13 arrived along with (as already usual) the whole feet (Router, Shell, Workbench and C++/J/ODBC/NET/Python/Node.js Connectors). I was eager to read the change log and as the refereed article from MySQL's Server Blog also suggests there are some interesting new features for designers and developers. Here below are my picks and few words on upgrading from 8.0.12.

SQL Default Values now could be also function or expression

It's now possible to have default values as function or expression. This is an important new feature. Before only literal values were allowed, which was quite limiting. The removal of this limitation means that it is now possible:
  • to generate UUID values by default (by using DEFAULT (uuid_to_bin(uuid())) for example);
  • to generate default values for geometry data types (by using DEFAULT (POINT(0,0)) or DEFAULT (ST_PointFromText('POINT(42.69751 23.32415)', 4326)) for example);
  • to generate default values for JSON columns (by using DEFAULT (JSON_ARRAY()) or DEFAULT ('[]') for example); and
  • other complex values (like DEFAULT (CURRENT_DATE + INTERVAL 1 DAY) or DEFAULT (PI() * POW(r, 2)) for example) using function or functions in an expression.
Remark: Please, note the parentheses surrounding the expression in DEFAULT (see Handling of Explicit Defaults as of MySQL 8.0.13 in the manual). MySQL Workbench 8.0.13 again has some problems parsing the new syntax (see screenshot below), so I opened bug 92900 and it already got verified:

MySQL Workbench 8.0.13 erorr on default expression

I tried the new functionality with the following:

CREATE TABLE def_expr (
  id        INT           NOT NULL AUTO_INCREMENT,
  uuid_def  BINARY(16)    DEFAULT (uuid_to_bin(uuid())),
  geo_def   POINT         DEFAULT (Point(0,0)),
  geo_def2  GEOMETRY      DEFAULT (ST_PointFromText('POINT(42.69751 23.32415)', 4326)),
  json_def  JSON          DEFAULT (JSON_ARRAY()),
  json_def2 JSON          DEFAULT ('[]') /* this works too */,
  tomorrow  DATE          DEFAULT (CURDATE() + INTERVAL 1 DAY),
  radius    INT           DEFAULT (FLOOR(1 + (RAND() * 10))),
  area      DECIMAL(10,3) DEFAULT (ROUND(PI() * POW(radius, 2), 3)),

  PRIMARY KEY (id),
  UNIQUE INDEX id_UNIQUE (id ASC) VISIBLE
);



Then inserted two dummy lines and got the following results:

INSERT INTO def_expr VALUES (); /* x 2 */

SELECT id,
       bin_to_uuid(uuid_def) uuid_def,
       ST_AsText(geo_def)    geo_def,
       ST_AsText(geo_def2)   geo_def2,
       json_def, json_def2,
       tomorrow, radius, area
  FROM def_expr;


+----+--------------------------------------+------------+--------------------------+----------+-----------+------------+--------+---------+
| id | uuid_def                             | geo_def    | geo_def2                 | json_def | json_def2 | tomorrow   | radius | area    |
+----+--------------------------------------+------------+--------------------------+----------+-----------+------------+--------+---------+
|  1 | a2747ee0-d6ee-11e8-b02e-02004c4f4f50 | POINT(0 0) | POINT(42.69751 23.32415) | []       | []        | 2018-10-24 |      2 |  12.566 |
|  2 | a2ff920b-d6ee-11e8-b02e-02004c4f4f50 | POINT(0 0) | POINT(42.69751 23.32415) | []       | []        | 2018-10-24 |     10 | 314.159 |
+----+--------------------------------------+------------+--------------------------+----------+-----------+------------+--------+---------+
2 rows in set (0.0021 sec)


That's cool, right? I'm eager to use it in my projects.

SQL Functional Indexes


It's now possible to have functional indexes (see Functional Key Parts in the manual), which means that the index is build from expression values, instead of column values or column prefix values. In other words you could index values not stored in the table, which I think could be quite powerful in some cases. In composite indexes with multiple key parts you could have mix of functional and nonfunctional (regular) key parts. Functional key parts are implemented as hidden virtual generated columns (see CREATE TABLE and Generated Columns in the manual) available since MySQL 5.7.6 (from 2015-03-09). This also means that functional key parts have the same restrictions (i.e. deterministic built-in functions and operators are permitted, but subqueries, parameters, variables, stored and user-defined functions are not permitted).
To try the new functionality I though that IP addresses are usually stored as string in databases and then parsed, but the address could be represented as an (unsigned) integer value, which requires just 4 bytes. So I used the following:

CREATE TABLE func_index (
  id        INT        NOT NULL AUTO_INCREMENT,
  ipaddr4   INT UNSIGNED /* 4 bytes */,

  PRIMARY KEY (id),
  UNIQUE INDEX id_UNIQUE (id ASC) VISIBLE,
  INDEX func_idx ((INET_NTOA(ipaddr4)))
);

Remark: Please, note the parentheses surrounding the expression. Without them there would be цоде 1064 (syntax error). Not surprisingly MySQL Workbench 8.0.13 wasn't ready for the new syntax, so I opened bug 92908 and it also already got verified.

MySQL Workbench 8.0.13 erorr on functional index

Then inserted a line and explained two SELECT queries below:

INSERT INTO func_index (ipaddr4) VALUES (INET_ATON('192.168.1.1'));

SELECT * FROM func_index WHERE ipaddr4 = INET_ATON('192.168.1.1');
SELECT * FROM func_index WHERE INET_NTOA(ipaddr4) = '192.168.1.1';

The first one would result in full table scan, while the second one would read the functional index func_idx. In order for the query to use the index it's important that the expression in the WHERE clause matches index's specification.

Option to Disallow Tables without a Primary Key

There is now the system variable sql_require_primary_key, which prevents the creation or altering of tables without primary key if set. In such case CREATE or ALTER queries would now fail with error code 3750 (see also SQL state ER_TABLE_WITHOUT_PK).
I tried this new possibility by setting the global variable in a session like this:

SET GLOBAL sql_require_primary_key = ON;

but I was able to create table without primary key. I have to check it again tomorrow and eventually report a bug. Setting the variable in my.ini and restarting the server worked just fine:

SQL> CREATE TABLE tab_no_pk (test INT);
ERROR: 3750: Unable to create a table without PK, when system variable 'sql_require_primary_key' is set. Add a PK to the table or unset this variable to avoid this message. Note that tables without PK can cause performance problems in row-based replication, so please consult your DBA before changing this setting.

I'll finally have a break from developers not familiar with relational concepts :-)

Geometry transformation

It's now possible to transform geometry from one spatial reference system (SRS) to another using built-in function ST_Transform, which accepts as second argument the target SRS. I'm not that much into GIS, so I didn't tested this one, but it seemed worth mentioning.

A few words on upgrading (from 8.0.12)

Upgrading my Windows installation was flawless with MySQL Installer for Windows. However, I had problem with my Linux installation, which consist of more databases. The server wasn't able to start and in the error log I found errors like the following:

2018-10-23T12:47:49.627732Z 1 [ERROR] [MY-013235] [Server] Error in parsing View 'db'.'aView' during upgrade. You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'desc' at line 1

I opened bug 92898 for this and the problem already got explained by support with an incompatible change (see SQL Syntax Notes from the release notes). I'm pretty sure I've read about ASC or DESC qualifiers for GROUP BY clauses being deprecated and I really do not remember why I used such syntax, but it got me off guard, so I had to update view definitions.

There's a lot more in MySQL 8.0.13 and I strongly suggest you review The MySQL 8.0.13 Maintenance Release is Generally Available article and release notes, then explore for yourself.

2018-10-21

First impressions from Oracle XE 18c trying to install it on Fedora 28/29 and Oracle Linux 7

Oracle released Oracle Database Express Edition (or better known as XE) on October 19, 2018. This date also happens to be my birthday, so what a birthday surprise! Let's get the present open and try it!
It was a long wait for Oracle XE 18c since the previous version (based on 11g Release 2) appeared more than 7 years ago (on September 24, 2011) and a release based on Oracle 12c never appeared. I was running XE on Fedora since 11g appeared in 2011, but with the new Fedora releases this become impossible. The database was behaving strange and was not usable after reboot, but I never found the time to investigate deeper these issues. I was thus considering trying Oracle Linux instead (see Which OS is “the best” for Oracle? for an expert opinion).

Fedora 28/29

Since I do not have enough space on the virtual machine I downloaded the RPMs on a server and tried to install them from an NFS mount following the instructions in the Quick Start:

[root@fedora ~]# yum -y localinstall /mnt/vm/oracle-database-preinstall-18c-1.0-1.el7.x86_64.rpm
Last metadata expiration check: 2:01:29 ago on Sun 21 Oct 2018 11:07:06 AM EEST.
Error:
 Problem: conflicting requests
  - nothing provides compat-libcap1 needed by oracle-database-preinstall-18c-1.0-1.el7.x86_64



Hmm... I'm just missing a required package compat-libcap1, but why it's not installed automatically?

[root@fedora ~]# yum install compat-libcap1
Last metadata expiration check: 1:24:06 ago on Sun 21 Oct 2018 11:07:06 AM EEST.
No match for argument: compat-libcap1
Error: Unable to find a match


That's strange, but Fedora doesn't provide this package. I found it in CentOS repository (direct download link) and after installing compat-libcap1 the preinstall RPM installed successfully. However, the database installation failed:

[root@fedora ~]# yum -y localinstall /mnt/vm/oracle-database-xe-18c-1.0-1.x86_64.rpm
Last metadata expiration check: 2:16:29 ago on Sun 21 Oct 2018 11:07:06 AM EEST.
Dependencies resolved.
==========================================================
 Package                Arch   Version Repository    Size
==========================================================
Installing:
 oracle-database-xe-18c x86_64 1.0-1   @commandline 2.4 G

Transaction Summary
==========================================================
Install  1 Package

Total size: 2.4 G
Installed size: 5.2 G
Downloading Packages:
Running transaction check
Transaction check succeeded.
Running transaction test
Error: Transaction check error:
  package oracle-database-xe-18c-1.0-1.x86_64 does not verify: no digest
  installing package oracle-database-xe-18c-1.0-1.x86_64 needs 2472MB on the / filesystem


Error Summary
-------------
Disk Requirements:
   At least 2472MB more space needed on the / filesystem.


Apparently the disk space requirements have increased, because previously I was able to install XE 11gR2 on the same virtual machine. I had to enlarge the disk and extend the volume. However, the problem Error: Transaction check error: package oracle-database-xe-18c-1.0-1.x86_64 does not verify: no digest remains, so I wrote in the forum (see thread 14969247).

To overcome this I used the following command. But to make it work I had to install also libnsl (i.e. dnf install libnsl) and increase the disk space once more. Apparently, the installation of the RPM requires about 5.2 GB.

[root@fedora ~]# rpm -i --nodigest /mnt/vm/oracle-database-xe-18c-1.0-1.x86_64.rpm
warning: /mnt/vm/oracle-database-xe-18c-1.0-1.x86_64.rpm: Header V3 RSA/SHA256 Signature, key ID ec551f03: NOKEY
[INFO] Executing post installation scripts...
[INFO] Oracle home installed successfully and ready to be configured.
To configure Oracle Database XE, optionally modify the parameters in '/etc/sysconfig/oracle-xe-18c.conf' and then execute '/etc/init.d/oracle-xe-18c configure' as root.


Then, it's time to configure. For the creation of the database 4.5 GB more disk space is necessary.

[root@fedora ~]# /etc/init.d/oracle-xe-18c configure
Specify a password to be used for database accounts. Oracle recommends that the password entered should be at least 8 characters in length, contain at least 1 uppercase character, 1 lower case character and 1 digit [0-9]. Note that the same password will be used for SYS, SYSTEM and PDBADMIN accounts:
Confirm the password:
Configuring Oracle Listener.
Listener configuration succeeded.
Configuring Oracle Database XE.
[WARNING] [DBT-11209] Current available memory is less than the required available memory (796MB) for creating the database.
   CAUSE: Following nodes do not have required available memory :
 Node:fedora            Available memory:471.8672MB (483192.0KB)

Enter SYS user password:
*************
Enter SYSTEM user password:
*************
Enter PDBADMIN User Password:
**************
Prepare for db operation
7% complete
Copying database files
29% complete
Creating and starting Oracle instance
30% complete
31% complete
34% complete
38% complete
41% complete
43% complete
Completing Database Creation
47% complete
50% complete
Creating Pluggable Databases
54% complete
71% complete
Executing Post Configuration Actions
93% complete
Running Custom Scripts
100% complete
Database creation complete. For details check the logfiles at:
 /opt/oracle/cfgtoollogs/dbca/XE.
Database Information:
Global Database Name:XE
System Identifier(SID):XE
Look at the log file "/opt/oracle/cfgtoollogs/dbca/XE/XE.log" for further details.

Connect to Oracle Database using one of the connect strings:
     Pluggable database: fedora:1539/XEPDB1
     Multitenant container database: fedora:1539
Use https://localhost:5500/em to access Oracle Enterprise Manager for Oracle Database XE


Note: If you receive  Listener configuration failed. Check log '/opt/oracle/cfgtoollogs/netca/netca_configure_out.log' and into the log there is the line No valid IP Address returned for the host fedora simply set the fully qualified domain name (FQDN) into /etc/hostname and start configuration again.

The same procedure applies also to Fedora 29.

Oracle Linux Server 7.5

The installation of preinstall RPM happens smoothly:


[root@oracle ~]# yum -y localinstall /mnt/vm/oracle-database-preinstall-18c-1.0-1.el7.x86_64.rpm
Loaded plugins: ulninfo
Examining /mnt/vm/oracle-database-preinstall-18c-1.0-1.el7.x86_64.rpm: oracle-database-preinstall-18c-1.0-1.el7.x86_64
Marking /mnt/vm/oracle-database-preinstall-18c-1.0-1.el7.x86_64.rpm to be installed
Resolving Dependencies
--> Running transaction check
---> Package oracle-database-preinstall-18c.x86_64 0:1.0-1.el6 will be installed
...
--> Processing Dependency: compat-libcap1 for package: oracle-database-preinstall-18c-1.0-1.el6.x86_64
...
Dependencies Resolved

====================================================================
 Package                         Arch   Version     Repository Size
====================================================================
Installing:                                                  
 oracle-database-preinstall-18c  x86_64 1.0-1.el7   /oracle... 55 k
Installing for dependencies:                                 
...                                                          
 compat-libcap1                  x86_64 1.10-7.el7  ol7_latest 17 k
...
Install  1 Package (+37 Dependent packages)
...
Installed:
  oracle-database-preinstall-18c.x86_64 0:1.0-1.el7

Dependency Installed:
compat-libcap1.x86_64 0:1.10-7.el7
...
Complete!


The dependency on compat-libcap1 was easily resolved as well as 36 other dependencies, because my installation of Oracle Linux is new and I do not have many packages installed yet. The installation of the RPM with the database also happened without problems:

[root@oracle ~]# yum -y localinstall /mnt/vm/oracle-database-xe-18c-1.0-1.x86_64.rpm
Loaded plugins: ulninfo
Examining /mnt/vm/oracle-database-xe-18c-1.0-1.x86_64.rpm: oracle-database-xe-18c-1.0-1.x86_64
Marking /mnt/vm/oracle-database-xe-18c-1.0-1.x86_64.rpm to be installed
Resolving Dependencies
--> Running transaction check
---> Package oracle-database-xe-18c.x86_64 0:1.0-1 will be installed
--> Finished Dependency Resolution

Dependencies Resolved

========================================================
 Package                 Arch   Version Repository Size
========================================================
Installing:
 oracle-database-xe-18c  x86_64 1.0-1   /oracle... 5.2 G

Transaction Summary
========================================================
Install  1 Package

Total size: 5.2 G
Installed size: 5.2 G
Downloading packages:
Running transaction check
Running transaction test
Transaction test succeeded
Running transaction
  Installing : oracle-database-xe-18c-1.0-1.x86_64  1/1
[INFO] Executing post installation scripts...
[INFO] Oracle home installed successfully and ready to be configured.
To configure Oracle Database XE, optionally modify the parameters in '/etc/sysconfig/oracle-xe-18c.conf' and then execute '/etc/init.d/oracle-xe-18c configure' as root.
  Verifying  : oracle-database-xe-18c-1.0-1.x86_64  1/1

Installed:
  oracle-database-xe-18c.x86_64 0:1.0-1

Complete!


And apparently about 5.2 GB is the space really needed for the software itself, because before the installation I had about this space more on the volume. Let's try to configure the database then:

[root@oracle ~]# /etc/init.d/oracle-xe-18c configure
The location '/opt/oracle' specified for database files has insufficient space.
Database creation needs at least '4.5GB' disk space.
Specify a different database file destination that has enough space in the configuration file '/etc/sysconfig/oracle-xe-18c.conf'.


Aha... so the disk space requirements are actually pretty much the same as for Standard Edition on Linux. After resizing the virtual disk and enlarging the volume the configuration passes successfully for about 10 minutes:

[root@oracle ~]# /etc/init.d/oracle-xe-18c configure
Specify a password to be used for database accounts. Oracle recommends that the password entered should be at least 8 characters in length, contain at least 1 uppercase character, 1 lower case character and 1 digit [0-9]. Note that the same password will be used for SYS, SYSTEM and PDBADMIN accounts:
Confirm the password:
Configuring Oracle Listener.
Listener configuration succeeded.
Configuring Oracle Database XE.
Enter SYS user password:
*************
Enter SYSTEM user password:
***************
Enter PDBADMIN User Password:
***********
Prepare for db operation
7% complete
Copying database files
29% complete
Creating and starting Oracle instance
30% complete
31% complete
34% complete
38% complete
41% complete
43% complete
Completing Database Creation
47% complete
50% complete
Creating Pluggable Databases
54% complete
71% complete
Executing Post Configuration Actions
93% complete
Running Custom Scripts
100% complete
Database creation complete. For details check the logfiles at:
 /opt/oracle/cfgtoollogs/dbca/XE.
Database Information:
Global Database Name:XE
System Identifier(SID):XE
Look at the log file "/opt/oracle/cfgtoollogs/dbca/XE/XE.log" for further details.

Connect to Oracle Database using one of the connect strings:
     Pluggable database: oracle.sotirov-bg.net/XEPDB1
     Multitenant container database: oracle.sotirov-bg.net
Use https://localhost:5500/em to access Oracle Enterprise Manager for Oracle Database XE


Even after successful installation and configuration there are few manual steps necessary:
  •  Set environment variables. For this I just added the following to /etc/profile:
export ORACLE_HOME=/opt/oracle/product/18c/dbhomeXE
export ORACLE_SID=XE
pathmunge $ORACLE_HOME/bin after

  • Enable database start at system boot. For this I used the default script at /etc/init.d/oracle-xe-18c and executed one of the following:
chkconfig --add oracle-xe-18c; chkconfig oracle-xe-18c on
systemctl enable oracle-xe-18c
  • Enable access over the network. For this it's necessary to allow the default listener port 1521 on the firewall:
firewall-cmd --permanent --zone=public --add-port=1521/tcp
systemctl reload firewalld

Time to connect to the database:

[root@oracle ~]# sqlplus sys/password@//localhost:1521/XE as sysdba

SQL*Plus: Release 18.0.0.0.0 - Production on Sun Oct 21 19:16:35 2018
Version 18.4.0.0.0

Copyright (c) 1982, 2018, Oracle.  All rights reserved.

Connected to:
Oracle Database 18c Express Edition Release 18.0.0.0.0 - Production
Version 18.4.0.0.0

SQL>


Hurray! Now that the database is installed and accessible it's time to load some data and start experimenting.