@@ -872,9 +872,165 @@ CAST('public' AS SYS.NVARCHAR(128)) AS NAME,
872
872
CAST(' SERVER ROLE' AS SYS .NVARCHAR (128 )) AS TYPE,
873
873
CAST(' GRANT OR DENY' as SYS .NVARCHAR (128 )) as USAGE;
874
874
875
-
876
875
GRANT SELECT ON sys .login_token TO PUBLIC;
877
876
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;
878
1034
879
1035
ALTER FUNCTION sys .json_query RENAME TO json_query_deprecated_in_5_2_0;
880
1036
0 commit comments