Skip to content

Commit d35674f

Browse files
Objects should be owned by schema owner in Babelfish (#3560)
When a new object is created in Babelfish, its owner should be same as its schema owner. Upgrade approach: Older objects will continue to have the owner (which can be different than the schema owner). There are functions provided to check the objects where there is owner mismatch between object and its schema. User can run the scripts and update the ownership themselves. Task: BABEL-5361 Signed-off-by: Shalini Lohia [email protected]
1 parent d4b2ca5 commit d35674f

40 files changed

+4085
-176
lines changed

contrib/babelfishpg_tsql/sql/ownership.sql

+158
Original file line numberDiff line numberDiff line change
@@ -869,3 +869,161 @@ SELECT
869869
END)
870870
ORDER BY class, class_desc, major_id, minor_id, ep.orig_name;
871871
GRANT SELECT ON sys.extended_properties TO PUBLIC;
872+
873+
/* Shows the list of objects where the object owner is not same as schema owner */
874+
/* Covers tables, views, functions, procedures, sequences, types */
875+
CREATE OR REPLACE FUNCTION sys.get_schema_object_ownership()
876+
RETURNS TABLE (
877+
schema_name name,
878+
schema_owner_name name,
879+
object_name name,
880+
object_owner_name name,
881+
object_type text
882+
) AS
883+
$$
884+
BEGIN
885+
RETURN QUERY
886+
WITH common_schemas AS (
887+
SELECT
888+
b.nspname AS schema_name
889+
FROM
890+
sys.babelfish_namespace_ext b
891+
JOIN
892+
pg_namespace n ON b.nspname = n.nspname
893+
JOIN
894+
pg_roles r ON n.nspowner = r.oid
895+
JOIN
896+
sys.babelfish_authid_user_ext u ON r.rolname = u.rolname
897+
WHERE
898+
u.orig_username <> 'db_owner'
899+
)
900+
-- First query for tables, views, index, types and sequences
901+
-- table types are considered as tables
902+
SELECT
903+
cs.schema_name::name,
904+
r1.rolname,
905+
c.relname,
906+
r2.rolname,
907+
CASE c.relkind
908+
WHEN 'r' THEN 'table'
909+
WHEN 'p' THEN 'table'
910+
WHEN 'v' THEN 'view'
911+
WHEN 'S' THEN 'sequence'
912+
ELSE c.relkind::text
913+
END
914+
FROM
915+
common_schemas cs
916+
JOIN
917+
pg_namespace n ON cs.schema_name = n.nspname
918+
JOIN
919+
pg_class c ON n.oid = c.relnamespace
920+
JOIN
921+
pg_roles r1 ON n.nspowner = r1.oid
922+
JOIN
923+
pg_roles r2 ON c.relowner = r2.oid
924+
WHERE
925+
c.relkind IN ('r', 'p', 'v', 'S')
926+
AND c.relname NOT LIKE '@%' -- Ignore temporary tables
927+
AND r1.rolname <> r2.rolname
928+
UNION ALL
929+
-- Second query for functions and procedures
930+
-- triggers are considered as functions
931+
SELECT
932+
cs.schema_name::name,
933+
r1.rolname,
934+
p.proname,
935+
r2.rolname,
936+
CASE p.prokind
937+
WHEN 'f' THEN 'function'
938+
WHEN 'p' THEN 'procedure'
939+
ELSE p.prokind::text
940+
END
941+
FROM
942+
common_schemas cs
943+
JOIN
944+
pg_namespace n ON cs.schema_name = n.nspname
945+
JOIN
946+
pg_roles r1 ON n.nspowner = r1.oid
947+
JOIN
948+
pg_proc p ON n.oid = p.pronamespace
949+
JOIN
950+
pg_roles r2 ON p.proowner = r2.oid
951+
WHERE
952+
p.prokind IN ('f', 'p')
953+
AND r1.rolname <> r2.rolname
954+
UNION ALL
955+
-- Third query is for types(excluding table types)
956+
SELECT
957+
cs.schema_name::name,
958+
r1.rolname,
959+
t.typname,
960+
r2.rolname,
961+
'type'::text
962+
FROM
963+
common_schemas cs
964+
JOIN
965+
pg_namespace n ON cs.schema_name = n.nspname
966+
JOIN
967+
pg_roles r1 ON n.nspowner = r1.oid
968+
JOIN
969+
pg_type t ON n.oid = t.typnamespace
970+
JOIN
971+
pg_roles r2 ON t.typowner = r2.oid
972+
WHERE
973+
t.typtype = 'd' -- Only show domain data type
974+
AND r1.rolname <> r2.rolname
975+
ORDER BY 1, 3; -- Order by schema_name, object_name using column positions
976+
END;
977+
$$ LANGUAGE plpgsql;
978+
979+
/*
980+
* Gives a list of ALTER statements that, when executed,
981+
* will change the ownership of all the objects to match their schema owners.
982+
*/
983+
CREATE OR REPLACE FUNCTION sys.generate_alter_ownership_statements()
984+
RETURNS TABLE (alter_statement text)
985+
AS $$
986+
DECLARE
987+
obj record;
988+
BEGIN
989+
FOR obj IN SELECT * FROM sys.get_schema_object_ownership()
990+
LOOP
991+
CASE obj.object_type
992+
WHEN 'table' THEN
993+
alter_statement := format('ALTER TABLE %I.%I OWNER TO %I;',
994+
obj.schema_name, obj.object_name, obj.schema_owner_name);
995+
RETURN NEXT;
996+
WHEN 'view' THEN
997+
alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = true;';
998+
RETURN NEXT;
999+
1000+
alter_statement := format('ALTER VIEW %I.%I OWNER TO %I;',
1001+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1002+
RETURN NEXT;
1003+
1004+
alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = false;';
1005+
RETURN NEXT;
1006+
WHEN 'sequence' THEN
1007+
alter_statement := format('ALTER SEQUENCE %I.%I OWNER TO %I;',
1008+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1009+
RETURN NEXT;
1010+
WHEN 'function' THEN
1011+
alter_statement := format('ALTER FUNCTION %I.%I OWNER TO %I;',
1012+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1013+
RETURN NEXT;
1014+
WHEN 'procedure' THEN
1015+
alter_statement := format('ALTER PROCEDURE %I.%I OWNER TO %I;',
1016+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1017+
RETURN NEXT;
1018+
WHEN 'type' THEN
1019+
alter_statement := format('ALTER TYPE %I.%I OWNER TO %I;',
1020+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1021+
RETURN NEXT;
1022+
ELSE
1023+
alter_statement := format('-- Unsupported object type: %s for %I.%I',
1024+
obj.object_type, obj.schema_name, obj.object_name);
1025+
RETURN NEXT;
1026+
END CASE;
1027+
END LOOP;
1028+
END;
1029+
$$ LANGUAGE plpgsql;

contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.5.0--4.6.0.sql

+157-1
Original file line numberDiff line numberDiff line change
@@ -872,9 +872,165 @@ CAST('public' AS SYS.NVARCHAR(128)) AS NAME,
872872
CAST('SERVER ROLE' AS SYS.NVARCHAR(128)) AS TYPE,
873873
CAST('GRANT OR DENY' as SYS.NVARCHAR(128)) as USAGE;
874874

875-
876875
GRANT SELECT ON sys.login_token TO PUBLIC;
877876

877+
/* Shows the list of objects where the object owner is not same as schema owner */
878+
/* Covers tables, views, functions, procedures, sequences, types */
879+
CREATE OR REPLACE FUNCTION sys.get_schema_object_ownership()
880+
RETURNS TABLE (
881+
schema_name name,
882+
schema_owner_name name,
883+
object_name name,
884+
object_owner_name name,
885+
object_type text
886+
) AS
887+
$$
888+
BEGIN
889+
RETURN QUERY
890+
WITH common_schemas AS (
891+
SELECT
892+
b.nspname AS schema_name
893+
FROM
894+
sys.babelfish_namespace_ext b
895+
JOIN
896+
pg_namespace n ON b.nspname = n.nspname
897+
JOIN
898+
pg_roles r ON n.nspowner = r.oid
899+
JOIN
900+
sys.babelfish_authid_user_ext u ON r.rolname = u.rolname
901+
WHERE
902+
u.orig_username <> 'db_owner'
903+
)
904+
-- First query for tables, views, index, types and sequences
905+
-- table types are considered as tables
906+
SELECT
907+
cs.schema_name::name,
908+
r1.rolname,
909+
c.relname,
910+
r2.rolname,
911+
CASE c.relkind
912+
WHEN 'r' THEN 'table'
913+
WHEN 'p' THEN 'table'
914+
WHEN 'v' THEN 'view'
915+
WHEN 'S' THEN 'sequence'
916+
ELSE c.relkind::text
917+
END
918+
FROM
919+
common_schemas cs
920+
JOIN
921+
pg_namespace n ON cs.schema_name = n.nspname
922+
JOIN
923+
pg_class c ON n.oid = c.relnamespace
924+
JOIN
925+
pg_roles r1 ON n.nspowner = r1.oid
926+
JOIN
927+
pg_roles r2 ON c.relowner = r2.oid
928+
WHERE
929+
c.relkind IN ('r', 'p', 'v', 'S')
930+
AND c.relname NOT LIKE '@%' -- Ignore temporary tables
931+
AND r1.rolname <> r2.rolname
932+
UNION ALL
933+
-- Second query for functions and procedures
934+
-- triggers are considered as functions
935+
SELECT
936+
cs.schema_name::name,
937+
r1.rolname,
938+
p.proname,
939+
r2.rolname,
940+
CASE p.prokind
941+
WHEN 'f' THEN 'function'
942+
WHEN 'p' THEN 'procedure'
943+
ELSE p.prokind::text
944+
END
945+
FROM
946+
common_schemas cs
947+
JOIN
948+
pg_namespace n ON cs.schema_name = n.nspname
949+
JOIN
950+
pg_roles r1 ON n.nspowner = r1.oid
951+
JOIN
952+
pg_proc p ON n.oid = p.pronamespace
953+
JOIN
954+
pg_roles r2 ON p.proowner = r2.oid
955+
WHERE
956+
p.prokind IN ('f', 'p')
957+
AND r1.rolname <> r2.rolname
958+
UNION ALL
959+
-- Third query is for types(excluding table types)
960+
SELECT
961+
cs.schema_name::name,
962+
r1.rolname,
963+
t.typname,
964+
r2.rolname,
965+
'type'::text
966+
FROM
967+
common_schemas cs
968+
JOIN
969+
pg_namespace n ON cs.schema_name = n.nspname
970+
JOIN
971+
pg_roles r1 ON n.nspowner = r1.oid
972+
JOIN
973+
pg_type t ON n.oid = t.typnamespace
974+
JOIN
975+
pg_roles r2 ON t.typowner = r2.oid
976+
WHERE
977+
t.typtype = 'd' -- Only show domain data type
978+
AND r1.rolname <> r2.rolname
979+
ORDER BY 1, 3; -- Order by schema_name, object_name using column positions
980+
END;
981+
$$ LANGUAGE plpgsql;
982+
983+
/*
984+
* Gives a list of ALTER statements that, when executed,
985+
* will change the ownership of all the objects to match their schema owners.
986+
*/
987+
CREATE OR REPLACE FUNCTION sys.generate_alter_ownership_statements()
988+
RETURNS TABLE (alter_statement text)
989+
AS $$
990+
DECLARE
991+
obj record;
992+
BEGIN
993+
FOR obj IN SELECT * FROM sys.get_schema_object_ownership()
994+
LOOP
995+
CASE obj.object_type
996+
WHEN 'table' THEN
997+
alter_statement := format('ALTER TABLE %I.%I OWNER TO %I;',
998+
obj.schema_name, obj.object_name, obj.schema_owner_name);
999+
RETURN NEXT;
1000+
WHEN 'view' THEN
1001+
alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = true;';
1002+
RETURN NEXT;
1003+
1004+
alter_statement := format('ALTER VIEW %I.%I OWNER TO %I;',
1005+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1006+
RETURN NEXT;
1007+
1008+
alter_statement := 'SET babelfishpg_tsql.enable_create_alter_view_from_pg = false;';
1009+
RETURN NEXT;
1010+
WHEN 'sequence' THEN
1011+
alter_statement := format('ALTER SEQUENCE %I.%I OWNER TO %I;',
1012+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1013+
RETURN NEXT;
1014+
WHEN 'function' THEN
1015+
alter_statement := format('ALTER FUNCTION %I.%I OWNER TO %I;',
1016+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1017+
RETURN NEXT;
1018+
WHEN 'procedure' THEN
1019+
alter_statement := format('ALTER PROCEDURE %I.%I OWNER TO %I;',
1020+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1021+
RETURN NEXT;
1022+
WHEN 'type' THEN
1023+
alter_statement := format('ALTER TYPE %I.%I OWNER TO %I;',
1024+
obj.schema_name, obj.object_name, obj.schema_owner_name);
1025+
RETURN NEXT;
1026+
ELSE
1027+
alter_statement := format('-- Unsupported object type: %s for %I.%I',
1028+
obj.object_type, obj.schema_name, obj.object_name);
1029+
RETURN NEXT;
1030+
END CASE;
1031+
END LOOP;
1032+
END;
1033+
$$ LANGUAGE plpgsql;
8781034

8791035
ALTER FUNCTION sys.json_query RENAME TO json_query_deprecated_in_5_2_0;
8801036

contrib/babelfishpg_tsql/src/hooks.c

+7-11
Original file line numberDiff line numberDiff line change
@@ -5769,7 +5769,6 @@ handle_grantstmt_for_dbsecadmin(ObjectType objType, Oid objId, Oid ownerId,
57695769
* Objects are always owned by current user in postgres but in babelfish
57705770
* schema contained objects should be owned by the schema owner by default
57715771
* Use this hook to pick schema owner as object owner during object creation
5772-
* We currently only do this if current user is member of db_ddladmin or db_owner
57735772
*/
57745773
static Oid
57755774
pltsql_get_object_owner(Oid namespaceId, Oid ownerId)
@@ -5803,6 +5802,8 @@ pltsql_get_object_owner(Oid namespaceId, Oid ownerId)
58035802
char *db_name = get_cur_db_name();
58045803
char *dbo_name = get_dbo_role_name(db_name);
58055804
Oid dbo_oid = get_role_oid(dbo_name, false);
5805+
Oid schema_db_id = get_dbid_from_physical_schema_name(NameStr(nsptup->nspname), false);
5806+
58065807
/*
58075808
* babelfish issue special handing for dbo schema since it is
58085809
* owned by db_owner but the correct owner should have been dbo
@@ -5812,17 +5813,12 @@ pltsql_get_object_owner(Oid namespaceId, Oid ownerId)
58125813
else
58135814
nsp_owner = nsptup->nspowner;
58145815

5815-
if (ownerId != nsp_owner)
5816+
/*
5817+
* Object owner should not be same as schema owner
5818+
*/
5819+
if ((ownerId != nsp_owner) && (schema_db_id == get_cur_db_id()))
58165820
{
5817-
Oid db_ddladmin = get_db_ddladmin_oid(db_name, false);
5818-
Oid db_owner = get_db_owner_oid(db_name, false);
5819-
Oid schema_db_id = get_dbid_from_physical_schema_name(NameStr(nsptup->nspname), false);
5820-
5821-
/* If current user is member of db_owner or db_ddladmin and object owner is not dbo */
5822-
if (schema_db_id == get_cur_db_id() && ownerId != dbo_oid &&
5823-
(has_privs_of_role(GetUserId(), db_owner) ||
5824-
has_privs_of_role(GetUserId(), db_ddladmin)))
5825-
ownerId = nsp_owner;
5821+
ownerId = nsp_owner;
58265822
}
58275823

58285824
pfree(db_name);

contrib/babelfishpg_tsql/src/pl_exec-2.c

+1-1
Original file line numberDiff line numberDiff line change
@@ -3968,7 +3968,7 @@ exec_stmt_grantschema(PLtsql_execstate *estate, PLtsql_stmt_grantschema *stmt)
39683968
for (i = 0; i < NUMBER_OF_PERMISSIONS; i++)
39693969
{
39703970
if (stmt->privileges & permissions[i])
3971-
exec_grantschema_subcmds(schema_name, rolname, stmt->is_grant, stmt->with_grant_option, permissions[i], false);
3971+
exec_grantschema_subcmds(schema_name, rolname, stmt->is_grant, stmt->with_grant_option, permissions[i]);
39723972
}
39733973

39743974
if (stmt->is_grant)

contrib/babelfishpg_tsql/src/pl_handler.c

-10
Original file line numberDiff line numberDiff line change
@@ -4199,16 +4199,6 @@ bbf_ProcessUtility(PlannedStmt *pstmt,
41994199
exec_database_roles_subcmds(create_schema->schemaname);
42004200
}
42014201

4202-
/* Grant ALL schema privileges to the user.*/
4203-
if (rolspec && strcmp(queryString, CREATE_LOGICAL_DATABASE) != 0)
4204-
{
4205-
int i;
4206-
for (i = 0; i < NUMBER_OF_PERMISSIONS; i++)
4207-
{
4208-
/* Execute the GRANT SCHEMA subcommands. */
4209-
exec_grantschema_subcmds(create_schema->schemaname, rolspec->rolename, true, false, permissions[i], true);
4210-
}
4211-
}
42124202
return;
42134203
}
42144204
else

0 commit comments

Comments
 (0)