The audit log plugin supports functions that provide an SQL interface for reading JSON-format audit log files. (This capability does not apply to log files written in other formats.)
When the audit log plugin initializes and is configured for JSON
logging, it uses the directory containing the current audit log
file as the location to search for readable audit log files. The
plugin determines the file location, base name, and suffix from
the value of the audit_log_file
system variable, then looks for files with names that match the
following pattern, where [...]
indicates
optional file name parts:
basename[.timestamp].suffix[.gz][[.pwd_id].enc]
If a file name ends with .enc
, the file is
encrypted and reading its unencrypted contents requires a
decryption password obtained from the keyring. The audit log
plugin determines the keyring ID of the decryption password as
follows:
If
.enc
is preceded bypwd_id
, the keyring ID isaudit_log-
.pwd_id
If
.enc
is not preceded bypwd_id
, the file has an old name from before audit log encryption password history was implemented. The keyring ID isaudit_log
.
For more information about encrypted audit log files, see Encrypting Audit Log Files.
The plugin ignores files that have been renamed manually and do
not match the pattern, and files that were encrypted with a
password no longer available in the keyring. The plugin opens
each remaining candidate file, verifies that the file actually
contains JSON
audit events, and
sorts the files using the timestamps from the first event of
each file. The result is a sequence of files that are subject to
access using the log-reading functions:
audit_log_read()
reads events from the audit log or closes the reading process.audit_log_read_bookmark()
returns a bookmark for the most recently written audit log event. This bookmark is suitable for passing toaudit_log_read()
to indicate where to begin reading.
audit_log_read()
takes an
optional JSON
string argument,
and the result returned from a successful call to either
function is a JSON
string.
To use the functions to read the audit log, follow these principles:
Call
audit_log_read()
to read events beginning from a given position or the current position, or to close reading:To initialize an audit log read sequence, pass an argument that indicates the position at which to begin. One way to do so is to pass the bookmark returned by
audit_log_read_bookmark()
:SELECT audit_log_read(audit_log_read_bookmark());
To continue reading from the current position in the sequence, call
audit_log_read()
with no position specified:SELECT audit_log_read();
To explicitly close the read sequence, pass a
JSON
null
argument:SELECT audit_log_read('null');
It is unnecessary to close reading explicitly. Reading is closed implicitly when the session ends or a new read sequence is initialized by calling
audit_log_read()
with an argument that indicates the position at which to begin.
A successful call to
audit_log_read()
to read events returns aJSON
string containing an array of audit events:If the final value of the returned array is not a
JSON
null
value, there are more events following those just read andaudit_log_read()
can be called again to read more of them.If the final value of the returned array is a
JSON
null
value, there are no more events left to be read in the current read sequence.
Each non-
null
array element is an event represented as aJSON
hash. For example:[ { "timestamp": "2020-05-18 13:39:33", "id": 0, "class": "connection", "event": "connect", ... }, { "timestamp": "2020-05-18 13:39:33", "id": 1, "class": "general", "event": "status", ... }, { "timestamp": "2020-05-18 13:39:33", "id": 2, "class": "connection", "event": "disconnect", ... }, null ]
For more information about the content of JSON-format audit events, see JSON Audit Log File Format.
An
audit_log_read()
call to read events that does not specify a position produces an error under any of these conditions:A read sequence has not yet been initialized by passing a position to
audit_log_read()
.There are no more events left to be read in the current read sequence; that is,
audit_log_read()
previously returned an array ending with aJSON
null
value.The most recent read sequence has been closed by passing a
JSON
null
value toaudit_log_read()
.
To read events under those conditions, it is necessary to first initialize a read sequence by calling
audit_log_read()
with an argument that specifies a position.
To specify a position to
audit_log_read()
, include an
argument that indicates where to begin reading. For example,
pass a bookmark, which is a JSON
hash containing timestamp
and
id
elements that uniquely identify a
particular event. Here is an example bookmark, obtained by
calling the
audit_log_read_bookmark()
function:
mysql> SELECT audit_log_read_bookmark();
+-------------------------------------------------+
| audit_log_read_bookmark() |
+-------------------------------------------------+
| { "timestamp": "2020-05-18 21:03:44", "id": 0 } |
+-------------------------------------------------+
Passing the current bookmark to
audit_log_read()
initializes
event reading beginning at the bookmark position:
mysql> SELECT audit_log_read(audit_log_read_bookmark());
+-----------------------------------------------------------------------+
| audit_log_read(audit_log_read_bookmark()) |
+-----------------------------------------------------------------------+
| [ {"timestamp":"2020-05-18 22:41:24","id":0,"class":"connection", ... |
+-----------------------------------------------------------------------+
The argument to audit_log_read()
is optional. If present, it can be a
JSON
null
value to close the read sequence, or a
JSON
hash.
Within a hash argument to
audit_log_read()
, items are
optional and control aspects of the read operation such as the
position at which to begin reading or how many events to read.
The following items are significant (other items are ignored):
start
: The position within the audit log of the first event to read. The position is given as a timestamp and the read starts from the first event that occurs on or after the timestamp value. Thestart
item has this format, wherevalue
is a literal timestamp value:"start": { "timestamp": "value" }
The
start
item is permitted as of MySQL 8.0.22.timestamp
,id
: The position within the audit log of the first event to read. Thetimestamp
andid
items together comprise a bookmark that uniquely identify a particular event. If anaudit_log_read()
argument includes either item, it must include both to completely specify a position or an error occurs.max_array_length
: The maximum number of events to read from the log. If this item is omitted, the default is to read to the end of the log or until the read buffer is full, whichever comes first.
To specify a starting position to
audit_log_read()
, pass a hash
argument that includes either a start
item or
a bookmark consisting of timestamp
and
id
items. If a hash argument includes both a
start
item and a bookmark, an error occurs.
If a hash argument specifies no starting position, reading continues from the current position.
If a timestamp value includes no time part, a time part of
00:00:00
is assumed.
Example arguments accepted by
audit_log_read()
:
Read events starting with the first event that occurs on or after the given timestamp:
audit_log_read('{ "start": { "timestamp": "2020-05-24 12:30:00" } }')
Like the previous example, but read at most 3 events:
audit_log_read('{ "start": { "timestamp": "2020-05-24 12:30:00" }, "max_array_length": 3 }')
Read events starting with the first event that occurs on or after
2020-05-24 00:00:00
(the timestamp includes no time part, so00:00:00
is assumed):audit_log_read('{ "start": { "timestamp": "2020-05-24" } }')
Read events starting with the event that has the exact timestamp and event ID:
audit_log_read('{ "timestamp": "2020-05-24 12:30:00", "id": 0 }')
Like the previous example, but read at most 3 events:
audit_log_read('{ "timestamp": "2020-05-24 12:30:00", "id": 0, "max_array_length": 3 }')
Read events from the current position in the read sequence:
audit_log_read()
Read at most 5 events beginning at the current position in the read sequence:
audit_log_read('{ "max_array_length": 5 }')
Close the current read sequence:
audit_log_read('null')
A JSON
string returned from
either log-reading function can be manipulated as necessary.
Suppose that a call to obtain a bookmark produces this value:
mysql> SET @mark := audit_log_read_bookmark();
mysql> SELECT @mark;
+-------------------------------------------------+
| @mark |
+-------------------------------------------------+
| { "timestamp": "2020-05-18 16:10:28", "id": 2 } |
+-------------------------------------------------+
Calling audit_log_read()
with
that argument can return multiple events. To limit
audit_log_read()
to reading at
most N
events, add to the string a
max_array_length
item with that value. For
example, to read a single event, modify the string as follows:
mysql> SET @mark := JSON_SET(@mark, '$.max_array_length', 1);
mysql> SELECT @mark;
+----------------------------------------------------------------------+
| @mark |
+----------------------------------------------------------------------+
| {"id": 2, "timestamp": "2020-05-18 16:10:28", "max_array_length": 1} |
+----------------------------------------------------------------------+
The modified string, when passed to
audit_log_read()
, produces a
result containing at most one event, no matter how many are
available.
Prior to MySQL 8.0.19, string return values from audit log
functions are binary strings. To use a binary string with
functions that require a nonbinary string (such as functions
that manipulate JSON
values),
convert it to a nonbinary string. For example, before passing a
bookmark to JSON_SET()
, convert
it to utf8mb4
as follows:
SET @mark = CONVERT(@mark USING utf8mb4);
That statement can be used even for MySQL 8.0.19 and higher; for those versions, it is essentially a no-op and is harmless.
If an audit log function is invoked from within the
mysql client, binary string results display
using hexadecimal notation, depending on the value of the
--binary-as-hex
. For more
information about that option, see Section 6.5.1, “mysql — The MySQL Command-Line Client”.
To set a limit on the number of bytes that
audit_log_read()
reads, set the
audit_log_read_buffer_size
system variable. As of MySQL 8.0.12, this variable has a default
of 32KB and can be set at runtime. Each client should set its
session value of
audit_log_read_buffer_size
appropriately for its use of
audit_log_read()
.
Each call to audit_log_read()
returns as many available events as fit within the buffer size.
Events that do not fit within the buffer size are skipped and
generate warnings. Given this behavior, consider these factors
when assessing the proper buffer size for an application:
There is a tradeoff between number of calls to
audit_log_read()
and events returned per call:With a smaller buffer size, calls return fewer events, so more calls are needed.
With a larger buffer size, calls return more events, so fewer calls are needed.
With a smaller buffer size, such as the default size of 32KB, there is a greater chance for events to exceed the buffer size and thus to be skipped.
Prior to MySQL 8.0.12,
audit_log_read_buffer_size
has
a default of 1MB, affects all clients, and can be changed only
at server startup.
For additional information about audit log-reading functions, see Audit Log Functions.