Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Objects should be owned by schema owner in Babelfish #3560

Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
39 commits
Select commit Hold shift + click to select a range
b6b41a1
Objects should be owned by schema owner in Babelfish
lohia-shalini Mar 9, 2025
80448a5
Don't change object owner if CREATE is granted via PG
lohia-shalini Mar 9, 2025
8bffa26
Fix db_ddladmin tests
lohia-shalini Mar 9, 2025
2a115a9
Initial tests to check the create privilege
lohia-shalini Mar 10, 2025
feb4c0e
Update expected_dependency.out
lohia-shalini Mar 10, 2025
883c872
Ignore the dbo schemas
lohia-shalini Mar 10, 2025
1894d01
Add upgrade tests, including other object types
lohia-shalini Mar 10, 2025
043ae55
Added upgrade tests and permission checks
lohia-shalini Mar 11, 2025
dc97b27
Fix expected_dependency and upgrade test
lohia-shalini Mar 11, 2025
e928b23
Merge branch 'BABEL_4_X_DEV' into jira-babel-5361-4x
lohia-shalini Mar 11, 2025
8d980ff
remove test from 14_18
lohia-shalini Mar 11, 2025
ce00e74
disable fault_injection, add single db file
lohia-shalini Mar 11, 2025
7054fe7
Update bbf_role_admin_restrictions.out
lohia-shalini Mar 11, 2025
e1b3bf2
Empty-Commit
lohia-shalini Mar 11, 2025
b8172b6
remove grant all on object for create schema
lohia-shalini Mar 11, 2025
42ce8b2
Remove temp change
lohia-shalini Mar 11, 2025
8f89b68
add tests with seq/identity columns
lohia-shalini Mar 12, 2025
c06a6a7
Update the check for dbo schema
lohia-shalini Mar 12, 2025
ebe11c9
Update comment
lohia-shalini Mar 12, 2025
8b2db54
Add tests and Don't handle permission granted via PG on TSQL side
lohia-shalini Mar 16, 2025
fdab974
Merge branch 'BABEL_4_X_DEV' into jira-babel-5361-4x
lohia-shalini Mar 16, 2025
004c9ba
Update babel-3254 prepare script
lohia-shalini Mar 16, 2025
a2490c2
Fix failing tests
lohia-shalini Mar 16, 2025
3816a82
Update jira-BABEL-3504-upgrade-vu-cleanup.out
lohia-shalini Mar 16, 2025
167ccf2
Remove a test from latest/schedule
lohia-shalini Mar 16, 2025
19466ff
Remove an extra function
lohia-shalini Mar 16, 2025
b15acda
Fix the upgrade test
lohia-shalini Mar 16, 2025
d492077
Test partition tables in upgrade and normal scenario
lohia-shalini Mar 16, 2025
5b617c9
Add tests for partition tables
lohia-shalini Mar 16, 2025
505b047
Fix 16_8 -> latest expected output
lohia-shalini Mar 17, 2025
e5b9ac1
Update PARTITION-vu-cleanup to make the cleanup file consistent for a…
lohia-shalini Mar 17, 2025
d74ecfc
expected_create.out
lohia-shalini Mar 17, 2025
76ddc22
Include triggers
lohia-shalini Mar 17, 2025
9ab1bea
Update expected file
lohia-shalini Mar 17, 2025
796a2ce
Add more tests
lohia-shalini Mar 18, 2025
86afc97
Merge branch 'BABEL_4_X_DEV' into jira-babel-5361-4x
lohia-shalini Mar 18, 2025
1fbe61e
Address comments, add PG metadata check
lohia-shalini Mar 18, 2025
e261f4f
Merge branch 'BABEL_4_X_DEV' into jira-babel-5361-4x
shalinilohia50 Mar 18, 2025
967c537
Add a file for single-db
lohia-shalini Mar 18, 2025
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
158 changes: 158 additions & 0 deletions contrib/babelfishpg_tsql/sql/ownership.sql
Original file line number Diff line number Diff line change
Expand Up @@ -869,3 +869,161 @@ SELECT
END)
ORDER BY class, class_desc, major_id, minor_id, ep.orig_name;
GRANT SELECT ON sys.extended_properties TO PUBLIC;

/* Shows the list of objects where the object owner is not same as schema owner */
/* Covers tables, views, functions, procedures, sequences, types */
CREATE OR REPLACE FUNCTION sys.get_schema_object_ownership()
RETURNS TABLE (
schema_name name,
schema_owner_name name,
object_name name,
object_owner_name name,
object_type text
) AS
$$
BEGIN
RETURN QUERY
WITH common_schemas AS (
SELECT
b.nspname AS schema_name
FROM
sys.babelfish_namespace_ext b
JOIN
pg_namespace n ON b.nspname = n.nspname
JOIN
pg_roles r ON n.nspowner = r.oid
JOIN
sys.babelfish_authid_user_ext u ON r.rolname = u.rolname
WHERE
u.orig_username <> 'db_owner'
)
-- First query for tables, views, index, types and sequences
-- table types are considered as tables
SELECT
cs.schema_name::name,
r1.rolname,
c.relname,
r2.rolname,
CASE c.relkind
WHEN 'r' THEN 'table'
WHEN 'p' THEN 'table'
WHEN 'v' THEN 'view'
WHEN 'S' THEN 'sequence'
ELSE c.relkind::text
END
FROM
common_schemas cs
JOIN
pg_namespace n ON cs.schema_name = n.nspname
JOIN
pg_class c ON n.oid = c.relnamespace
JOIN
pg_roles r1 ON n.nspowner = r1.oid
JOIN
pg_roles r2 ON c.relowner = r2.oid
WHERE
c.relkind IN ('r', 'p', 'v', 'S')
AND c.relname NOT LIKE '@%' -- Ignore temporary tables
AND r1.rolname <> r2.rolname
UNION ALL
-- Second query for functions and procedures
-- triggers are considered as functions
SELECT
cs.schema_name::name,
r1.rolname,
p.proname,
r2.rolname,
CASE p.prokind
WHEN 'f' THEN 'function'
WHEN 'p' THEN 'procedure'
ELSE p.prokind::text
END
FROM
common_schemas cs
JOIN
pg_namespace n ON cs.schema_name = n.nspname
JOIN
pg_roles r1 ON n.nspowner = r1.oid
JOIN
pg_proc p ON n.oid = p.pronamespace
JOIN
pg_roles r2 ON p.proowner = r2.oid
WHERE
p.prokind IN ('f', 'p')
AND r1.rolname <> r2.rolname
UNION ALL
-- Third query is for types(excluding table types)
SELECT
cs.schema_name::name,
r1.rolname,
t.typname,
r2.rolname,
'type'::text
FROM
common_schemas cs
JOIN
pg_namespace n ON cs.schema_name = n.nspname
JOIN
pg_roles r1 ON n.nspowner = r1.oid
JOIN
pg_type t ON n.oid = t.typnamespace
JOIN
pg_roles r2 ON t.typowner = r2.oid
WHERE
t.typtype = 'd' -- Only show domain data type
AND r1.rolname <> r2.rolname
ORDER BY 1, 3; -- Order by schema_name, object_name using column positions
END;
$$ LANGUAGE plpgsql;

/*
* Gives a list of ALTER statements that, when executed,
* will change the ownership of all the objects to match their schema owners.
*/
CREATE OR REPLACE FUNCTION sys.generate_alter_ownership_statements()
RETURNS TABLE (alter_statement text)
AS $$
DECLARE
obj record;
BEGIN
FOR obj IN SELECT * FROM sys.get_schema_object_ownership()
LOOP
CASE obj.object_type
WHEN 'table' THEN
alter_statement := format('ALTER TABLE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'view' THEN
alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = true;';
RETURN NEXT;

alter_statement := format('ALTER VIEW %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;

alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = false;';
RETURN NEXT;
WHEN 'sequence' THEN
alter_statement := format('ALTER SEQUENCE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'function' THEN
alter_statement := format('ALTER FUNCTION %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'procedure' THEN
alter_statement := format('ALTER PROCEDURE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'type' THEN
alter_statement := format('ALTER TYPE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
ELSE
alter_statement := format('-- Unsupported object type: %s for %I.%I',
obj.object_type, obj.schema_name, obj.object_name);
RETURN NEXT;
END CASE;
END LOOP;
END;
$$ LANGUAGE plpgsql;
Original file line number Diff line number Diff line change
Expand Up @@ -741,9 +741,165 @@ CAST('public' AS SYS.NVARCHAR(128)) AS NAME,
CAST('SERVER ROLE' AS SYS.NVARCHAR(128)) AS TYPE,
CAST('GRANT OR DENY' as SYS.NVARCHAR(128)) as USAGE;


GRANT SELECT ON sys.login_token TO PUBLIC;

/* Shows the list of objects where the object owner is not same as schema owner */
/* Covers tables, views, functions, procedures, sequences, types */
CREATE OR REPLACE FUNCTION sys.get_schema_object_ownership()
RETURNS TABLE (
schema_name name,
schema_owner_name name,
object_name name,
object_owner_name name,
object_type text
) AS
$$
BEGIN
RETURN QUERY
WITH common_schemas AS (
SELECT
b.nspname AS schema_name
FROM
sys.babelfish_namespace_ext b
JOIN
pg_namespace n ON b.nspname = n.nspname
JOIN
pg_roles r ON n.nspowner = r.oid
JOIN
sys.babelfish_authid_user_ext u ON r.rolname = u.rolname
WHERE
u.orig_username <> 'db_owner'
)
-- First query for tables, views, index, types and sequences
-- table types are considered as tables
SELECT
cs.schema_name::name,
r1.rolname,
c.relname,
r2.rolname,
CASE c.relkind
WHEN 'r' THEN 'table'
WHEN 'p' THEN 'table'
WHEN 'v' THEN 'view'
WHEN 'S' THEN 'sequence'
ELSE c.relkind::text
END
FROM
common_schemas cs
JOIN
pg_namespace n ON cs.schema_name = n.nspname
JOIN
pg_class c ON n.oid = c.relnamespace
JOIN
pg_roles r1 ON n.nspowner = r1.oid
JOIN
pg_roles r2 ON c.relowner = r2.oid
WHERE
c.relkind IN ('r', 'p', 'v', 'S')
AND c.relname NOT LIKE '@%' -- Ignore temporary tables
AND r1.rolname <> r2.rolname
UNION ALL
-- Second query for functions and procedures
-- triggers are considered as functions
SELECT
cs.schema_name::name,
r1.rolname,
p.proname,
r2.rolname,
CASE p.prokind
WHEN 'f' THEN 'function'
WHEN 'p' THEN 'procedure'
ELSE p.prokind::text
END
FROM
common_schemas cs
JOIN
pg_namespace n ON cs.schema_name = n.nspname
JOIN
pg_roles r1 ON n.nspowner = r1.oid
JOIN
pg_proc p ON n.oid = p.pronamespace
JOIN
pg_roles r2 ON p.proowner = r2.oid
WHERE
p.prokind IN ('f', 'p')
AND r1.rolname <> r2.rolname
UNION ALL
-- Third query is for types(excluding table types)
SELECT
cs.schema_name::name,
r1.rolname,
t.typname,
r2.rolname,
'type'::text
FROM
common_schemas cs
JOIN
pg_namespace n ON cs.schema_name = n.nspname
JOIN
pg_roles r1 ON n.nspowner = r1.oid
JOIN
pg_type t ON n.oid = t.typnamespace
JOIN
pg_roles r2 ON t.typowner = r2.oid
WHERE
t.typtype = 'd' -- Only show domain data type
AND r1.rolname <> r2.rolname
ORDER BY 1, 3; -- Order by schema_name, object_name using column positions
END;
$$ LANGUAGE plpgsql;

/*
* Gives a list of ALTER statements that, when executed,
* will change the ownership of all the objects to match their schema owners.
*/
CREATE OR REPLACE FUNCTION sys.generate_alter_ownership_statements()
RETURNS TABLE (alter_statement text)
AS $$
DECLARE
obj record;
BEGIN
FOR obj IN SELECT * FROM sys.get_schema_object_ownership()
LOOP
CASE obj.object_type
WHEN 'table' THEN
alter_statement := format('ALTER TABLE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'view' THEN
alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = true;';
RETURN NEXT;

alter_statement := format('ALTER VIEW %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;

alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = false;';
RETURN NEXT;
WHEN 'sequence' THEN
alter_statement := format('ALTER SEQUENCE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'function' THEN
alter_statement := format('ALTER FUNCTION %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'procedure' THEN
alter_statement := format('ALTER PROCEDURE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
WHEN 'type' THEN
alter_statement := format('ALTER TYPE %I.%I OWNER TO %I;',
obj.schema_name, obj.object_name, obj.schema_owner_name);
RETURN NEXT;
ELSE
alter_statement := format('-- Unsupported object type: %s for %I.%I',
obj.object_type, obj.schema_name, obj.object_name);
RETURN NEXT;
END CASE;
END LOOP;
END;
$$ LANGUAGE plpgsql;

ALTER FUNCTION sys.json_query RENAME TO json_query_deprecated_in_5_2_0;

Expand Down
18 changes: 7 additions & 11 deletions contrib/babelfishpg_tsql/src/hooks.c
Original file line number Diff line number Diff line change
Expand Up @@ -5769,7 +5769,6 @@ handle_grantstmt_for_dbsecadmin(ObjectType objType, Oid objId, Oid ownerId,
* Objects are always owned by current user in postgres but in babelfish
* schema contained objects should be owned by the schema owner by default
* Use this hook to pick schema owner as object owner during object creation
* We currently only do this if current user is member of db_ddladmin or db_owner
*/
static Oid
pltsql_get_object_owner(Oid namespaceId, Oid ownerId)
Expand Down Expand Up @@ -5803,6 +5802,8 @@ pltsql_get_object_owner(Oid namespaceId, Oid ownerId)
char *db_name = get_cur_db_name();
char *dbo_name = get_dbo_role_name(db_name);
Oid dbo_oid = get_role_oid(dbo_name, false);
Oid schema_db_id = get_dbid_from_physical_schema_name(NameStr(nsptup->nspname), false);

/*
* babelfish issue special handing for dbo schema since it is
* owned by db_owner but the correct owner should have been dbo
Expand All @@ -5812,17 +5813,12 @@ pltsql_get_object_owner(Oid namespaceId, Oid ownerId)
else
nsp_owner = nsptup->nspowner;

if (ownerId != nsp_owner)
/*
* Object owner should not be same as schema owner
*/
if ((ownerId != nsp_owner) && (schema_db_id == get_cur_db_id()))
{
Oid db_ddladmin = get_db_ddladmin_oid(db_name, false);
Oid db_owner = get_db_owner_oid(db_name, false);
Oid schema_db_id = get_dbid_from_physical_schema_name(NameStr(nsptup->nspname), false);

/* If current user is member of db_owner or db_ddladmin and object owner is not dbo */
if (schema_db_id == get_cur_db_id() && ownerId != dbo_oid &&
(has_privs_of_role(GetUserId(), db_owner) ||
has_privs_of_role(GetUserId(), db_ddladmin)))
ownerId = nsp_owner;
ownerId = nsp_owner;
}

pfree(db_name);
Expand Down
2 changes: 1 addition & 1 deletion contrib/babelfishpg_tsql/src/pl_exec-2.c
Original file line number Diff line number Diff line change
Expand Up @@ -3968,7 +3968,7 @@ exec_stmt_grantschema(PLtsql_execstate *estate, PLtsql_stmt_grantschema *stmt)
for (i = 0; i < NUMBER_OF_PERMISSIONS; i++)
{
if (stmt->privileges & permissions[i])
exec_grantschema_subcmds(schema_name, rolname, stmt->is_grant, stmt->with_grant_option, permissions[i], false);
exec_grantschema_subcmds(schema_name, rolname, stmt->is_grant, stmt->with_grant_option, permissions[i]);
}

if (stmt->is_grant)
Expand Down
10 changes: 0 additions & 10 deletions contrib/babelfishpg_tsql/src/pl_handler.c
Original file line number Diff line number Diff line change
Expand Up @@ -4078,16 +4078,6 @@ bbf_ProcessUtility(PlannedStmt *pstmt,
exec_database_roles_subcmds(create_schema->schemaname);
}

/* Grant ALL schema privileges to the user.*/
if (rolspec && strcmp(queryString, CREATE_LOGICAL_DATABASE) != 0)
{
int i;
for (i = 0; i < NUMBER_OF_PERMISSIONS; i++)
{
/* Execute the GRANT SCHEMA subcommands. */
exec_grantschema_subcmds(create_schema->schemaname, rolspec->rolename, true, false, permissions[i], true);
}
}
return;
}
else
Expand Down
Loading
Loading