Month: January 2017
PL/SQL in MariaDB
The Oracle 12c manual says “Oracle PL/SQL provides functionality equivalent to SQL/PSM:2011, with minor syntactic differences, such as the spelling or arrangement of keywords.” Yes, and English provides functionality equivalent to Russian, except all the words are spelled differently and in different order. Seriously, since Oracle has PL/SQL and MariaDB has SQL/PSM, their stored procedures and functions and triggers and anonymous blocks — hereinafter “code blocks” — look different.
But that’s changing.
There’s a boatload of Oracle compatibility sauce in MariaDB 10.3, and part of it is PL/SQL code blocks, which is what I’ll look at here. MariaDB 10.3 is not released and might not be released for a long time, but the source code is public. I downloaded it with
git clone -b bb-10.2-compatibility https://github.com/MariaDB/server.git
and followed the usual instructions for building from source. I had a bit of trouble building, and I’ll make a few quibbles when I describe details. But to get to the bottom line here at the top: the feature is complete and works about as well as some betas that I’ve seen.
Here’s a short example.
CREATE PROCEDURE p AS var1 NUMBER(6) := 1; BEGIN WHILE var1 < 5 LOOP DELETE FROM t WHERE s1 = var1; var1 := var1 + 1; END LOOP; END;
Notice some obvious differences from SQL/PSM:
there are no parentheses after p, they're optional
var1 is defined outside the BEGIN END block
WHILE ... LOOP ... END LOOP not WHILE ... DO ... END WHILE
assignment is done without SET, this too is sometimes optional.
In terms of "Oracle 12c compatibility", MariaDB is now pulling ahead of MySQL, which is bemusing when one considers that Oracle owns MySQL. MariaDB will still not be as compatible as PostgreSQL with EnterpriseDB, I suppose, but this is a boost for migrants.
First complaint: Ocelot's stored-procedure debugger, which is part of our open-source GUI (ocelotgui) for MySQL and MariaDB, can't handle the new PL/SQL. It doesn't even detect where statements end, so I've got work to do.
Second complaint: obviously Monty Widenius makes the MariaDB programmers work too hard. What happened to the halcyon days of yore when making DBMSs was one long party?
For the rest of this blog post, I will describe what the differences are between MariaDB's current PSM and MariaDB 10.3's PL/SQL.
sql_mode='oracle'
In order to enable creation of PL/SQL code blocks, say
SET sql_mode='oracle';
Before saying "this is a bad idea", I will admit that:
I don't have a better idea at the moment.
Now, with that out of the way, I can say that:
this is a bad idea.
(1) There's already a "SET sql_mode='oracle';" statement, so this is a significant behaviour change.
(2) The setting changes what statements are legal. That means that, faced with a code-block statement, it's impossible to know whether it's syntactically correct unless you know what the earlier statements were.
(3) Inevitably some things will be SQL/PSM and some things will be PL/SQL, at least in some installations. Therefore there will be lots of jumping back and forth with sql_mode settings, with special extra fun if someone makes the change to @@sql_mode globally.
In other words, this is such a bad idea that it cannot possibly survive. Therefore don't worry about it. (UPDATE: 2017-02-12: since I have no better idea, and since few current users would be affected, I backtrack -- MariaDB may as well stay on course.)
CREATE PROCEDURE
SQL/PSM PL/SQL ------- ------ CREATE CREATE [OR REPLACE] [OR REPLACE] [DEFINER = {user|CURRENT_USER }] [DEFINER = {user|CURRENT_USER}] PROCEDURE sp_name PROCEDURE sp_name ([proc_parameter[,...]]) [([proc_parameter[,...]])] [characteristic ...] [characteristic ...] {IS|AS} body body proc_parameter: [IN|OUT|INOUT] name type name [IN|OUT|INOUT] type type: Any MariaDB data type any MariaDB or Oracle data type characteristic: LANGUAGE SQL LANGUAGE SQL | [NOT] DETERMINISTIC | [NOT] DETERMINISTIC | contains|reads|modifies SQL clause | contains|reads|modifies SQL clause | SQL SECURITY {DEFINER|INVOKER} | SQL SECURITY {DEFINER|INVOKER} | COMMENT 'string' | COMMENT 'string'
The only differences between the left column and the right column are:
* {IS|AS} clause -- if you see IS OR AS here, then you know it's PL/SQL.
* parentheses around the parameter list are optional.
* types can be Oracle data types, which I'll discuss later.
If Mr Spock saw this he would say "It's PL/SQL captain, but not as we know it." The DEFINER clause and the INOUT option and all the characteristics are not in Oracle 12c. But they are good additions -- if they weren't allowed, some functionality would be lost. So my only quibble would be: the Oracle characteristics clause AUTHID {DEFINER|CURRENT_USER} should have been allowed as well.
After I created with
CREATE PROCEDURE p IS BEGIN DELETE FROM t; END;
I looked at information_schema with
SELECT routine_definition, routine_body, sql_data_access, sql_mode
FROM information_schema.routines
WHERE routine_name='p';
and saw
ROUTINE_DEFINITION: 'IS BEGIN DELETE FROM t; END'
ROUTINE_BODY = 'SQL'
SQL_DATA_ACCESS = 'CONTAINS SQL'
SQL_MODE: 'PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE, ...' (etc.)
So how do I know this is a PL/SQL routine?
I can't depend on SQL_MODE, for the reasons I stated before. I don't like to depend on ROUTINE_DEFINITION, because really the definition doesn't start with IS, it starts with BEGIN.
So my second quibble is: I wish the value in ROUTINE_BODY was 'PLSQL' rather than 'SQL'.
Approximately the same syntax enhancements exist for functions and triggers.
Body
When a body of a routine is a compound statement ...
SQL/PSM PL/SQL ------- ------ [DECLARE section] BEGIN [[NOT] ATOMIC] BEGIN [variable declarations] [exception-handler declarations] [Executable statements] Executable statements [EXCEPTION section] END END
In SQL/PSM the variables are declared within BEGIN/END, in PL/SQL they're declared before BEGIN/END. In SQL/PSM the exceptions are declared within BEGIN/END, in PL/SQL they're declared after BEGIN/END.
Therefore the SQL/PSM body...
CREATE OR REPLACE PROCEDURE a() BEGIN DECLARE v VARCHAR(100) DEFAULT 'Default'; SET v = NULL; END;
... does look different in PL/SQL ...
CREATE PROCEDURE a IS v VARCHAR2(100) := 'Default'; BEGIN v := NULL; END;
but the differences are in the syntax and order of non-executable statements. That is, the existing MariaDB-10.2 SQL executable statements (DELETE, DROP, etc.) will work in a PL/SQL body.
Control statements
SQL/PSM PL/SQL ------- ------ label: <<label>> IF ... THEN ... [ELSE ...] END IF IF ... THEN ... [ELSE ...] END IF LOOP ... END LOOP LOOP ... END LOOP WHILE ... DO ...; END WHILE WHILE LOOP ...; END LOOP CASE ... WHEN ... THEN ... END CASE CASE ... WHEN ... THEN ... END CASE REPEAT ... UNTIL ... ELSIF FOR GOTO NULL LEAVE EXIT [WHEN ...] ITERATE CONTINUE [WHEN ...]
For controlling the flow of execution, there's a lot of similarity.
The only major "enhancement" in PL/SQL is GOTO, which is considered beneficial when one wishes to get out of a loop that's within a loop that's within a loop. Seeing how that works out in practice will be interesting (a euphemism for: there will be bugs).
The only minor "enhancement" in PL/SQL is NULL, which does nothing. That is, where in SQL/PSM you'd say "BEGIN END", in SQL/PSM you'd say "BEGIN NULL; END".
Third quibble: For some reason, BEGIN <<label>> NULL; END is illegal.
Fourth quibble: The NULL statement is not visible in INFORMATION_SCHEMA.
(Update 2017-01-17: The third quibble has been taken care of, and the fourth quibble was my mistake, the NULL statement is visible.)
Variables
This is a PL/SQL procedure with a mishmash of declarations and assignments.
CREATE PROCEDURE p() IS a VARCHAR2(500); b CHAR(7) CHARACTER SET sjis; c NUMBER(6) := 1; d TINYINT DEFAULT 1; BEGIN SET @c = c; d := @d; END;
Variables a and c are declared with Oracle syntax, but variables b and d are declared with MySQL syntax. The first assignment is MariaDB syntax, but the second assignment is Oracle syntax.
Fifth quibble: "SET d := @d" wouldn't work, which shows that Oracle and MariaDB variable and assignment statements aren't always interchangeable, but they usually are.
Mishmash is good -- once again, the MariaDB folks didn't see a need to limit functionality just because Oracle doesn't do something, and didn't see a need to be strict about Oracle syntax because of course MariaDB syntax works. However, routines like this can't be migrated to Oracle 12c. Compatibility only works one way.
The worklog
MariaDB is open -- the early source code is available, and so are the worklog tasks on JIRA. The information in the worklog tasks is sparse, far inferior to what we used to do for MySQL. But these items are worth following to see when they change.
[MDEV-10137] Providing compatibility to other databases
[MDEV-10142] PL/SQL parser
[MDEV-10343] Providing compatibility for basic SQL data types
[MDEV-10411] Providing compatibility for basic PL/SQL constructs
[MDEV-10580] sql_mode=ORACLE: FOR loop statement
[MDEV-10697] GOTO statement
[MDEV-10764] PL/SQL parser - Phase 2
There are many other tasks associated with "Oracle compatibility", if I had tried to describe them all this post would be too long.