Files
flyer-crawler.projectium.com/sql/fix_permissions.sql

93 lines
4.2 KiB
SQL

-- ============================================================================
-- COMPREHENSIVE OWNERSHIP CHANGE SCRIPT
-- ============================================================================
-- Purpose:
-- This script transfers ownership of all tables, sequences, and functions
-- in the 'public' schema to a specified user. This is crucial for allowing
-- a non-superuser (like the application user) to manage the database schema
-- during deployments or resets.
--
-- Usage:
-- Connect to the database as a superuser (e.g., 'postgres') and run this
-- entire script.
--
-- IMPORTANT: Set the new_owner variable to the appropriate user:
-- - For production: 'flyer_crawler_prod'
-- - For test: 'flyer_crawler_test'
DO $$
DECLARE
-- Define the new owner for all objects.
-- Change this to 'flyer_crawler_test' when running against the test database.
new_owner TEXT := 'flyer_crawler_prod';
-- Variables for iterating through object names.
tbl_name TEXT;
seq_name TEXT;
-- Variables for handling function signatures.
func_record RECORD;
func_signature TEXT;
BEGIN
-- 1. Change Ownership of all TABLES in the public schema
RAISE NOTICE 'Changing ownership of all tables in schema "public" to "%"...', new_owner;
FOR tbl_name IN SELECT tablename FROM pg_tables WHERE schemaname = 'public' LOOP
EXECUTE format('ALTER TABLE public.%I OWNER TO %I;', tbl_name, new_owner);
END LOOP;
RAISE NOTICE 'Table ownership change complete.';
-- 2. Change Ownership of all SEQUENCES in the public schema
RAISE NOTICE 'Changing ownership of all sequences in schema "public" to "%"...', new_owner;
FOR seq_name IN SELECT sequence_name FROM information_schema.sequences WHERE sequence_schema = 'public' LOOP
EXECUTE format('ALTER SEQUENCE public.%I OWNER TO %I;', seq_name, new_owner);
END LOOP;
RAISE NOTICE 'Sequence ownership change complete.';
-- 3. Change Ownership of all FUNCTIONS in the public schema
RAISE NOTICE 'Changing ownership of all functions in schema "public" to "%"...', new_owner;
FOR func_record IN SELECT p.proname AS function_name, pg_get_function_identity_arguments(p.oid) AS argument_list FROM pg_proc p JOIN pg_namespace n ON p.pronamespace = n.oid WHERE n.nspname = 'public' LOOP
func_signature := format('public.%I(%s)', func_record.function_name, func_record.argument_list);
EXECUTE format('ALTER FUNCTION %s OWNER TO %I;', func_signature, new_owner);
END LOOP;
RAISE NOTICE 'Function ownership change complete.';
RAISE NOTICE '✅ All ownership changes completed successfully.';
END $$;
-- long version of step 3 for clarity:
-- DO $$
-- DECLARE
-- -- Declare a record variable to hold the results of our query for each function.
-- func_record RECORD;
-- -- Declare a variable to hold the full, formatted function signature.
-- func_signature TEXT;
-- BEGIN
-- -- Loop through all functions in the 'public' schema.
-- -- We use pg_proc and pg_namespace for a more detailed and reliable query
-- -- than the information_schema.
-- FOR func_record IN
-- SELECT
-- p.proname AS function_name,
-- -- pg_get_function_identity_arguments() is a powerful built-in function
-- -- that returns the argument list of a function as a string (e.g., 'integer, text').
-- -- This is the key to handling overloaded functions correctly.
-- pg_get_function_identity_arguments(p.oid) AS argument_list
-- FROM
-- pg_proc p
-- JOIN
-- pg_namespace n ON p.pronamespace = n.oid
-- WHERE
-- n.nspname = 'public'
-- LOOP
-- -- Construct the full function signature, which includes the name and the argument list.
-- -- For example: public.my_function(integer, text)
-- func_signature := format('public.%I(%s)', func_record.function_name, func_record.argument_list);
--
-- -- Construct and execute the ALTER FUNCTION statement using the full signature.
-- -- This command is now unambiguous and will work for all functions, including overloaded ones.
-- EXECUTE format('ALTER FUNCTION %s OWNER TO flyer_crawler_prod;', func_signature);
-- END LOOP;
-- END $$;