SQL_MODE=ORACLE

From MariaDB 10.3, setting the sql_mode system variable to Oracle allows the server to understand a subset of Oracle's PL/SQL language. For example:

SET SQL_MODE='ORACLE';

All traditional MariaDB SQL/PSM syntax should work as before, as long as it does not conflict with Oracle's PL/SQL syntax. All MariaDB functions should be supported in both normal and Oracle modes.

Prior to MariaDB 10.3, MariaDB does not support Oracle's PL/SQL language, and SET SQL_MODE=ORACLE is only an alias for the following sql_mode in those versions:

SET SQL_MODE='PIPES_AS_CONCAT, ANSI_QUOTES, IGNORE_SPACE, NO_KEY_OPTIONS,
NO_TABLE_OPTIONS, NO_FIELD_OPTIONS, NO_AUTO_CREATE_USER';

From MariaDB 10.3, SET SQL_MODE=ORACLE is same as:

SET SQL_MODE='PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,
NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER,SIMULTANEOUS_ASSIGNMENT';

Supported Syntax in Oracle Mode

Stored Procedures and Stored Functions

Oracle mode makes the following changes to Stored Procedures and Stored Functions:

Oracle syntaxDescription
CREATE PROCEDURE p1 (param OUT INT)ANSI uses (OUT param INT)
CREATE PROCEDURE p1 (a IN OUT INT)ANSI uses (INOUT param INT)
AS before function bodyCREATE FUNCTION f1 RETURN NUMBER AS BEGIN...
IS before function bodyCREATE FUNCTION f1 RETURN NUMBER IS BEGIN...
If function has no parameters then parentheses must be omittedExample: CREATE PROCEDURE p1 AS BEGIN NULL; END;
CREATE PROCEDURE p1 AS BEGIN END p1;Optional routine name after END keyword. MDEV-12089
CREATE FUNCTION f1(a VARCHAR)VARCHAR can be used without length for routine parameters and RETURN clause. The length is inherited from the argument at call time. MDEV-10596
CREATE AGGREGATE FUNCTION f1( )Creates an aggregate function, which performs the function against a set of rows and returns one aggregate result.
No CALL needed in Stored ProceduresIn Oracle mode one can call other stored procedures with name only. MDEV-12107
RETURN. Can also be used in stored proceduresANSI uses RETURNS. MariaDB mode only supports RETURNS in stored functions

Cursors

Oracle mode makes the following changes to Cursors:

Oracle syntaxDescription
CREATE PROCEDURE p1 AS CURSOR cur IS (SELECT a, b FROM t1); BEGIN FOR rec IN cur ...Explicit cursor with FOR loop. MDEV-10581
CREATE PROCEDURE p1 AS rec IN (SELECT a, b FROM t1)Implicit cursor with FOR loop. MDEV-12098
CURSOR c(prm_a VARCHAR2, prm_b VARCHAR2) ... OPEN c(1,2)Cursor with parameters. MDEV-10597
CURSOR c(prm_a VARCHAR2, prm_b VARCHAR2) ... FOR rec in c(1,2)Cursor with parameters and FOR loop. MDEV-12314
s %ISOPEN, %ROWCOUNT, %FOUND, %NOTFOUNDExplicit cursor attributes. MDEV-10582

LOOP

Oracle mode makes the following changes to LOOP:

Oracle syntaxDescription
FOR i IN 1..10 LOOP ... END LOOPNumeric FOR loop. MDEV-10580
GOTOGOTO statement. MDEV-10697
<<label>> used with GOTOANSI uses label:. MDEV-10697
To leave loop block: EXIT [ label ] [ WHEN bool_expr ]ANSI syntax is IF bool_expr THEN LEAVE label
[<<label>>] WHILE boolean_expression LOOP statement... END LOOP [ label ] ;Oracle style WHILE loop
CONTINUE [ label ] [ WHEN boolean_expression]CONTINUE is only valid inside a loop

Variables

Oracle syntaxVersionDescription
var:= 10; Can also be used with MariaDB systemvariables10.3MariaDB uses SET var= 10;
var INT := 1010.3Default variable value
var1 table_name.column_name%TYPE10.3Take data type from a table column. MDEV-10577
var2 var1%TYPE10.3Take data type from another variable
rec1 table_name%ROWTYPE10.3Take ROW structure from a table. MDEV-12133
rec2 rec1%ROWTYPE10.3Take ROW structure from ROW variable
CURSOR c1 IS SELECT a,b FROM t1; rec1 c1%ROWTYPE;10.3Take ROW structure from a cursor. MDEV-12011
Variables can be declared after cursor declarations10.3In MariaDB mode, variables must be declared before cursors. MDEV-10598
Triggers uses :NEW and :OLD10.3ANSI uses NEW and OLD. MDEV-10579
SQLCODE10.3Returns the number code of the most recent exception. Can only be used in Stored Procedures. MDEV-10578
SQLERRM10.3Returns the error message associdated to it's error number argument or SQLCODE if no argument is given. Can only be used in Stored Procedures. MDEV-10578
SQL%ROWCOUNT10.3Almost same as ROW_COUNT(). MDEV-10583
ROWNUM10.6.1Returns number of accepted rows

Exceptions

Oracle syntaxDescription
BEGIN ... EXCEPTION WHEN OTHERS THEN BEGIN .. END; END;Exception handlers are declared at the end of a block
TOO_MANY_ROWS, NO_DATA_FOUND, DUP_VAL_ON_INDEXPredefined exceptions. MDEV-10839
RAISE TOO_MANY_ROWS ; .... EXCEPTION WHEN TOO_MANY_ROWS THEN ...Exception can be used with RAISE and EXCEPTION...WHEN. MDEV-10840
CREATE OR REPLACE FUNCTION f1 (a INT) RETURN INT AS e1 EXCEPTION...User defined exceptions. MDEV-10587

BEGIN Blocks

Oracle syntaxDescription
BEGIN to start a blockMariaDB uses BEGIN NOT ATOMIC for anyonymous blocks. MDEV-10655
DECLARE is used before BEGINDECLARE a INT; b VARCHAR(10); BEGIN v:= 10; END;
WHEN DUP_VAL_ON_INDEX THEN NULL ; NULL; WHEN OTHERS THEN NULLDo not require BEGIN..END in multi-statement exception handlers in THEN clause. MDEV-12088

Simple Syntax Compatibility

Oracle syntaxVersionDescription
ELSIF10.3ANSI uses ELSEIF
SELECT UNIQUE10.3Same as SELECT DISTINCT. MDEV-12086
TRUNCATE TABLE t1 [DROP STORAGE] or [REUSE STORAGE]10.3DROP STORAGE and REUSE STORAGE are allowed as optional keywords for TRUNCATE TABLE. MDEV-10588
Subqueries in a FROM clause without an alias10.6 SELECT * FROM (SELECT 1 FROM DUAL), (SELECT 2 FROM DUAL)
UNION, EXCEPT and INTERSE