23.6 Stored Object Access Control

Stored programs (procedures, functions, triggers, and events) and views are defined prior to use and, when referenced, execute within a security context that determines their privileges. The privileges applicable to execution of a stored object are controlled by its 'DEFINER' attribute and 'SQL SECURITY' characteristic.

The DEFINER Attribute

A stored object definition can include a 'DEFINER' attribute that names a MySQL account. If a definition omits the 'DEFINER' attribute, the default object definer is the user who creates it.

The following rules determine which accounts you can specify as the 'DEFINER' attribute for a stored object:

Creating a stored object with a nonexistent 'DEFINER' account creates an orphan object, which may have negative consequences; see *note stored-objects-security-orphan-objects::.

The SQL SECURITY Characteristic

For stored routines (procedures and functions) and views, the object definition can include an 'SQL SECURITY' characteristic with a value of 'DEFINER' or 'INVOKER' to specify whether the object executes in definer or invoker context. If the definition omits the 'SQL SECURITY' characteristic, the default is definer context.

Triggers and events have no 'SQL SECURITY' characteristic and always execute in definer context. The server invokes these objects automatically as necessary, so there is no invoking user.

Definer and invoker security contexts differ as follows:

Examples

Consider the following stored procedure, which is declared with 'SQL SECURITY DEFINER' to execute in definer security context:

 CREATE DEFINER = 'admin'@'localhost' PROCEDURE p1()
 SQL SECURITY DEFINER
 BEGIN
   UPDATE t1 SET counter = counter + 1;
 END;

Any user who has the 'EXECUTE' privilege for 'p1' can invoke it with a *note 'CALL': call. statement. However, when 'p1' executes, it does so in definer security context and thus executes with the privileges of ''admin'@'localhost'', the account named as its 'DEFINER' attribute. This account must have the 'EXECUTE' privilege for 'p1' as well as the 'UPDATE' privilege for the table 't1' referenced within the object body. Otherwise, the procedure fails.

Now consider this stored procedure, which is identical to 'p1' except that its 'SQL SECURITY' characteristic is 'INVOKER':

 CREATE DEFINER = 'admin'@'localhost' PROCEDURE p2()
 SQL SECURITY INVOKER
 BEGIN
   UPDATE t1 SET counter = counter + 1;
 END;

Unlike 'p1', 'p2' executes in invoker security context and thus with the privileges of the invoking user regardless of the 'DEFINER' attribute value. 'p2' fails if the invoker lacks the 'EXECUTE' privilege for 'p2' or the 'UPDATE' privilege for the table 't1'.

Orphan Stored Objects

An orphan stored object is one for which its 'DEFINER' attribute names a nonexistent account:

An orphan stored object may be problematic in these ways:

To obtain information about the accounts used as stored object definers in a MySQL installation, query the 'INFORMATION_SCHEMA'.

This query identifies which 'INFORMATION_SCHEMA' tables describe objects that have a 'DEFINER' attribute:

 mysql> SELECT TABLE_SCHEMA, TABLE_NAME FROM INFORMATION_SCHEMA.COLUMNS
        WHERE COLUMN_NAME = 'DEFINER';
 +--------------------+------------+
 | TABLE_SCHEMA       | TABLE_NAME |
 +--------------------+------------+
 | information_schema | EVENTS     |
 | information_schema | ROUTINES   |
 | information_schema | TRIGGERS   |
 | information_schema | VIEWS      |
 +--------------------+------------+

The result tells you which tables to query to discover which stored object 'DEFINER' values exist and which objects have a particular 'DEFINER' value:

Risk-Minimization Guidelines

To minimize the risk potential for stored object creation and use, follow these guidelines:

 File: manual.info.tmp, Node: stored-programs-logging, Next: stored-program-restrictions, Prev: stored-objects-security, Up: stored-objects