From 32e48bdb1aad7e81fb126847ff3bec0c35709aff Mon Sep 17 00:00:00 2001 From: Joseph Koshakow Date: Mon, 16 Oct 2023 10:24:54 -0400 Subject: [PATCH] sql: Implement SHOW PRIVILEGES command (#22393) This commit implements a SHOW PRIVILEGES command that allow users to display all privileges. The command allows optional filtering on object type or role grantee. Works towards resolving #20452 --- doc/user/content/sql/grant-privilege.md | 1 + doc/user/content/sql/revoke-privilege.md | 1 + doc/user/content/sql/show-privileges.md | 78 +++++++++++++ .../partials/sql-grammar/show-privileges.svg | 107 ++++++++++++++++++ doc/user/sql-grammar/sql-grammar.bnf | 2 + src/sql-parser/src/ast/defs/statement.rs | 38 ++++++- src/sql-parser/src/parser.rs | 65 +++++++++++ src/sql-parser/tests/testdata/show | 49 ++++++++ src/sql/src/plan/statement/show.rs | 53 ++++++++- test/sqllogictest/rbac_views.slt | 87 ++++++++++++++ 10 files changed, 479 insertions(+), 2 deletions(-) create mode 100644 doc/user/content/sql/show-privileges.md create mode 100644 doc/user/layouts/partials/sql-grammar/show-privileges.svg diff --git a/doc/user/content/sql/grant-privilege.md b/doc/user/content/sql/grant-privilege.md index 3674203bbc8f2..68c325ac9ec52 100644 --- a/doc/user/content/sql/grant-privilege.md +++ b/doc/user/content/sql/grant-privilege.md @@ -112,6 +112,7 @@ The privileges required to execute this statement are: ## Related pages +- [SHOW PRIVILEGES](../show-privileges) - [CREATE ROLE](../create-role) - [ALTER ROLE](../alter-role) - [DROP ROLE](../drop-role) diff --git a/doc/user/content/sql/revoke-privilege.md b/doc/user/content/sql/revoke-privilege.md index d6d0bcf2079aa..db39e79382629 100644 --- a/doc/user/content/sql/revoke-privilege.md +++ b/doc/user/content/sql/revoke-privilege.md @@ -113,6 +113,7 @@ The privileges required to execute this statement are: ## Related pages +- [SHOW PRIVILEGES](../show-privileges) - [CREATE ROLE](../create-role) - [ALTER ROLE](../alter-role) - [DROP ROLE](../drop-role) diff --git a/doc/user/content/sql/show-privileges.md b/doc/user/content/sql/show-privileges.md new file mode 100644 index 0000000000000..4fd6268bc04c3 --- /dev/null +++ b/doc/user/content/sql/show-privileges.md @@ -0,0 +1,78 @@ +--- +title: "SHOW PRIVILEGES" +description: "`SHOW PRIVILEGES` lists the privileges granted in Materialize." +menu: + main: + parent: 'commands' + +--- + +`SHOW PRIVILEGES` lists the privileges granted as part of [access control](/manage/access-control/) in Materialize. + +## Syntax + +{{< diagram "show-privileges.svg" >}} + +Field | Use +----------------------------------------------------|-------------------------------------------------- +_object_name_ | Only shows privileges for a specific object type. +_role_name_ | Only shows privileges granted directly or indirectly to _role_name_. + +## Examples + +```sql +SHOW PRIVILEGES; +``` + +```nofmt + grantor | grantee | database | schema | name | object_type | privilege_type +-----------+-------------+-------------+--------+-------------+-------------+---------------- + mz_system | PUBLIC | materialize | | public | schema | USAGE + mz_system | PUBLIC | | | default | cluster | USAGE + mz_system | PUBLIC | | | materialize | database | USAGE + mz_system | materialize | materialize | | public | schema | CREATE + mz_system | materialize | materialize | | public | schema | USAGE + mz_system | materialize | | | default | cluster | CREATE + mz_system | materialize | | | default | cluster | USAGE + mz_system | materialize | | | materialize | database | CREATE + mz_system | materialize | | | materialize | database | USAGE + mz_system | materialize | | | | system | CREATECLUSTER + mz_system | materialize | | | | system | CREATEDB + mz_system | materialize | | | | system | CREATEROLE +``` + +```sql +SHOW PRIVILEGES ON SCHEMAS; +``` + +```nofmt + grantor | grantee | database | schema | name | object_type | privilege_type +-----------+-------------+-------------+--------+--------+-------------+---------------- + mz_system | PUBLIC | materialize | | public | schema | USAGE + mz_system | materialize | materialize | | public | schema | CREATE + mz_system | materialize | materialize | | public | schema | USAGE +``` + +```sql +SHOW PRIVILEGES FOR materialize; +``` + +```nofmt + grantor | grantee | database | schema | name | object_type | privilege_type +-----------+-------------+-------------+--------+-------------+-------------+---------------- + mz_system | materialize | materialize | | public | schema | CREATE + mz_system | materialize | materialize | | public | schema | USAGE + mz_system | materialize | | | default | cluster | CREATE + mz_system | materialize | | | default | cluster | USAGE + mz_system | materialize | | | materialize | database | CREATE + mz_system | materialize | | | materialize | database | USAGE + mz_system | materialize | | | | system | CREATECLUSTER + mz_system | materialize | | | | system | CREATEDB + mz_system | materialize | | | | system | CREATEROLE +``` + +## Related pages + +- [GRANT PRIVILEGE](../grant-privilege) +- [REVOKE PRIVILEGE](../revoke-privilege) +- [access control](/manage/access-control/) diff --git a/doc/user/layouts/partials/sql-grammar/show-privileges.svg b/doc/user/layouts/partials/sql-grammar/show-privileges.svg new file mode 100644 index 0000000000000..6ca7658dea7e0 --- /dev/null +++ b/doc/user/layouts/partials/sql-grammar/show-privileges.svg @@ -0,0 +1,107 @@ + + + + + + SHOW + + + PRIVILEGES + + + ON + + + TABLES + + + TYPES + + + SECRETS + + + CONNECTIONS + + + DATABASES + + + SCHEMAS + + + CLUSTERS + + + SYSTEM + + + FOR + + + role_name + + + + diff --git a/doc/user/sql-grammar/sql-grammar.bnf b/doc/user/sql-grammar/sql-grammar.bnf index abd34cbf20ee5..38e8deabe5497 100644 --- a/doc/user/sql-grammar/sql-grammar.bnf +++ b/doc/user/sql-grammar/sql-grammar.bnf @@ -437,6 +437,8 @@ show_views ::= 'SHOW' 'VIEWS' ('FROM' schema_name)? show_objects ::= 'SHOW' 'OBJECTS' ('FROM' schema_name)? +show_privileges ::= + 'SHOW' 'PRIVILEGES' ('ON' ('TABLES' | 'TYPES' | 'SECRETS' | 'CONNECTIONS' | 'DATABASES' | 'SCHEMAS' | 'CLUSTERS' | 'SYSTEM'))? ('FOR' role_name)? string_agg ::= 'string_agg' '(' value ',' delimiter ( 'ORDER' 'BY' col_ref ( 'ASC' | 'DESC' )? ( 'NULLS LAST' | 'NULLS FIRST' )? ( ',' col_ref ( 'ASC' | 'DESC' )? ( 'NULLS LAST' | 'NULLS FIRST' )? )* )? ')' ('FILTER' '(' 'WHERE' filter_clause ')')? subscribe_stmt ::= diff --git a/src/sql-parser/src/ast/defs/statement.rs b/src/sql-parser/src/ast/defs/statement.rs index c3597a7c7359f..913667f1755cf 100644 --- a/src/sql-parser/src/ast/defs/statement.rs +++ b/src/sql-parser/src/ast/defs/statement.rs @@ -2448,6 +2448,10 @@ pub enum ShowObjectType { Subsource { on_source: Option, }, + Privileges { + object_type: Option, + role: Option, + }, } /// `SHOW S` /// @@ -2468,6 +2472,7 @@ impl AstDisplay for ShowObjectsStatement { fn fmt(&self, f: &mut AstFormatter) { f.write_str("SHOW"); f.write_str(" "); + f.write_str(match &self.object_type { ShowObjectType::Table => "TABLES", ShowObjectType::View => "VIEWS", @@ -2485,6 +2490,7 @@ impl AstDisplay for ShowObjectsStatement { ShowObjectType::Database => "DATABASES", ShowObjectType::Schema { .. } => "SCHEMAS", ShowObjectType::Subsource { .. } => "SUBSOURCES", + ShowObjectType::Privileges { .. } => "PRIVILEGES", }); if let ShowObjectType::Index { on_object, .. } = &self.object_type { @@ -2525,6 +2531,20 @@ impl AstDisplay for ShowObjectsStatement { } } + if let ShowObjectType::Privileges { object_type, role } = &self.object_type { + if let Some(object_type) = object_type { + f.write_str(" ON "); + f.write_node(object_type); + if let SystemObjectType::Object(_) = object_type { + f.write_str("S"); + } + } + if let Some(role) = role { + f.write_str(" FOR "); + f.write_node(role); + } + } + if let Some(filter) = &self.filter { f.write_str(" "); f.write_node(filter); @@ -2864,7 +2884,7 @@ impl AstDisplay for InsertSource { } impl_display_t!(InsertSource); -#[derive(Debug, Clone, PartialEq, Eq, Hash, Copy)] +#[derive(Debug, Clone, PartialEq, Eq, Hash, PartialOrd, Ord, Copy)] pub enum ObjectType { Table, View, @@ -2931,6 +2951,22 @@ impl AstDisplay for ObjectType { } impl_display!(ObjectType); +#[derive(Debug, Clone, PartialEq, Eq, Hash, PartialOrd, Ord, Copy)] +pub enum SystemObjectType { + System, + Object(ObjectType), +} + +impl AstDisplay for SystemObjectType { + fn fmt(&self, f: &mut AstFormatter) { + match self { + SystemObjectType::System => f.write_str("SYSTEM"), + SystemObjectType::Object(object) => f.write_node(object), + } + } +} +impl_display!(SystemObjectType); + #[derive(Debug, Clone, PartialEq, Eq, Hash, PartialOrd, Ord)] pub enum ShowStatementFilter { Like(String), diff --git a/src/sql-parser/src/parser.rs b/src/sql-parser/src/parser.rs index 17e06b5310f78..38c1e68af598d 100644 --- a/src/sql-parser/src/parser.rs +++ b/src/sql-parser/src/parser.rs @@ -6345,6 +6345,8 @@ impl<'a> Parser<'a> { Ok(ShowStatement::ShowVariable(ShowVariableStatement { variable: Ident::from("cluster"), })) + } else if self.parse_keyword(PRIVILEGES) { + self.parse_show_privileges() } else if self.parse_keywords(&[CREATE, VIEW]) { Ok(ShowStatement::ShowCreateView(ShowCreateViewStatement { view_name: self.parse_raw_name()?, @@ -6418,6 +6420,24 @@ impl<'a> Parser<'a> { } } + fn parse_show_privileges(&mut self) -> Result, ParserError> { + let object_type = if self.parse_keyword(ON) { + Some(self.expect_plural_system_object_type_for_privileges()?) + } else { + None + }; + let role = if self.parse_keyword(FOR) { + Some(self.parse_identifier()?) + } else { + None + }; + Ok(ShowStatement::ShowObjects(ShowObjectsStatement { + object_type: ShowObjectType::Privileges { object_type, role }, + from: None, + filter: self.parse_show_statement_filter()?, + })) + } + fn parse_inspect(&mut self) -> Result, ParserError> { self.expect_keyword(SHARD)?; let id = self.parse_literal_string()?; @@ -7678,6 +7698,51 @@ impl<'a> Parser<'a> { ) } + /// Bail out if the current token is not a privilege object type in the plural form, or consume and + /// return it if it is. + fn expect_plural_system_object_type_for_privileges( + &mut self, + ) -> Result { + if let Some(object_type) = self.parse_one_of_keywords(&[VIEWS, SOURCES]) { + return parser_err!( + self, + self.peek_prev_pos(), + format!("For object type {object_type}, you must specify 'TABLES'") + ); + } + if self.parse_keywords(&[MATERIALIZED, VIEWS]) { + self.prev_token(); + return parser_err!( + self, + self.peek_prev_pos(), + format!("For object type MATERIALIZED VIEWS, you must specify 'TABLES'") + ); + } + + Ok( + match self.expect_one_of_keywords(&[ + SYSTEM, + TABLES, + TYPES, + CLUSTERS, + SECRETS, + CONNECTIONS, + DATABASES, + SCHEMAS, + ])? { + SYSTEM => SystemObjectType::System, + TABLES => SystemObjectType::Object(ObjectType::Table), + TYPES => SystemObjectType::Object(ObjectType::Type), + CLUSTERS => SystemObjectType::Object(ObjectType::Cluster), + SECRETS => SystemObjectType::Object(ObjectType::Secret), + CONNECTIONS => SystemObjectType::Object(ObjectType::Connection), + DATABASES => SystemObjectType::Object(ObjectType::Database), + SCHEMAS => SystemObjectType::Object(ObjectType::Schema), + _ => unreachable!(), + }, + ) + } + /// Look for a privilege and return it if it matches. fn parse_privilege(&mut self) -> Option { Some( diff --git a/src/sql-parser/tests/testdata/show b/src/sql-parser/tests/testdata/show index b04478e7f33fb..7b5a401896613 100644 --- a/src/sql-parser/tests/testdata/show +++ b/src/sql-parser/tests/testdata/show @@ -686,3 +686,52 @@ SHOW CONNECTIONS SHOW CONNECTIONS => Show(ShowObjects(ShowObjectsStatement { object_type: Connection, from: None, filter: None })) + +parse-statement +SHOW PRIVILEGES +---- +SHOW PRIVILEGES +=> +Show(ShowObjects(ShowObjectsStatement { object_type: Privileges { object_type: None, role: None }, from: None, filter: None })) + +parse-statement +SHOW PRIVILEGES ON TABLES +---- +SHOW PRIVILEGES ON TABLES +=> +Show(ShowObjects(ShowObjectsStatement { object_type: Privileges { object_type: Some(Object(Table)), role: None }, from: None, filter: None })) + +parse-statement +SHOW PRIVILEGES FOR joe +---- +SHOW PRIVILEGES FOR joe +=> +Show(ShowObjects(ShowObjectsStatement { object_type: Privileges { object_type: None, role: Some(Ident("joe")) }, from: None, filter: None })) + +parse-statement +SHOW PRIVILEGES ON CLUSTERS FOR mike +---- +SHOW PRIVILEGES ON CLUSTERS FOR mike +=> +Show(ShowObjects(ShowObjectsStatement { object_type: Privileges { object_type: Some(Object(Cluster)), role: Some(Ident("mike")) }, from: None, filter: None })) + +parse-statement +SHOW PRIVILEGES ON SYSTEM +---- +SHOW PRIVILEGES ON SYSTEM +=> +Show(ShowObjects(ShowObjectsStatement { object_type: Privileges { object_type: Some(System), role: None }, from: None, filter: None })) + +parse-statement +SHOW PRIVILEGES ON MATERIALIZED VIEWS +---- +error: For object type MATERIALIZED VIEWS, you must specify 'TABLES' +SHOW PRIVILEGES ON MATERIALIZED VIEWS + ^ + +parse-statement +SHOW PRIVILEGES ON SOURCES +---- +error: For object type SOURCES, you must specify 'TABLES' +SHOW PRIVILEGES ON SOURCES + ^ diff --git a/src/sql/src/plan/statement/show.rs b/src/sql/src/plan/statement/show.rs index fa6b79bdddec0..fb95e9956be4b 100644 --- a/src/sql/src/plan/statement/show.rs +++ b/src/sql/src/plan/statement/show.rs @@ -20,6 +20,7 @@ use mz_repr::{Datum, GlobalId, RelationDesc, Row, ScalarType}; use mz_sql_parser::ast::display::AstDisplay; use mz_sql_parser::ast::{ ShowCreateConnectionStatement, ShowCreateMaterializedViewStatement, ShowObjectType, + SystemObjectType, }; use query::QueryContext; @@ -32,7 +33,7 @@ use crate::ast::{ use crate::catalog::{CatalogItemType, SessionCatalog}; use crate::names::{ self, Aug, NameSimplifier, ResolvedClusterName, ResolvedDatabaseName, ResolvedIds, - ResolvedItemName, ResolvedSchemaName, + ResolvedItemName, ResolvedRoleName, ResolvedSchemaName, }; use crate::parse; use crate::plan::scope::Scope; @@ -338,6 +339,10 @@ pub fn show_objects<'a>( assert!(from.is_none(), "parser should reject from"); show_schemas(scx, db_from, filter) } + ShowObjectType::Privileges { object_type, role } => { + assert!(from.is_none(), "parser should reject from"); + show_privileges(scx, object_type, role, filter) + } } } @@ -694,6 +699,52 @@ pub fn show_secrets<'a>( ShowSelect::new(scx, query, filter, None, Some(&["name"])) } +pub fn show_privileges<'a>( + scx: &'a StatementContext<'a>, + object_type: Option, + role: Option, + filter: Option>, +) -> Result, PlanError> { + let mut query_filter = Vec::new(); + if let Some(object_type) = object_type { + query_filter.push(format!( + "object_type = '{}'", + object_type.to_string().to_lowercase() + )); + } + if let Some(role) = role { + let name = role.name; + query_filter.push(format!("CASE WHEN grantee = 'PUBLIC' THEN true ELSE pg_has_role('{name}', grantee, 'USAGE') END")); + } + let query_filter = if query_filter.len() > 0 { + format!("WHERE {}", itertools::join(query_filter, " AND ")) + } else { + "".to_string() + }; + + let query = format!( + "SELECT grantor, grantee, database, schema, name, object_type, privilege_type + FROM mz_internal.mz_show_all_privileges + {query_filter}", + ); + + ShowSelect::new( + scx, + query, + filter, + None, + Some(&[ + "grantor", + "grantee", + "database", + "schema", + "name", + "object_type", + "privilege_type", + ]), + ) +} + /// An intermediate result when planning a `SHOW` query. /// /// Can be interrogated for its columns, or converted into a proper [`Plan`]. diff --git a/test/sqllogictest/rbac_views.slt b/test/sqllogictest/rbac_views.slt index 81bda59e13d9a..31f7def93c571 100644 --- a/test/sqllogictest/rbac_views.slt +++ b/test/sqllogictest/rbac_views.slt @@ -355,6 +355,93 @@ materialize,r1,materialize,public,t,table,SELECT materialize,r2,materialize,public,t,table,SELECT COMPLETE 23 +query TTTTTTT +SELECT * FROM (SHOW PRIVILEGES) ORDER BY object_type, database, schema, name, grantee +---- +materialize PUBLIC NULL NULL c cluster USAGE +materialize materialize NULL NULL c cluster USAGE +materialize materialize NULL NULL c cluster CREATE +materialize r1 NULL NULL c cluster USAGE +materialize r3 NULL NULL c cluster USAGE +materialize r3 NULL NULL c cluster CREATE +materialize r4 NULL NULL c cluster CREATE +mz_system PUBLIC NULL NULL default cluster USAGE +mz_system materialize NULL NULL default cluster USAGE +mz_system materialize NULL NULL default cluster CREATE +materialize PUBLIC NULL NULL d database CREATE +materialize materialize NULL NULL d database USAGE +materialize materialize NULL NULL d database CREATE +materialize r1 NULL NULL d database USAGE +materialize r1 NULL NULL d database CREATE +materialize r2 NULL NULL d database USAGE +materialize r4 NULL NULL d database CREATE +mz_system PUBLIC NULL NULL materialize database USAGE +mz_system materialize NULL NULL materialize database USAGE +mz_system materialize NULL NULL materialize database CREATE +materialize PUBLIC d NULL public schema USAGE +materialize materialize d NULL public schema USAGE +materialize materialize d NULL public schema CREATE +mz_system PUBLIC materialize NULL public schema USAGE +mz_system materialize materialize NULL public schema USAGE +mz_system materialize materialize NULL public schema CREATE +materialize PUBLIC materialize NULL s schema USAGE +materialize materialize materialize NULL s schema USAGE +materialize materialize materialize NULL s schema CREATE +materialize r1 materialize NULL s schema USAGE +materialize r3 materialize NULL s schema USAGE +materialize r5 materialize NULL s schema USAGE +materialize r5 materialize NULL s schema CREATE +mz_system PUBLIC NULL NULL NULL system CREATECLUSTER +mz_system materialize NULL NULL NULL system CREATEDB +mz_system materialize NULL NULL NULL system CREATEROLE +mz_system materialize NULL NULL NULL system CREATECLUSTER +mz_system r1 NULL NULL NULL system CREATEDB +mz_system r1 NULL NULL NULL system CREATECLUSTER +mz_system r2 NULL NULL NULL system CREATEROLE +mz_system r4 NULL NULL NULL system CREATECLUSTER +materialize PUBLIC materialize public t table INSERT +materialize materialize materialize public t table DELETE +materialize materialize materialize public t table INSERT +materialize materialize materialize public t table SELECT +materialize materialize materialize public t table UPDATE +materialize r1 materialize public t table INSERT +materialize r1 materialize public t table SELECT +materialize r2 materialize public t table SELECT +materialize r5 materialize public t table DELETE + +query TTTTTTT +SELECT * FROM (SHOW PRIVILEGES ON CLUSTERS) ORDER BY object_type, database, schema, name, grantee +---- +materialize PUBLIC NULL NULL c cluster USAGE +materialize materialize NULL NULL c cluster USAGE +materialize materialize NULL NULL c cluster CREATE +materialize r1 NULL NULL c cluster USAGE +materialize r3 NULL NULL c cluster USAGE +materialize r3 NULL NULL c cluster CREATE +materialize r4 NULL NULL c cluster CREATE +mz_system PUBLIC NULL NULL default cluster USAGE +mz_system materialize NULL NULL default cluster USAGE +mz_system materialize NULL NULL default cluster CREATE + +query TTTTTTT +SELECT * FROM (SHOW PRIVILEGES FOR r2) ORDER BY object_type, database, schema, name, grantee +---- +materialize PUBLIC NULL NULL c cluster USAGE +materialize r3 NULL NULL c cluster USAGE +materialize r3 NULL NULL c cluster CREATE +mz_system PUBLIC NULL NULL default cluster USAGE +materialize PUBLIC NULL NULL d database CREATE +materialize r2 NULL NULL d database USAGE +mz_system PUBLIC NULL NULL materialize database USAGE +materialize PUBLIC d NULL public schema USAGE +mz_system PUBLIC materialize NULL public schema USAGE +materialize PUBLIC materialize NULL s schema USAGE +materialize r3 materialize NULL s schema USAGE +mz_system PUBLIC NULL NULL NULL system CREATECLUSTER +mz_system r2 NULL NULL NULL system CREATEROLE +materialize PUBLIC materialize public t table INSERT +materialize r2 materialize public t table SELECT + # SHOW DEFAULT PRIVILEGES statement ok