Adds grant/revoke privileges on database propagation (#7109)

DESCRIPTION: Adds grant/revoke propagation support for database
privileges

Following the implementation of support for granting and revoking
database privileges, certain tests that issued grants for worker nodes
experienced failures. These ones are fixed in this PR as well.
pull/7140/head
Gürkan İndibay 2023-08-24 14:43:19 +03:00 committed by GitHub
parent 553780e3f1
commit 8d3a06c1c7
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
15 changed files with 1544 additions and 69 deletions

View File

@ -31,6 +31,8 @@
static AlterOwnerStmt * RecreateAlterDatabaseOwnerStmt(Oid databaseOid);
static Oid get_database_owner(Oid db_oid);
List * PreprocessGrantOnDatabaseStmt(Node *node, const char *queryString,
ProcessUtilityContext processUtilityContext);
/* controlled via GUC */
bool EnableAlterDatabaseOwner = true;
@ -107,3 +109,41 @@ get_database_owner(Oid db_oid)
return dba;
}
/*
* PreprocessGrantOnDatabaseStmt is executed before the statement is applied to the local
* postgres instance.
*
* In this stage we can prepare the commands that need to be run on all workers to grant
* on databases.
*/
List *
PreprocessGrantOnDatabaseStmt(Node *node, const char *queryString,
ProcessUtilityContext processUtilityContext)
{
if (!ShouldPropagate())
{
return NIL;
}
GrantStmt *stmt = castNode(GrantStmt, node);
Assert(stmt->objtype == OBJECT_DATABASE);
List *databaseList = stmt->objects;
if (list_length(databaseList) == 0)
{
return NIL;
}
EnsureCoordinator();
char *sql = DeparseTreeNode((Node *) stmt);
List *commands = list_make3(DISABLE_DDL_PROPAGATION,
(void *) sql,
ENABLE_DDL_PROPAGATION);
return NodeDDLTaskList(NON_COORDINATOR_NODES, commands);
}

View File

@ -432,6 +432,18 @@ static DistributeObjectOps Database_AlterOwner = {
.address = AlterDatabaseOwnerObjectAddress,
.markDistributed = false,
};
static DistributeObjectOps Database_Grant = {
.deparse = DeparseGrantOnDatabaseStmt,
.qualify = NULL,
.preprocess = PreprocessGrantOnDatabaseStmt,
.postprocess = NULL,
.objectType = OBJECT_DATABASE,
.operationType = DIST_OPS_ALTER,
.address = NULL,
.markDistributed = false,
};
static DistributeObjectOps Domain_Alter = {
.deparse = DeparseAlterDomainStmt,
.qualify = QualifyAlterDomainStmt,
@ -1911,6 +1923,11 @@ GetDistributeObjectOps(Node *node)
return &Routine_Grant;
}
case OBJECT_DATABASE:
{
return &Database_Grant;
}
default:
{
return &Any_Grant;

View File

@ -49,3 +49,79 @@ AppendAlterDatabaseOwnerStmt(StringInfo buf, AlterOwnerStmt *stmt)
quote_identifier(strVal((String *) stmt->object)),
RoleSpecString(stmt->newowner, true));
}
static void
AppendGrantDatabases(StringInfo buf, GrantStmt *stmt)
{
ListCell *cell = NULL;
appendStringInfo(buf, " ON DATABASE ");
foreach(cell, stmt->objects)
{
char *database = strVal(lfirst(cell));
appendStringInfoString(buf, quote_identifier(database));
if (cell != list_tail(stmt->objects))
{
appendStringInfo(buf, ", ");
}
}
}
static void
AppendGrantOnDatabaseStmt(StringInfo buf, GrantStmt *stmt)
{
Assert(stmt->objtype == OBJECT_DATABASE);
appendStringInfo(buf, "%s ", stmt->is_grant ? "GRANT" : "REVOKE");
if (!stmt->is_grant && stmt->grant_option)
{
appendStringInfo(buf, "GRANT OPTION FOR ");
}
AppendGrantPrivileges(buf, stmt);
AppendGrantDatabases(buf, stmt);
AppendGrantGrantees(buf, stmt);
if (stmt->is_grant && stmt->grant_option)
{
appendStringInfo(buf, " WITH GRANT OPTION");
}
if (!stmt->is_grant)
{
if (stmt->behavior == DROP_RESTRICT)
{
appendStringInfo(buf, " RESTRICT");
}
else if (stmt->behavior == DROP_CASCADE)
{
appendStringInfo(buf, " CASCADE");
}
}
if (stmt->grantor)
{
appendStringInfo(buf, " GRANTED BY %s", RoleSpecString(stmt->grantor, true));
}
appendStringInfo(buf, ";");
}
char *
DeparseGrantOnDatabaseStmt(Node *node)
{
GrantStmt *stmt = castNode(GrantStmt, node);
Assert(stmt->objtype == OBJECT_DATABASE);
StringInfoData str = { 0 };
initStringInfo(&str);
AppendGrantOnDatabaseStmt(&str, stmt);
return str.data;
}

View File

@ -220,6 +220,9 @@ extern List * AlterDatabaseOwnerObjectAddress(Node *node, bool missing_ok, bool
isPostprocess);
extern List * DatabaseOwnerDDLCommands(const ObjectAddress *address);
extern List * PreprocessGrantOnDatabaseStmt(Node *node, const char *queryString,
ProcessUtilityContext processUtilityContext);
/* domain.c - forward declarations */
extern List * CreateDomainStmtObjectAddress(Node *node, bool missing_ok, bool
isPostprocess);
@ -235,6 +238,7 @@ extern List * RenameDomainStmtObjectAddress(Node *node, bool missing_ok, bool
extern CreateDomainStmt * RecreateDomainStmt(Oid domainOid);
extern Oid get_constraint_typid(Oid conoid);
/* extension.c - forward declarations */
extern bool IsDropCitusExtensionStmt(Node *parsetree);
extern List * GetDependentFDWsToExtension(Oid extensionId);

View File

@ -210,6 +210,7 @@ extern char * DeparseAlterExtensionStmt(Node *stmt);
/* forward declarations for deparse_database_stmts.c */
extern char * DeparseAlterDatabaseOwnerStmt(Node *node);
extern char * DeparseGrantOnDatabaseStmt(Node *node);
/* forward declaration for deparse_publication_stmts.c */
extern char * DeparseCreatePublicationStmt(Node *stmt);

View File

@ -0,0 +1,967 @@
-- Public role has connect,temp,temporary privileges on database
-- To test these scenarios, we need to revoke these privileges from public role
-- since public role privileges are inherited by new roles/users
revoke connect,temp,temporary on database regression from public;
CREATE SCHEMA grant_on_database_propagation;
SET search_path TO grant_on_database_propagation;
-- test grant/revoke CREATE privilege propagation on database
create user myuser;
grant create on database regression to myuser;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
revoke create on database regression from myuser;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
drop user myuser;
---------------------------------------------------------------------
-- test grant/revoke CONNECT privilege propagation on database
create user myuser;
grant CONNECT on database regression to myuser;
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
revoke connect on database regression from myuser;
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
drop user myuser;
---------------------------------------------------------------------
-- test grant/revoke TEMP privilege propagation on database
create user myuser;
-- test grant/revoke temp on database
grant TEMP on database regression to myuser;
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
revoke TEMP on database regression from myuser;
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
drop user myuser;
---------------------------------------------------------------------
-- test temporary privilege on database
create user myuser;
-- test grant/revoke temporary on database
grant TEMPORARY on database regression to myuser;
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
revoke TEMPORARY on database regression from myuser;
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
drop user myuser;
---------------------------------------------------------------------
-- test ALL privileges with ALL statement on database
create user myuser;
grant ALL on database regression to myuser;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
revoke ALL on database regression from myuser;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
drop user myuser;
---------------------------------------------------------------------
-- test CREATE,CONNECT,TEMP,TEMPORARY privileges one by one on database
create user myuser;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
RESET ROLE;
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
drop user myuser;
---------------------------------------------------------------------
-- test CREATE,CONNECT,TEMP,TEMPORARY privileges one by one on database with grant option
create user myuser;
create user myuser_1;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser;
set role myuser;
--here since myuser does not have grant option, it should fail
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser_1;
WARNING: no privileges were granted for "regression"
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
RESET ROLE;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser with grant option;
set role myuser;
--here since myuser have grant option, it should succeed
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser_1 granted by myuser;
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
RESET ROLE;
--below test should fail and should throw an error since myuser_1 still have the dependent privileges
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser restrict;
ERROR: dependent privileges exist
HINT: Use CASCADE to revoke them too.
--below test should fail and should throw an error since myuser_1 still have the dependent privileges
revoke grant option for CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser restrict ;
ERROR: dependent privileges exist
HINT: Use CASCADE to revoke them too.
--below test should succeed and should not throw any error since myuser_1 privileges are revoked with cascade
revoke grant option for CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser cascade ;
--here we test if myuser still have the privileges after revoke grant option for
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
reset role;
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser;
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser_1;
drop user myuser_1;
drop user myuser;
---------------------------------------------------------------------
-- test CREATE,CONNECT,TEMP,TEMPORARY privileges one by one on database multi database
-- and multi user
create user myuser;
create user myuser_1;
create database test_db;
NOTICE: Citus partially supports CREATE DATABASE for distributed databases
DETAIL: Citus does not propagate CREATE DATABASE command to workers
HINT: You can manually create a database and its extensions on workers.
SELECT result FROM run_command_on_workers($$create database test_db$$);
result
---------------------------------------------------------------------
CREATE DATABASE
CREATE DATABASE
(2 rows)
revoke connect,temp,temporary on database test_db from public;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db to myuser,myuser_1;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
t
(1 row)
\c - - - :master_port
RESET ROLE;
--below test should fail and should throw an error
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db from myuser ;
--below test should succeed and should not throw any error
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db from myuser_1;
--below test should succeed and should not throw any error
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db from myuser cascade;
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'CREATE');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'CONNECT');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMP');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
has_database_privilege
---------------------------------------------------------------------
f
(1 row)
\c - - - :master_port
reset role;
drop user myuser_1;
drop user myuser;
drop database test_db;
SELECT result FROM run_command_on_workers($$drop database test_db$$);
result
---------------------------------------------------------------------
DROP DATABASE
DROP DATABASE
(2 rows)
---------------------------------------------------------------------
-- rollbacks public role database privileges to original state
grant connect,temp,temporary on database regression to public;
SET client_min_messages TO ERROR;
DROP SCHEMA grant_on_database_propagation CASCADE;
---------------------------------------------------------------------

View File

@ -572,13 +572,6 @@ WARNING: Query could not find the intermediate result file "squares_2", it was
-- test refreshing mat views
SET client_min_messages TO ERROR;
CREATE USER some_other_user;
SELECT run_command_on_workers($$GRANT ALL ON DATABASE regression TO some_other_user;$$);
run_command_on_workers
---------------------------------------------------------------------
(localhost,57637,t,GRANT)
(localhost,57638,t,GRANT)
(2 rows)
GRANT ALL ON DATABASE regression TO some_other_user;
RESET client_min_messages;
\c - some_other_user

View File

@ -12,6 +12,8 @@ SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15;
t
(1 row)
CREATE SCHEMA multi_deparse_shard_query;
SET search_path TO multi_deparse_shard_query;
SET citus.next_shard_id TO 13100000;
SET citus.shard_replication_factor TO 1;
CREATE FUNCTION deparse_shard_query_test(text)
@ -74,7 +76,7 @@ SELECT deparse_shard_query_test('
INSERT INTO raw_events_1
SELECT * FROM raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_1, value_2, value_3, value_4, value_5, value_6, value_7, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_1, raw_events_1_1.value_2, raw_events_1_1.value_3, raw_events_1_1.value_4, raw_events_1_1.value_5, raw_events_1_1.value_6, raw_events_1_1.value_7, raw_events_1_1.event_at FROM public.raw_events_1 raw_events_1_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_1, value_2, value_3, value_4, value_5, value_6, value_7, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_1, raw_events_1_1.value_2, raw_events_1_1.value_3, raw_events_1_1.value_4, raw_events_1_1.value_5, raw_events_1_1.value_6, raw_events_1_1.value_7, raw_events_1_1.event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -87,7 +89,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_4, value_6, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_4, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1 raw_events_1_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_4, value_6, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_4, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -101,7 +103,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT raw_events_1_1.tenant_id, (raw_events_1_1.value_5)::integer AS value_5, raw_events_1_1.value_4, (raw_events_1_1.value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1 raw_events_1_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT raw_events_1_1.tenant_id, (raw_events_1_1.value_5)::integer AS value_5, raw_events_1_1.value_4, (raw_events_1_1.value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -115,7 +117,7 @@ SELECT
FROM
raw_events_2;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT raw_events_2.tenant_id, (raw_events_2.value_5)::integer AS value_5, raw_events_2.value_4, (raw_events_2.value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_2
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT raw_events_2.tenant_id, (raw_events_2.value_5)::integer AS value_5, raw_events_2.value_4, (raw_events_2.value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_2
deparse_shard_query_test
---------------------------------------------------------------------
@ -131,7 +133,7 @@ FROM
GROUP BY
tenant_id, date_trunc(\'hour\', event_at)
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, average_value_3, sum_value_4, average_value_6, rollup_hour) SELECT raw_events_1.tenant_id, sum(raw_events_1.value_1) AS sum, avg(raw_events_1.value_3) AS avg, sum(raw_events_1.value_4) AS sum, avg(raw_events_1.value_6) AS avg, date_trunc('hour'::text, (raw_events_1.event_at)::timestamp with time zone) AS date_trunc FROM public.raw_events_1 GROUP BY raw_events_1.tenant_id, (date_trunc('hour'::text, (raw_events_1.event_at)::timestamp with time zone))
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, average_value_3, sum_value_4, average_value_6, rollup_hour) SELECT raw_events_1.tenant_id, sum(raw_events_1.value_1) AS sum, avg(raw_events_1.value_3) AS avg, sum(raw_events_1.value_4) AS sum, avg(raw_events_1.value_6) AS avg, date_trunc('hour'::text, (raw_events_1.event_at)::timestamp with time zone) AS date_trunc FROM multi_deparse_shard_query.raw_events_1 GROUP BY raw_events_1.tenant_id, (date_trunc('hour'::text, (raw_events_1.event_at)::timestamp with time zone))
deparse_shard_query_test
---------------------------------------------------------------------
@ -148,7 +150,7 @@ FROM
WHERE
raw_events_1.tenant_id = raw_events_2.tenant_id;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT raw_events_1_1.tenant_id, raw_events_2.value_3, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1 raw_events_1_1, public.raw_events_2 WHERE (raw_events_1_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT raw_events_1_1.tenant_id, raw_events_2.value_3, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1, multi_deparse_shard_query.raw_events_2 WHERE (raw_events_1_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)
deparse_shard_query_test
---------------------------------------------------------------------
@ -164,7 +166,7 @@ FROM
WHERE
raw_events_1.tenant_id = raw_events_2.tenant_id GROUP BY raw_events_1.event_at
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT avg(raw_events_1_1.value_3) AS avg, max(raw_events_2.value_3) AS max, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1 raw_events_1_1, public.raw_events_2 WHERE (raw_events_1_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id) GROUP BY raw_events_1_1.event_at
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT avg(raw_events_1_1.value_3) AS avg, max(raw_events_2.value_3) AS max, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1, multi_deparse_shard_query.raw_events_2 WHERE (raw_events_1_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id) GROUP BY raw_events_1_1.event_at
deparse_shard_query_test
---------------------------------------------------------------------
@ -184,7 +186,7 @@ GROUP BY
ORDER BY
r2.event_at DESC;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_4) SELECT r3.tenant_id, max(r1.value_4) AS max FROM public.raw_events_1 r1, public.raw_events_2 r2, public.raw_events_1 r3 WHERE ((r1.tenant_id OPERATOR(pg_catalog.=) r2.tenant_id) AND (r2.tenant_id OPERATOR(pg_catalog.=) r3.tenant_id)) GROUP BY r1.value_1, r3.tenant_id, r2.event_at ORDER BY r2.event_at DESC
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_4) SELECT r3.tenant_id, max(r1.value_4) AS max FROM multi_deparse_shard_query.raw_events_1 r1, multi_deparse_shard_query.raw_events_2 r2, multi_deparse_shard_query.raw_events_1 r3 WHERE ((r1.tenant_id OPERATOR(pg_catalog.=) r2.tenant_id) AND (r2.tenant_id OPERATOR(pg_catalog.=) r3.tenant_id)) GROUP BY r1.value_1, r3.tenant_id, r2.event_at ORDER BY r2.event_at DESC
deparse_shard_query_test
---------------------------------------------------------------------
@ -201,7 +203,7 @@ FROM
GROUP BY
event_at, tenant_id;
');
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM public.raw_events_1) INSERT INTO public.aggregated_events (tenant_id, sum_value_5, rollup_hour) SELECT raw_events_1.tenant_id, sum((raw_events_1.value_5)::integer) AS sum, raw_events_1.event_at FROM public.raw_events_1 GROUP BY raw_events_1.event_at, raw_events_1.tenant_id
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM multi_deparse_shard_query.raw_events_1) INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_5, rollup_hour) SELECT raw_events_1.tenant_id, sum((raw_events_1.value_5)::integer) AS sum, raw_events_1.event_at FROM multi_deparse_shard_query.raw_events_1 GROUP BY raw_events_1.event_at, raw_events_1.tenant_id
deparse_shard_query_test
---------------------------------------------------------------------
@ -217,7 +219,7 @@ FROM
GROUP BY
event_at, tenant_id;
');
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM public.raw_events_1) INSERT INTO public.aggregated_events (tenant_id, sum_value_5) SELECT raw_events_1.tenant_id, sum((raw_events_1.value_5)::integer) AS sum FROM public.raw_events_1 GROUP BY raw_events_1.event_at, raw_events_1.tenant_id
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM multi_deparse_shard_query.raw_events_1) INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_5) SELECT raw_events_1.tenant_id, sum((raw_events_1.value_5)::integer) AS sum FROM multi_deparse_shard_query.raw_events_1 GROUP BY raw_events_1.event_at, raw_events_1.tenant_id
deparse_shard_query_test
---------------------------------------------------------------------
@ -236,7 +238,7 @@ WITH RECURSIVE hierarchy as (
h.value_1 = re.value_6))
SELECT * FROM hierarchy WHERE LEVEL <= 2;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, sum_value_5) WITH RECURSIVE hierarchy AS (SELECT raw_events_1.value_1, 1 AS level, raw_events_1.tenant_id FROM public.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) 1) UNION SELECT re.value_2, (h.level OPERATOR(pg_catalog.+) 1), re.tenant_id FROM (hierarchy h JOIN public.raw_events_1 re ON (((h.tenant_id OPERATOR(pg_catalog.=) re.tenant_id) AND (h.value_1 OPERATOR(pg_catalog.=) re.value_6))))) SELECT hierarchy.tenant_id, hierarchy.value_1, hierarchy.level FROM hierarchy WHERE (hierarchy.level OPERATOR(pg_catalog.<=) 2)
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, sum_value_5) WITH RECURSIVE hierarchy AS (SELECT raw_events_1.value_1, 1 AS level, raw_events_1.tenant_id FROM multi_deparse_shard_query.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) 1) UNION SELECT re.value_2, (h.level OPERATOR(pg_catalog.+) 1), re.tenant_id FROM (hierarchy h JOIN multi_deparse_shard_query.raw_events_1 re ON (((h.tenant_id OPERATOR(pg_catalog.=) re.tenant_id) AND (h.value_1 OPERATOR(pg_catalog.=) re.value_6))))) SELECT hierarchy.tenant_id, hierarchy.value_1, hierarchy.level FROM hierarchy WHERE (hierarchy.level OPERATOR(pg_catalog.<=) 2)
deparse_shard_query_test
---------------------------------------------------------------------
@ -249,7 +251,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.aggregated_events (sum_value_1) SELECT DISTINCT raw_events_1.value_1 FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (sum_value_1) SELECT DISTINCT raw_events_1.value_1 FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -262,7 +264,7 @@ SELECT value_3, value_2, tenant_id
FROM raw_events_1
WHERE (value_5 like \'%s\' or value_5 like \'%a\') and (tenant_id = 1) and (value_6 < 3000 or value_3 > 8000);
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT raw_events_1.tenant_id, raw_events_1.value_2, raw_events_1.value_3 FROM public.raw_events_1 WHERE (((raw_events_1.value_5 OPERATOR(pg_catalog.~~) '%s'::text) OR (raw_events_1.value_5 OPERATOR(pg_catalog.~~) '%a'::text)) AND (raw_events_1.tenant_id OPERATOR(pg_catalog.=) 1) AND ((raw_events_1.value_6 OPERATOR(pg_catalog.<) 3000) OR (raw_events_1.value_3 OPERATOR(pg_catalog.>) (8000)::double precision)))
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT raw_events_1.tenant_id, raw_events_1.value_2, raw_events_1.value_3 FROM multi_deparse_shard_query.raw_events_1 WHERE (((raw_events_1.value_5 OPERATOR(pg_catalog.~~) '%s'::text) OR (raw_events_1.value_5 OPERATOR(pg_catalog.~~) '%a'::text)) AND (raw_events_1.tenant_id OPERATOR(pg_catalog.=) 1) AND ((raw_events_1.value_6 OPERATOR(pg_catalog.<) 3000) OR (raw_events_1.value_3 OPERATOR(pg_catalog.>) (8000)::double precision)))
deparse_shard_query_test
---------------------------------------------------------------------
@ -274,7 +276,7 @@ SELECT rank() OVER (PARTITION BY tenant_id ORDER BY value_6), tenant_id
FROM raw_events_1
WHERE event_at = now();
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_5) SELECT raw_events_1.tenant_id, rank() OVER (PARTITION BY raw_events_1.tenant_id ORDER BY raw_events_1.value_6) AS rank FROM public.raw_events_1 WHERE (raw_events_1.event_at OPERATOR(pg_catalog.=) now())
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_5) SELECT raw_events_1.tenant_id, rank() OVER (PARTITION BY raw_events_1.tenant_id ORDER BY raw_events_1.value_6) AS rank FROM multi_deparse_shard_query.raw_events_1 WHERE (raw_events_1.event_at OPERATOR(pg_catalog.=) now())
deparse_shard_query_test
---------------------------------------------------------------------
@ -287,7 +289,7 @@ SELECT random(), int4eq(1, max(value_1))::int, value_6
WHERE event_at = now()
GROUP BY event_at, value_7, value_6;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_4, sum_value_5) SELECT (int4eq(1, max(raw_events_1.value_1)))::integer AS int4eq, raw_events_1.value_6, random() AS random FROM public.raw_events_1 WHERE (raw_events_1.event_at OPERATOR(pg_catalog.=) now()) GROUP BY raw_events_1.event_at, raw_events_1.value_7, raw_events_1.value_6
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_4, sum_value_5) SELECT (int4eq(1, max(raw_events_1.value_1)))::integer AS int4eq, raw_events_1.value_6, random() AS random FROM multi_deparse_shard_query.raw_events_1 WHERE (raw_events_1.event_at OPERATOR(pg_catalog.=) now()) GROUP BY raw_events_1.event_at, raw_events_1.value_7, raw_events_1.value_6
deparse_shard_query_test
---------------------------------------------------------------------
@ -308,7 +310,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1) SELECT max(raw_events_1.tenant_id) AS max, count(DISTINCT CASE WHEN (raw_events_1.value_1 OPERATOR(pg_catalog.>) 100) THEN raw_events_1.tenant_id ELSE (raw_events_1.value_6)::bigint END) AS c FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1) SELECT max(raw_events_1.tenant_id) AS max, count(DISTINCT CASE WHEN (raw_events_1.value_1 OPERATOR(pg_catalog.>) 100) THEN raw_events_1.tenant_id ELSE (raw_events_1.value_6)::bigint END) AS c FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -325,7 +327,7 @@ FROM
raw_events_2
) as foo
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_1, value_6, value_7, event_at) SELECT foo.tenant_id, foo.value_1, 10 AS value_6, foo.value_7, (now())::date AS event_at FROM (SELECT raw_events_2.tenant_id, raw_events_2.value_2 AS value_7, raw_events_2.value_1 FROM public.raw_events_2) foo
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_1, value_6, value_7, event_at) SELECT foo.tenant_id, foo.value_1, 10 AS value_6, foo.value_7, (now())::date AS event_at FROM (SELECT raw_events_2.tenant_id, raw_events_2.value_2 AS value_7, raw_events_2.value_1 FROM multi_deparse_shard_query.raw_events_2) foo
deparse_shard_query_test
---------------------------------------------------------------------
@ -346,7 +348,7 @@ FROM
GROUP BY
tenant_id, date_trunc(\'hour\', event_at)
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT foo.tenant_id, sum(foo.value_1) AS sum, sum((foo.value_5)::bigint) AS sum FROM (SELECT raw_events_1.event_at, raw_events_2.tenant_id, raw_events_2.value_5, raw_events_1.value_1 FROM public.raw_events_2, public.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)) foo GROUP BY foo.tenant_id, (date_trunc('hour'::text, (foo.event_at)::timestamp with time zone))
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT foo.tenant_id, sum(foo.value_1) AS sum, sum((foo.value_5)::bigint) AS sum FROM (SELECT raw_events_1.event_at, raw_events_2.tenant_id, raw_events_2.value_5, raw_events_1.value_1 FROM multi_deparse_shard_query.raw_events_2, multi_deparse_shard_query.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)) foo GROUP BY foo.tenant_id, (date_trunc('hour'::text, (foo.event_at)::timestamp with time zone))
deparse_shard_query_test
---------------------------------------------------------------------
@ -363,7 +365,7 @@ FROM
raw_events_1
) as foo
');
INFO: query: INSERT INTO public.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT foo.tenant_id, foo.value_1, foo.value_2, foo.value_3, foo.value_4, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM public.raw_events_1) foo
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT foo.tenant_id, foo.value_1, foo.value_2, foo.value_3, foo.value_4, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM multi_deparse_shard_query.raw_events_1) foo
deparse_shard_query_test
---------------------------------------------------------------------
@ -380,7 +382,7 @@ FROM
raw_events_1
) as foo
');
INFO: query: INSERT INTO public.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT foo.value_2, foo.value_4, foo.value_1, foo.value_3, foo.tenant_id, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM public.raw_events_1) foo
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT foo.value_2, foo.value_4, foo.value_1, foo.value_3, foo.tenant_id, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM multi_deparse_shard_query.raw_events_1) foo
deparse_shard_query_test
---------------------------------------------------------------------
@ -396,7 +398,7 @@ FROM
ORDER BY
value_2, value_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_7, 10 AS value_6, raw_events_1_1.value_7, (now())::date AS event_at FROM public.raw_events_1 raw_events_1_1 ORDER BY raw_events_1_1.value_2, raw_events_1_1.value_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_7, 10 AS value_6, raw_events_1_1.value_7, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1 ORDER BY raw_events_1_1.value_2, raw_events_1_1.value_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -411,9 +413,11 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_4, 10 AS value_6, raw_events_1_1.value_7, (now())::date AS event_at FROM public.raw_events_1 raw_events_1_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT raw_events_1_1.tenant_id, raw_events_1_1.value_4, 10 AS value_6, raw_events_1_1.value_7, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 raw_events_1_1
deparse_shard_query_test
---------------------------------------------------------------------
(1 row)
SET client_min_messages TO ERROR;
DROP SCHEMA multi_deparse_shard_query CASCADE;

View File

@ -12,6 +12,8 @@ SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15;
f
(1 row)
CREATE SCHEMA multi_deparse_shard_query;
SET search_path TO multi_deparse_shard_query;
SET citus.next_shard_id TO 13100000;
SET citus.shard_replication_factor TO 1;
CREATE FUNCTION deparse_shard_query_test(text)
@ -74,7 +76,7 @@ SELECT deparse_shard_query_test('
INSERT INTO raw_events_1
SELECT * FROM raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_1, value_2, value_3, value_4, value_5, value_6, value_7, event_at) SELECT tenant_id, value_1, value_2, value_3, value_4, value_5, value_6, value_7, event_at FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_1, value_2, value_3, value_4, value_5, value_6, value_7, event_at) SELECT tenant_id, value_1, value_2, value_3, value_4, value_5, value_6, value_7, event_at FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -87,7 +89,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_4, value_6, event_at) SELECT tenant_id, value_4, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_4, value_6, event_at) SELECT tenant_id, value_4, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -101,7 +103,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT tenant_id, (value_5)::integer AS value_5, value_4, (value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT tenant_id, (value_5)::integer AS value_5, value_4, (value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -115,7 +117,7 @@ SELECT
FROM
raw_events_2;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT tenant_id, (value_5)::integer AS value_5, value_4, (value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_2
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_2, value_4, value_5, value_6, event_at) SELECT tenant_id, (value_5)::integer AS value_5, value_4, (value_2)::text AS value_2, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_2
deparse_shard_query_test
---------------------------------------------------------------------
@ -131,7 +133,7 @@ FROM
GROUP BY
tenant_id, date_trunc(\'hour\', event_at)
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, average_value_3, sum_value_4, average_value_6, rollup_hour) SELECT tenant_id, sum(value_1) AS sum, avg(value_3) AS avg, sum(value_4) AS sum, avg(value_6) AS avg, date_trunc('hour'::text, (event_at)::timestamp with time zone) AS date_trunc FROM public.raw_events_1 GROUP BY tenant_id, (date_trunc('hour'::text, (event_at)::timestamp with time zone))
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, average_value_3, sum_value_4, average_value_6, rollup_hour) SELECT tenant_id, sum(value_1) AS sum, avg(value_3) AS avg, sum(value_4) AS sum, avg(value_6) AS avg, date_trunc('hour'::text, (event_at)::timestamp with time zone) AS date_trunc FROM multi_deparse_shard_query.raw_events_1 GROUP BY tenant_id, (date_trunc('hour'::text, (event_at)::timestamp with time zone))
deparse_shard_query_test
---------------------------------------------------------------------
@ -148,7 +150,7 @@ FROM
WHERE
raw_events_1.tenant_id = raw_events_2.tenant_id;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT raw_events_1.tenant_id, raw_events_2.value_3, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1, public.raw_events_2 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT raw_events_1.tenant_id, raw_events_2.value_3, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1, multi_deparse_shard_query.raw_events_2 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)
deparse_shard_query_test
---------------------------------------------------------------------
@ -164,7 +166,7 @@ FROM
WHERE
raw_events_1.tenant_id = raw_events_2.tenant_id GROUP BY raw_events_1.event_at
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT avg(raw_events_1.value_3) AS avg, max(raw_events_2.value_3) AS max, 10 AS value_6, (now())::date AS event_at FROM public.raw_events_1, public.raw_events_2 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id) GROUP BY raw_events_1.event_at
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_3, value_6, event_at) SELECT avg(raw_events_1.value_3) AS avg, max(raw_events_2.value_3) AS max, 10 AS value_6, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1, multi_deparse_shard_query.raw_events_2 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id) GROUP BY raw_events_1.event_at
deparse_shard_query_test
---------------------------------------------------------------------
@ -184,7 +186,7 @@ GROUP BY
ORDER BY
r2.event_at DESC;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_4) SELECT r3.tenant_id, max(r1.value_4) AS max FROM public.raw_events_1 r1, public.raw_events_2 r2, public.raw_events_1 r3 WHERE ((r1.tenant_id OPERATOR(pg_catalog.=) r2.tenant_id) AND (r2.tenant_id OPERATOR(pg_catalog.=) r3.tenant_id)) GROUP BY r1.value_1, r3.tenant_id, r2.event_at ORDER BY r2.event_at DESC
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_4) SELECT r3.tenant_id, max(r1.value_4) AS max FROM multi_deparse_shard_query.raw_events_1 r1, multi_deparse_shard_query.raw_events_2 r2, multi_deparse_shard_query.raw_events_1 r3 WHERE ((r1.tenant_id OPERATOR(pg_catalog.=) r2.tenant_id) AND (r2.tenant_id OPERATOR(pg_catalog.=) r3.tenant_id)) GROUP BY r1.value_1, r3.tenant_id, r2.event_at ORDER BY r2.event_at DESC
deparse_shard_query_test
---------------------------------------------------------------------
@ -201,7 +203,7 @@ FROM
GROUP BY
event_at, tenant_id;
');
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM public.raw_events_1) INSERT INTO public.aggregated_events (tenant_id, sum_value_5, rollup_hour) SELECT tenant_id, sum((value_5)::integer) AS sum, event_at FROM public.raw_events_1 GROUP BY event_at, tenant_id
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM multi_deparse_shard_query.raw_events_1) INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_5, rollup_hour) SELECT tenant_id, sum((value_5)::integer) AS sum, event_at FROM multi_deparse_shard_query.raw_events_1 GROUP BY event_at, tenant_id
deparse_shard_query_test
---------------------------------------------------------------------
@ -217,7 +219,7 @@ FROM
GROUP BY
event_at, tenant_id;
');
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM public.raw_events_1) INSERT INTO public.aggregated_events (tenant_id, sum_value_5) SELECT tenant_id, sum((value_5)::integer) AS sum FROM public.raw_events_1 GROUP BY event_at, tenant_id
INFO: query: WITH first_tenant AS (SELECT raw_events_1.event_at, raw_events_1.value_5, raw_events_1.tenant_id FROM multi_deparse_shard_query.raw_events_1) INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_5) SELECT tenant_id, sum((value_5)::integer) AS sum FROM multi_deparse_shard_query.raw_events_1 GROUP BY event_at, tenant_id
deparse_shard_query_test
---------------------------------------------------------------------
@ -236,7 +238,7 @@ WITH RECURSIVE hierarchy as (
h.value_1 = re.value_6))
SELECT * FROM hierarchy WHERE LEVEL <= 2;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, sum_value_5) WITH RECURSIVE hierarchy AS (SELECT raw_events_1.value_1, 1 AS level, raw_events_1.tenant_id FROM public.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) 1) UNION SELECT re.value_2, (h.level OPERATOR(pg_catalog.+) 1), re.tenant_id FROM (hierarchy h JOIN public.raw_events_1 re ON (((h.tenant_id OPERATOR(pg_catalog.=) re.tenant_id) AND (h.value_1 OPERATOR(pg_catalog.=) re.value_6))))) SELECT tenant_id, value_1, level FROM hierarchy WHERE (level OPERATOR(pg_catalog.<=) 2)
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, sum_value_5) WITH RECURSIVE hierarchy AS (SELECT raw_events_1.value_1, 1 AS level, raw_events_1.tenant_id FROM multi_deparse_shard_query.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) 1) UNION SELECT re.value_2, (h.level OPERATOR(pg_catalog.+) 1), re.tenant_id FROM (hierarchy h JOIN multi_deparse_shard_query.raw_events_1 re ON (((h.tenant_id OPERATOR(pg_catalog.=) re.tenant_id) AND (h.value_1 OPERATOR(pg_catalog.=) re.value_6))))) SELECT tenant_id, value_1, level FROM hierarchy WHERE (level OPERATOR(pg_catalog.<=) 2)
deparse_shard_query_test
---------------------------------------------------------------------
@ -249,7 +251,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.aggregated_events (sum_value_1) SELECT DISTINCT value_1 FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (sum_value_1) SELECT DISTINCT value_1 FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -262,7 +264,7 @@ SELECT value_3, value_2, tenant_id
FROM raw_events_1
WHERE (value_5 like \'%s\' or value_5 like \'%a\') and (tenant_id = 1) and (value_6 < 3000 or value_3 > 8000);
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT tenant_id, value_2, value_3 FROM public.raw_events_1 WHERE (((value_5 OPERATOR(pg_catalog.~~) '%s'::text) OR (value_5 OPERATOR(pg_catalog.~~) '%a'::text)) AND (tenant_id OPERATOR(pg_catalog.=) 1) AND ((value_6 OPERATOR(pg_catalog.<) 3000) OR (value_3 OPERATOR(pg_catalog.>) (8000)::double precision)))
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT tenant_id, value_2, value_3 FROM multi_deparse_shard_query.raw_events_1 WHERE (((value_5 OPERATOR(pg_catalog.~~) '%s'::text) OR (value_5 OPERATOR(pg_catalog.~~) '%a'::text)) AND (tenant_id OPERATOR(pg_catalog.=) 1) AND ((value_6 OPERATOR(pg_catalog.<) 3000) OR (value_3 OPERATOR(pg_catalog.>) (8000)::double precision)))
deparse_shard_query_test
---------------------------------------------------------------------
@ -274,7 +276,7 @@ SELECT rank() OVER (PARTITION BY tenant_id ORDER BY value_6), tenant_id
FROM raw_events_1
WHERE event_at = now();
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_5) SELECT tenant_id, rank() OVER (PARTITION BY tenant_id ORDER BY value_6) AS rank FROM public.raw_events_1 WHERE (event_at OPERATOR(pg_catalog.=) now())
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_5) SELECT tenant_id, rank() OVER (PARTITION BY tenant_id ORDER BY value_6) AS rank FROM multi_deparse_shard_query.raw_events_1 WHERE (event_at OPERATOR(pg_catalog.=) now())
deparse_shard_query_test
---------------------------------------------------------------------
@ -287,7 +289,7 @@ SELECT random(), int4eq(1, max(value_1))::int, value_6
WHERE event_at = now()
GROUP BY event_at, value_7, value_6;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_4, sum_value_5) SELECT (int4eq(1, max(value_1)))::integer AS int4eq, value_6, random() AS random FROM public.raw_events_1 WHERE (event_at OPERATOR(pg_catalog.=) now()) GROUP BY event_at, value_7, value_6
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_4, sum_value_5) SELECT (int4eq(1, max(value_1)))::integer AS int4eq, value_6, random() AS random FROM multi_deparse_shard_query.raw_events_1 WHERE (event_at OPERATOR(pg_catalog.=) now()) GROUP BY event_at, value_7, value_6
deparse_shard_query_test
---------------------------------------------------------------------
@ -308,7 +310,7 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1) SELECT max(tenant_id) AS max, count(DISTINCT CASE WHEN (value_1 OPERATOR(pg_catalog.>) 100) THEN tenant_id ELSE (value_6)::bigint END) AS c FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1) SELECT max(tenant_id) AS max, count(DISTINCT CASE WHEN (value_1 OPERATOR(pg_catalog.>) 100) THEN tenant_id ELSE (value_6)::bigint END) AS c FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -325,7 +327,7 @@ FROM
raw_events_2
) as foo
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_1, value_6, value_7, event_at) SELECT tenant_id, value_1, 10 AS value_6, value_7, (now())::date AS event_at FROM (SELECT raw_events_2.tenant_id, raw_events_2.value_2 AS value_7, raw_events_2.value_1 FROM public.raw_events_2) foo
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_1, value_6, value_7, event_at) SELECT tenant_id, value_1, 10 AS value_6, value_7, (now())::date AS event_at FROM (SELECT raw_events_2.tenant_id, raw_events_2.value_2 AS value_7, raw_events_2.value_1 FROM multi_deparse_shard_query.raw_events_2) foo
deparse_shard_query_test
---------------------------------------------------------------------
@ -341,12 +343,12 @@ FROM
FROM
raw_events_2, raw_events_1
WHERE
raw_events_1.tenant_id = raw_events_2.tenant_id
raw_events_1.tenant_id = raw_events_2.tenant_id
) as foo
GROUP BY
tenant_id, date_trunc(\'hour\', event_at)
');
INFO: query: INSERT INTO public.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT tenant_id, sum(value_1) AS sum, sum((value_5)::bigint) AS sum FROM (SELECT raw_events_1.event_at, raw_events_2.tenant_id, raw_events_2.value_5, raw_events_1.value_1 FROM public.raw_events_2, public.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)) foo GROUP BY tenant_id, (date_trunc('hour'::text, (event_at)::timestamp with time zone))
INFO: query: INSERT INTO multi_deparse_shard_query.aggregated_events (tenant_id, sum_value_1, sum_value_5) SELECT tenant_id, sum(value_1) AS sum, sum((value_5)::bigint) AS sum FROM (SELECT raw_events_1.event_at, raw_events_2.tenant_id, raw_events_2.value_5, raw_events_1.value_1 FROM multi_deparse_shard_query.raw_events_2, multi_deparse_shard_query.raw_events_1 WHERE (raw_events_1.tenant_id OPERATOR(pg_catalog.=) raw_events_2.tenant_id)) foo GROUP BY tenant_id, (date_trunc('hour'::text, (event_at)::timestamp with time zone))
deparse_shard_query_test
---------------------------------------------------------------------
@ -363,7 +365,7 @@ FROM
raw_events_1
) as foo
');
INFO: query: INSERT INTO public.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT tenant_id, value_1, value_2, value_3, value_4, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM public.raw_events_1) foo
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT tenant_id, value_1, value_2, value_3, value_4, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM multi_deparse_shard_query.raw_events_1) foo
deparse_shard_query_test
---------------------------------------------------------------------
@ -380,7 +382,7 @@ FROM
raw_events_1
) as foo
');
INFO: query: INSERT INTO public.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT value_2, value_4, value_1, value_3, tenant_id, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM public.raw_events_1) foo
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_2 (tenant_id, value_1, value_2, value_3, value_4, value_6, event_at) SELECT value_2, value_4, value_1, value_3, tenant_id, (random() OPERATOR(pg_catalog.*) (100)::double precision) AS value_6, (now())::date AS event_at FROM (SELECT raw_events_1.value_2, raw_events_1.value_4, raw_events_1.tenant_id, raw_events_1.value_1, raw_events_1.value_3 FROM multi_deparse_shard_query.raw_events_1) foo
deparse_shard_query_test
---------------------------------------------------------------------
@ -396,7 +398,7 @@ FROM
ORDER BY
value_2, value_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT tenant_id, value_7, 10 AS value_6, value_7, (now())::date AS event_at FROM public.raw_events_1 ORDER BY value_2, value_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT tenant_id, value_7, 10 AS value_6, value_7, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1 ORDER BY value_2, value_1
deparse_shard_query_test
---------------------------------------------------------------------
@ -411,9 +413,11 @@ SELECT
FROM
raw_events_1;
');
INFO: query: INSERT INTO public.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT tenant_id, value_4, 10 AS value_6, value_7, (now())::date AS event_at FROM public.raw_events_1
INFO: query: INSERT INTO multi_deparse_shard_query.raw_events_1 (tenant_id, value_4, value_6, value_7, event_at) SELECT tenant_id, value_4, 10 AS value_6, value_7, (now())::date AS event_at FROM multi_deparse_shard_query.raw_events_1
deparse_shard_query_test
---------------------------------------------------------------------
(1 row)
SET client_min_messages TO ERROR;
DROP SCHEMA multi_deparse_shard_query CASCADE;

View File

@ -1345,13 +1345,6 @@ DROP USER test_other_super_user;
CREATE ROLE test_non_super_user WITH LOGIN;
ALTER ROLE test_non_super_user NOSUPERUSER;
GRANT CREATE ON DATABASE regression TO test_non_super_user;
SELECT result FROM run_command_on_workers($$GRANT CREATE ON DATABASE regression TO test_non_super_user$$);
result
---------------------------------------------------------------------
GRANT
GRANT
(2 rows)
GRANT CREATE ON SCHEMA public TO test_non_super_user ;
\c - test_non_super_user
SET search_path TO regular_schema;
@ -1487,13 +1480,6 @@ $$);
\c - postgres
REVOKE CREATE ON DATABASE regression FROM test_non_super_user;
SELECT result FROM run_command_on_workers($$REVOKE CREATE ON DATABASE regression FROM test_non_super_user$$);
result
---------------------------------------------------------------------
REVOKE
REVOKE
(2 rows)
REVOKE CREATE ON SCHEMA public FROM test_non_super_user;
DROP ROLE test_non_super_user;
\c - - - :worker_1_port

View File

@ -50,6 +50,8 @@ test: multi_metadata_attributes
test: multi_read_from_secondaries
test: grant_on_database_propagation
# ----------
# multi_citus_tools tests utility functions written for citus tools
# ----------

View File

@ -0,0 +1,378 @@
-- Public role has connect,temp,temporary privileges on database
-- To test these scenarios, we need to revoke these privileges from public role
-- since public role privileges are inherited by new roles/users
revoke connect,temp,temporary on database regression from public;
CREATE SCHEMA grant_on_database_propagation;
SET search_path TO grant_on_database_propagation;
-- test grant/revoke CREATE privilege propagation on database
create user myuser;
grant create on database regression to myuser;
select has_database_privilege('myuser','regression', 'CREATE');
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CREATE');
\c - - - :master_port
revoke create on database regression from myuser;
select has_database_privilege('myuser','regression', 'CREATE');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
\c - - - :master_port
drop user myuser;
-----------------------------------------------------------------------
-- test grant/revoke CONNECT privilege propagation on database
create user myuser;
grant CONNECT on database regression to myuser;
select has_database_privilege('myuser','regression', 'CONNECT');
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CONNECT');
\c - - - :master_port
revoke connect on database regression from myuser;
select has_database_privilege('myuser','regression', 'CONNECT');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CONNECT');
\c - - - :master_port
drop user myuser;
-----------------------------------------------------------------------
-- test grant/revoke TEMP privilege propagation on database
create user myuser;
-- test grant/revoke temp on database
grant TEMP on database regression to myuser;
select has_database_privilege('myuser','regression', 'TEMP');
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'TEMP');
\c - - - :master_port
revoke TEMP on database regression from myuser;
select has_database_privilege('myuser','regression', 'TEMP');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'TEMP');
\c - - - :master_port
drop user myuser;
-----------------------------------------------------------------------
-- test temporary privilege on database
create user myuser;
-- test grant/revoke temporary on database
grant TEMPORARY on database regression to myuser;
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
revoke TEMPORARY on database regression from myuser;
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
drop user myuser;
-----------------------------------------------------------------------
-- test ALL privileges with ALL statement on database
create user myuser;
grant ALL on database regression to myuser;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
revoke ALL on database regression from myuser;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
drop user myuser;
-----------------------------------------------------------------------
-- test CREATE,CONNECT,TEMP,TEMPORARY privileges one by one on database
create user myuser;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
RESET ROLE;
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
drop user myuser;
-----------------------------------------------------------------------
-- test CREATE,CONNECT,TEMP,TEMPORARY privileges one by one on database with grant option
create user myuser;
create user myuser_1;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser;
set role myuser;
--here since myuser does not have grant option, it should fail
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser_1;
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
\c - - - :master_port
RESET ROLE;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser with grant option;
set role myuser;
--here since myuser have grant option, it should succeed
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression to myuser_1 granted by myuser;
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
\c - - - :master_port
RESET ROLE;
--below test should fail and should throw an error since myuser_1 still have the dependent privileges
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser restrict;
--below test should fail and should throw an error since myuser_1 still have the dependent privileges
revoke grant option for CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser restrict ;
--below test should succeed and should not throw any error since myuser_1 privileges are revoked with cascade
revoke grant option for CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser cascade ;
--here we test if myuser still have the privileges after revoke grant option for
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
\c - - - :master_port
reset role;
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser;
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression from myuser_1;
drop user myuser_1;
drop user myuser;
-----------------------------------------------------------------------
-- test CREATE,CONNECT,TEMP,TEMPORARY privileges one by one on database multi database
-- and multi user
create user myuser;
create user myuser_1;
create database test_db;
SELECT result FROM run_command_on_workers($$create database test_db$$);
revoke connect,temp,temporary on database test_db from public;
grant CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db to myuser,myuser_1;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
select has_database_privilege('myuser','test_db', 'CREATE');
select has_database_privilege('myuser','test_db', 'CONNECT');
select has_database_privilege('myuser','test_db', 'TEMP');
select has_database_privilege('myuser','test_db', 'TEMPORARY');
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
select has_database_privilege('myuser_1','test_db', 'CREATE');
select has_database_privilege('myuser_1','test_db', 'CONNECT');
select has_database_privilege('myuser_1','test_db', 'TEMP');
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
select has_database_privilege('myuser','test_db', 'CREATE');
select has_database_privilege('myuser','test_db', 'CONNECT');
select has_database_privilege('myuser','test_db', 'TEMP');
select has_database_privilege('myuser','test_db', 'TEMPORARY');
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
select has_database_privilege('myuser_1','test_db', 'CREATE');
select has_database_privilege('myuser_1','test_db', 'CONNECT');
select has_database_privilege('myuser_1','test_db', 'TEMP');
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
\c - - - :master_port
RESET ROLE;
--below test should fail and should throw an error
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db from myuser ;
--below test should succeed and should not throw any error
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db from myuser_1;
--below test should succeed and should not throw any error
revoke CREATE,CONNECT,TEMP,TEMPORARY on database regression,test_db from myuser cascade;
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
select has_database_privilege('myuser','test_db', 'CREATE');
select has_database_privilege('myuser','test_db', 'CONNECT');
select has_database_privilege('myuser','test_db', 'TEMP');
select has_database_privilege('myuser','test_db', 'TEMPORARY');
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
select has_database_privilege('myuser_1','test_db', 'CREATE');
select has_database_privilege('myuser_1','test_db', 'CONNECT');
select has_database_privilege('myuser_1','test_db', 'TEMP');
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
\c - - - :worker_1_port
select has_database_privilege('myuser','regression', 'CREATE');
select has_database_privilege('myuser','regression', 'CONNECT');
select has_database_privilege('myuser','regression', 'TEMP');
select has_database_privilege('myuser','regression', 'TEMPORARY');
select has_database_privilege('myuser','test_db', 'CREATE');
select has_database_privilege('myuser','test_db', 'CONNECT');
select has_database_privilege('myuser','test_db', 'TEMP');
select has_database_privilege('myuser','test_db', 'TEMPORARY');
select has_database_privilege('myuser_1','regression', 'CREATE');
select has_database_privilege('myuser_1','regression', 'CONNECT');
select has_database_privilege('myuser_1','regression', 'TEMP');
select has_database_privilege('myuser_1','regression', 'TEMPORARY');
select has_database_privilege('myuser_1','test_db', 'CREATE');
select has_database_privilege('myuser_1','test_db', 'CONNECT');
select has_database_privilege('myuser_1','test_db', 'TEMP');
select has_database_privilege('myuser_1','test_db', 'TEMPORARY');
\c - - - :master_port
reset role;
drop user myuser_1;
drop user myuser;
drop database test_db;
SELECT result FROM run_command_on_workers($$drop database test_db$$);
---------------------------------------------------------------------------
-- rollbacks public role database privileges to original state
grant connect,temp,temporary on database regression to public;
SET client_min_messages TO ERROR;
DROP SCHEMA grant_on_database_propagation CASCADE;
---------------------------------------------------------------------------

View File

@ -255,7 +255,6 @@ SELECT * FROM read_intermediate_results(ARRAY['squares_1', 'squares_2']::text[],
-- test refreshing mat views
SET client_min_messages TO ERROR;
CREATE USER some_other_user;
SELECT run_command_on_workers($$GRANT ALL ON DATABASE regression TO some_other_user;$$);
GRANT ALL ON DATABASE regression TO some_other_user;
RESET client_min_messages;

View File

@ -8,6 +8,9 @@
SHOW server_version \gset
SELECT substring(:'server_version', '\d+')::int >= 15 AS server_version_ge_15;
CREATE SCHEMA multi_deparse_shard_query;
SET search_path TO multi_deparse_shard_query;
SET citus.next_shard_id TO 13100000;
SET citus.shard_replication_factor TO 1;
@ -304,3 +307,6 @@ SELECT
FROM
raw_events_1;
');
SET client_min_messages TO ERROR;
DROP SCHEMA multi_deparse_shard_query CASCADE;

View File

@ -905,7 +905,6 @@ CREATE ROLE test_non_super_user WITH LOGIN;
ALTER ROLE test_non_super_user NOSUPERUSER;
GRANT CREATE ON DATABASE regression TO test_non_super_user;
SELECT result FROM run_command_on_workers($$GRANT CREATE ON DATABASE regression TO test_non_super_user$$);
GRANT CREATE ON SCHEMA public TO test_non_super_user ;
@ -997,7 +996,6 @@ $$);
\c - postgres
REVOKE CREATE ON DATABASE regression FROM test_non_super_user;
SELECT result FROM run_command_on_workers($$REVOKE CREATE ON DATABASE regression FROM test_non_super_user$$);
REVOKE CREATE ON SCHEMA public FROM test_non_super_user;