In MariaDB/MySQL, stored procedures default to running in the context of
the definer rather than the invoker.
This is a problem in a streaming replication scenario since the definer
is often the root user who has the "super" power to write to a read-only
database (unless super-read-only is enabled, which is not available for
MariaDB), thus breaking the replication timeline.
Additionally, exiting an SP does not finalise any running transaction.
If an exception is raised within the SP (e.g. due to the database being
read-only) we must handle this and finalise the transaction, otherwise
subsequent calls to "SET TRANSACTION ISOLATION LEVEL READ COMMITTED"
will fail ad nauseam until the connection is finally closed.
IN v_lease_duration INT,
IN v_requested_address VARCHAR(15)
)
+SQL SECURITY INVOKER
proc:BEGIN
DECLARE r_address VARCHAR(15);
IN v_lease_duration INT,
IN v_requested_address VARCHAR(15)
)
+SQL SECURITY INVOKER
proc:BEGIN
DECLARE r_address VARCHAR(15);
+ DECLARE EXIT HANDLER FOR SQLEXCEPTION
+ BEGIN
+ ROLLBACK;
+ RESIGNAL;
+ END;
+
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
START TRANSACTION;
IN v_pool_key VARCHAR(64),
IN v_lease_duration INT
)
+SQL SECURITY INVOKER
proc:BEGIN
DECLARE r_address VARCHAR(15);
IN v_pool_key VARCHAR(64),
IN v_lease_duration INT
)
+SQL SECURITY INVOKER
proc:BEGIN
DECLARE r_address VARCHAR(15);
+ DECLARE EXIT HANDLER FOR SQLEXCEPTION
+ BEGIN
+ ROLLBACK;
+ RESIGNAL;
+ END;
+
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
START TRANSACTION;