1
0
mirror of https://github.com/MariaDB/server.git synced 2025-07-30 16:24:05 +03:00

MDEV-24486 Add table_privileges view to the sys schema

The existing INFORMATION_SCHEMA.TABLE_PRIVILEGES displays only those
privileges that were specifically granted on the table level,
whereas it may be useful to see privileges granted at the database
and global level.

This commit adds a new view `table_privileges` to the `sys` schema
for that purpose. The view shows privileges on existing tables
and views, combining all possible levels:
 - user_privileges
 - schema_privileges
 - table_privileges
This commit is contained in:
Oleg Smirnov
2023-11-16 16:54:16 +07:00
parent 6b2287fff2
commit 1a5e69b42b
30 changed files with 341 additions and 12 deletions

View File

@ -38,6 +38,7 @@ ${CMAKE_CURRENT_SOURCE_DIR}/views/i_s/schema_object_overview.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/i_s/schema_auto_increment_columns.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/i_s/x_schema_flattened_keys.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/i_s/schema_redundant_indexes.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/i_s/table_privileges.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/p_s/ps_check_lost_instrumentation_57.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/p_s/latest_file_io.sql
${CMAKE_CURRENT_SOURCE_DIR}/views/p_s/x_latest_file_io.sql

View File

@ -1,6 +1,13 @@
# Change history for the MySQL sys schema
## 1.5.1 (07/07/16)
## 1.5.2 (2023-11-20)
### Improvements
* A new `table_privileges` view was added, which displays privileges on tables granted at all levels (user, schema, table)
## 1.5.1 (2016-07-07)
### Improvements
@ -24,7 +31,7 @@
* Oracle Bug #21970806 - The `sysschema.fn_ps_thread_trx_info` test was unstable
* Oracle Bug #23621189 - The `ps_trace_statement_digest` procedure ran EXPLAIN incorrectly in certain cases (such as on a SHOW statement, no query being specified, or not having a full qualified table), the procedure now catches these issues and ignores them
## 1.5.0 (11/09/15)
## 1.5.0 (2015-09-11)
### Improvements
@ -84,7 +91,7 @@
* Template files were added for stored procedures and functions
* Improved the sys_config_cleanup.inc procedure in tests to be able to reset the sys_config table completely (including the set_by column to NULL). The triggers can now be set to not update the column by setting the @sys.ignore_sys_config_triggers user variable to true
## 1.4.0 (09/03/2015)
## 1.4.0 (2015-03-09)
### Backwards Incompatible Changes
@ -126,7 +133,7 @@ Various changes were made to allow better generation of integration sql files:
* Each object has been created within it's own file. No longer do x$ views live with their non-x$ counterparts
* DELIMITERs were standardized to $$
## 1.3.0 (23/10/2014)
## 1.3.0 (2014-10-23)
### Improvements
@ -136,7 +143,7 @@ Various changes were made to allow better generation of integration sql files:
* Fixed broken `host_summary_by_stages` views, broken with a last minute change before the 1.2.0 release that went unnoticed (facepalm)
## 1.2.0 (22/10/2014)
## 1.2.0 (2014-10-22)
### Backwards Incompatible Changes
@ -163,7 +170,7 @@ Various changes were made to allow better generation of integration sql files:
* Added missing space for hour notation within the `format_time` function
* Fixed views affected by MySQL 5.7 ONLY_FULL_GROUP_BY and functional dependency changes
## 1.1.0 (04/09/2014)
## 1.1.0 (2014-09-04)
### Improvements
@ -195,7 +202,7 @@ Various changes were made to allow better generation of integration sql files:
* Fixed the RETURN datatype `extract_schema_from_file_name` and `extract_table_from_file_name` to return a VARCHAR(64) (**Contributed by Jesper Wisborg Krogh**)
* Added events_transactions_current to the default enabled consumers in 5.7 (#25)
## 1.0.1 (23/05/2014)
## 1.0.1 (2014-05-23)
### Improvements
@ -215,4 +222,4 @@ Various changes were made to allow better generation of integration sql files:
* Some views did not work with the ERROR_FOR_DIVISION_BY_ZERO SQL mode. (#6) (**Contributed by Joe Grasse**)
* On Windows the `ps_thread_stack()` stored function failed to escape file path backslashes correctly within the JSON output.
## 1.0.0 (11/04/2014)
## 1.0.0 (2014-04-11)

View File

@ -1635,6 +1635,59 @@ mysql> select * from schema_object_overview;
10 rows in set (1.58 sec)
```
#### table_privileges
##### Description
-- Shows privileges on existing tables and views granted at all possible levels:
-- - user_privileges
-- - schema_privileges
-- - table_privileges
##### Structure
```SQL
MariaDB [test]> desc sys.table_privileges;
+--------------+--------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+--------------+--------------+------+-----+---------+-------+
| TABLE_SCHEMA | varchar(64) | NO | | NULL | |
| TABLE_NAME | varchar(64) | NO | | NULL | |
| GRANTEE | varchar(385) | NO | | | |
| PRIVILEGE | varchar(64) | NO | | | |
| LEVEL | varchar(6) | NO | | | |
+--------------+--------------+------+-----+---------+-------+
5 rows in set (0.002 sec)
```
##### Example
```SQL
mysql> select * from sys.table_privileges;
+--------------+------------+--------------------+----------------+--------+
| TABLE_SCHEMA | TABLE_NAME | GRANTEE | PRIVILEGE_TYPE | LEVEL |
+--------------+------------+--------------------+----------------+--------+
| test | v1 | 'oleg'@'localhost' | SELECT | GLOBAL |
| test | t1 | 'oleg'@'localhost' | SELECT | GLOBAL |
| test | v1 | 'oleg'@'localhost' | INSERT | GLOBAL |
| test | t1 | 'oleg'@'localhost' | INSERT | GLOBAL |
| test | v1 | 'oleg'@'localhost' | UPDATE | GLOBAL |
| test | v1 | 'PUBLIC'@'' | SELECT | SCHEMA |
| test | t1 | 'PUBLIC'@'' | SELECT | SCHEMA |
| test | v1 | 'PUBLIC'@'' | INSERT | SCHEMA |
| test | t1 | 'PUBLIC'@'' | INSERT | SCHEMA |
| test | v1 | 'PUBLIC'@'' | UPDATE | SCHEMA |
| test | t1 | 'PUBLIC'@'' | UPDATE | SCHEMA |
| test | v1 | 'PUBLIC'@'' | DELETE HISTORY | SCHEMA |
| test | t1 | 'PUBLIC'@'' | DELETE HISTORY | SCHEMA |
| test | t1 | 'oleg'@'%' | SELECT | TABLE |
| test | t1 | 'oleg'@'%' | UPDATE | TABLE |
| test | v1 | 'oleg'@'%' | SELECT | TABLE |
+--------------+------------+--------------------+----------------+--------+
16 rows in set (1.58 sec)
```
#### schema_table_statistics / x$schema_table_statistics
##### Description

View File

@ -55,6 +55,7 @@ SOURCE ./views/i_s/schema_object_overview.sql
SOURCE ./views/i_s/schema_auto_increment_columns.sql
SOURCE ./views/i_s/x_schema_flattened_keys.sql
SOURCE ./views/i_s/schema_redundant_indexes.sql
SOURCE ./views/i_s/table_privileges.sql
SOURCE ./views/p_s/ps_check_lost_instrumentation.sql
SOURCE ./views/p_s/processlist.sql

View File

@ -56,6 +56,7 @@ SOURCE ./views/i_s/schema_object_overview.sql
SOURCE ./views/i_s/schema_auto_increment_columns.sql
SOURCE ./views/i_s/x_schema_flattened_keys.sql
SOURCE ./views/i_s/schema_redundant_indexes.sql
SOURCE ./views/i_s/table_privileges.sql
SOURCE ./views/p_s/ps_check_lost_instrumentation_57.sql

View File

@ -0,0 +1,76 @@
--
-- View: table_privileges
--
-- Shows privileges on existing tables and views granted at all possible levels:
-- - user_privileges
-- - schema_privileges
-- - table_privileges
--
-- mysql> select * from sys.table_privileges;
-- +--------------+------------+--------------------+----------------+--------+
-- | TABLE_SCHEMA | TABLE_NAME | GRANTEE | PRIVILEGE_TYPE | LEVEL |
-- +--------------+------------+--------------------+----------------+--------+
-- | test | v1 | 'oleg'@'localhost' | SELECT | GLOBAL |
-- | test | t1 | 'oleg'@'localhost' | SELECT | GLOBAL |
-- | test | v1 | 'oleg'@'localhost' | INSERT | GLOBAL |
-- | test | t1 | 'oleg'@'localhost' | INSERT | GLOBAL |
-- | test | v1 | 'oleg'@'localhost' | UPDATE | GLOBAL |
-- | test | v1 | 'PUBLIC'@'' | SELECT | SCHEMA |
-- | test | t1 | 'PUBLIC'@'' | SELECT | SCHEMA |
-- | test | v1 | 'PUBLIC'@'' | INSERT | SCHEMA |
-- | test | t1 | 'PUBLIC'@'' | INSERT | SCHEMA |
-- | test | v1 | 'PUBLIC'@'' | UPDATE | SCHEMA |
-- | test | t1 | 'PUBLIC'@'' | UPDATE | SCHEMA |
-- | test | v1 | 'PUBLIC'@'' | DELETE HISTORY | SCHEMA |
-- | test | t1 | 'PUBLIC'@'' | DELETE HISTORY | SCHEMA |
-- | test | t1 | 'oleg'@'%' | SELECT | TABLE |
-- | test | t1 | 'oleg'@'%' | UPDATE | TABLE |
-- | test | v1 | 'oleg'@'%' | SELECT | TABLE |
-- +--------------+------------+--------------------+----------------+--------+
CREATE OR REPLACE
ALGORITHM = TEMPTABLE
DEFINER = 'mariadb.sys'@'localhost'
SQL SECURITY INVOKER
VIEW table_privileges (
TABLE_SCHEMA,
TABLE_NAME,
GRANTEE,
PRIVILEGE,
LEVEL
) AS
SELECT t.TABLE_SCHEMA,
t.TABLE_NAME,
privs.GRANTEE,
privs.PRIVILEGE_TYPE,
privs.LEVEL
FROM INFORMATION_SCHEMA.TABLES AS t
JOIN ( SELECT NULL AS TABLE_SCHEMA,
NULL AS TABLE_NAME,
GRANTEE,
PRIVILEGE_TYPE,
'GLOBAL' LEVEL
FROM INFORMATION_SCHEMA.USER_PRIVILEGES
UNION
SELECT TABLE_SCHEMA,
NULL AS TABLE_NAME,
GRANTEE,
PRIVILEGE_TYPE,
'SCHEMA' LEVEL
FROM INFORMATION_SCHEMA.SCHEMA_PRIVILEGES
UNION
SELECT TABLE_SCHEMA,
TABLE_NAME,
GRANTEE,
PRIVILEGE_TYPE,
'TABLE' LEVEL
FROM INFORMATION_SCHEMA.TABLE_PRIVILEGES
) privs
ON (t.TABLE_SCHEMA = privs.TABLE_SCHEMA OR privs.TABLE_SCHEMA IS NULL)
AND (t.TABLE_NAME = privs.TABLE_NAME OR privs.TABLE_NAME IS NULL)
AND privs.PRIVILEGE_TYPE IN ('SELECT', 'INSERT', 'UPDATE', 'DELETE',
'CREATE', 'ALTER', 'DROP', 'INDEX',
'REFERENCES', 'TRIGGER', 'GRANT OPTION',
'SHOW VIEW', 'DELETE HISTORY')
WHERE t.TABLE_SCHEMA NOT IN ('sys', 'mysql','information_schema',
'performance_schema');

View File

@ -33,5 +33,5 @@ VIEW version (
sys_version,
mysql_version
) AS
SELECT '1.5.1' AS sys_version,
version() AS mysql_version;
SELECT '1.5.2' AS sys_version,
version() AS mysql_version;