Skip to content

Commit

Permalink
Merge branch 'main' into aneesh/issue-tests
Browse files Browse the repository at this point in the history
  • Loading branch information
makalaaneesh committed Dec 6, 2024
2 parents 44889ca + e242809 commit 5b61d22
Show file tree
Hide file tree
Showing 81 changed files with 9,058 additions and 2,730 deletions.
41 changes: 28 additions & 13 deletions guardrails-scripts/yb-voyager-pg-grant-migration-permissions.sql
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
--- How to use the script:
-- Run the script with psql command line tool, passing the necessary parameters:
--- psql -h <host> -d <database> -U <username> -v voyager_user='<voyager_user>' -v schema_list='<schema_list>' -v is_live_migration=<is_live_migration> -v is_live_migration_fall_back=<is_live_migration_fall_back> -v replication_group='<replication_group>' -v original_owner_of_tables='<original_owner_of_tables>' -f <path_to_script>
--- psql -h <host> -d <database> -U <username> -v voyager_user='<voyager_user>' -v schema_list='<schema_list>' -v is_live_migration=<is_live_migration> -v is_live_migration_fall_back=<is_live_migration_fall_back> -v replication_group='<replication_group>' -f <path_to_script>
--- Example:
--- psql -h <host> -d <database> -U <username> -v voyager_user='ybvoyager' -v schema_list='schema1,public,schema2' -v is_live_migration=1 -v is_live_migration_fall_back=0 -v replication_group='replication_group' -v original_owner_of_tables='postgres' -f /home/ubuntu/yb-voyager-pg-grant-migration-permissions.sql
--- psql -h <host> -d <database> -U <username> -v voyager_user='ybvoyager' -v schema_list='schema1,public,schema2' -v is_live_migration=1 -v is_live_migration_fall_back=0 -v replication_group='replication_group' -f /home/ubuntu/yb-voyager-pg-grant-migration-permissions.sql
--- Parameters:
--- <host>: The hostname of the PostgreSQL server.
--- <database>: The name of the database to connect to.
Expand All @@ -12,7 +12,6 @@
--- <is_live_migration>: A flag indicating if this is a live migration (1 for true, 0 for false). If set to 0 then the script will check for permissions for an offline migration.
--- <is_live_migration_fall_back>: A flag indicating if this is a live migration with fallback (1 for true, 0 for false). If set to 0 then the script will detect permissions for live migration with fall-forward. Should only be set to 1 when is_live_migration is also set to 1. Does not need to be provided unless is_live_migration is set to 1.
--- <replication_group>: The name of the replication group to be created. Not needed for offline migration.
--- <original_owner_of_tables>: The original owner of the tables to be added to the replication group. Not needed for offline migration.

\echo ''
\echo '--- Checking Variables ---'
Expand Down Expand Up @@ -41,7 +40,7 @@
\q
\endif

-- If live migration is enabled, then is_live_migration_fall_back, replication_group and original_owner_of_tables should be provided
-- If live migration is enabled, then is_live_migration_fall_back, replication_group should be provided
\if :is_live_migration

-- Check if is_live_migration_fall_back is provided
Expand All @@ -59,14 +58,6 @@
\echo 'Error: replication_group flag is not provided!'
\q
\endif

-- Check if original_owner_of_tables is provided
\if :{?original_owner_of_tables}
\echo 'Original owner of tables is provided: ':original_owner_of_tables
\else
\echo 'Error: original_owner_of_tables flag is not provided!'
\q
\endif
\endif

-- If live migration fallback is provided and enabled, then is_live_migration should be enabled
Expand Down Expand Up @@ -165,7 +156,31 @@ GRANT pg_read_all_stats to :voyager_user;
-- Add the original owner of the tables to the group
\echo ''
\echo '--- Adding Original Owner to Replication Group ---'
GRANT :replication_group TO :original_owner_of_tables;
DO $$
DECLARE
tableowner TEXT;
schema_list TEXT[] := string_to_array(current_setting('myvars.schema_list'), ','); -- Convert the schema list to an array
replication_group TEXT := current_setting('myvars.replication_group'); -- Get the replication group from settings
BEGIN
-- Generate the GRANT statements and execute them dynamically
FOR tableowner IN
SELECT DISTINCT t.tableowner
FROM pg_catalog.pg_tables t
WHERE t.schemaname = ANY (schema_list) -- Use the schema_list variable
AND NOT EXISTS (
SELECT 1
FROM pg_roles r
WHERE r.rolname = t.tableowner
AND pg_has_role(t.tableowner, replication_group, 'USAGE') -- Use the replication_group variable
)
LOOP
-- Display the GRANT statement
RAISE NOTICE 'Granting role: GRANT % TO %;', replication_group, tableowner;

-- Execute the GRANT statement
EXECUTE format('GRANT %I TO %I;', replication_group, tableowner);
END LOOP;
END $$;

-- Add the user ybvoyager to the replication group
\echo ''
Expand Down
5 changes: 3 additions & 2 deletions migtests/scripts/functions.sh
Original file line number Diff line number Diff line change
Expand Up @@ -155,7 +155,7 @@ grant_permissions_for_live_migration_pg() {
db_name=$1
db_schema=$2
conn_string="postgresql://${SOURCE_DB_ADMIN_USER}:${SOURCE_DB_ADMIN_PASSWORD}@${SOURCE_DB_HOST}:${SOURCE_DB_PORT}/${db_name}"
psql "${conn_string}" -v voyager_user="${SOURCE_DB_USER}" -v schema_list="${db_schema}" -v replication_group='replication_group' -v original_owner_of_tables="${SOURCE_DB_ADMIN_USER}" -v is_live_migration=1 -v is_live_migration_fall_back=0 -f /opt/yb-voyager/guardrails-scripts/yb-voyager-pg-grant-migration-permissions.sql
psql "${conn_string}" -v voyager_user="${SOURCE_DB_USER}" -v schema_list="${db_schema}" -v replication_group='replication_group' -v is_live_migration=1 -v is_live_migration_fall_back=0 -f /opt/yb-voyager/guardrails-scripts/yb-voyager-pg-grant-migration-permissions.sql
}

grant_permissions() {
Expand Down Expand Up @@ -676,7 +676,7 @@ setup_fallback_environment() {
run_sqlplus_as_sys ${SOURCE_DB_NAME} ${SCRIPTS}/oracle/fall_back_prep.sql
elif [ "${SOURCE_DB_TYPE}" = "postgresql" ]; then
conn_string="postgresql://${SOURCE_DB_ADMIN_USER}:${SOURCE_DB_ADMIN_PASSWORD}@${SOURCE_DB_HOST}:${SOURCE_DB_PORT}/${SOURCE_DB_NAME}"
psql "${conn_string}" -v voyager_user="${SOURCE_DB_USER}" -v schema_list="${SOURCE_DB_SCHEMA}" -v replication_group='replication_group' -v original_owner_of_tables="${SOURCE_DB_ADMIN_USER}" -v is_live_migration=1 -v is_live_migration_fall_back=1 -f /opt/yb-voyager/guardrails-scripts/yb-voyager-pg-grant-migration-permissions.sql
psql "${conn_string}" -v voyager_user="${SOURCE_DB_USER}" -v schema_list="${SOURCE_DB_SCHEMA}" -v replication_group='replication_group' -v is_live_migration=1 -v is_live_migration_fall_back=1 -f /opt/yb-voyager/guardrails-scripts/yb-voyager-pg-grant-migration-permissions.sql

disable_triggers_sql=$(mktemp)
drop_constraints_sql=$(mktemp)
Expand Down Expand Up @@ -879,6 +879,7 @@ normalize_json() {
if type == "object" then
.ObjectNames? |= (if type == "string" then split(", ") | sort | join(", ") else . end) |
.VoyagerVersion? = "IGNORED" |
.TargetDBVersion? = "IGNORED" |
.DbVersion? = "IGNORED" |
.FilePath? = "IGNORED" |
.OptimalSelectConnectionsPerNode? = "IGNORED" |
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -87,4 +87,90 @@ BEGIN
SELECT * FROM employees e WHERE e.xmax = (SELECT MAX(xmax) FROM employees WHERE department = e.department);

END;
$$;
$$;

CREATE FUNCTION public.get_employeee_salary(emp_id integer) RETURNS numeric
LANGUAGE plpgsql
AS $$
DECLARE
emp_salary employees.salary%TYPE; -- Declare a variable with the same type as employees.salary
BEGIN
SELECT salary INTO emp_salary
FROM employees
WHERE employee_id = emp_id;
RETURN emp_salary;
END;
$$;

CREATE OR REPLACE FUNCTION calculate_tax(salary_amount NUMERIC) RETURNS NUMERIC AS $$
DECLARE
tax_rate employees.tax_rate%TYPE; -- Inherits type from employees.tax_rate column
tax_amount NUMERIC;
BEGIN
-- Assign a value to the variable
SELECT tax_rate INTO tax_rate FROM employees WHERE id = 1;

-- Use the variable in a calculation
tax_amount := salary_amount * tax_rate;
RETURN tax_amount;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION log_salary_change() RETURNS TRIGGER AS $$
DECLARE
old_salary employees.salary%TYPE; -- Matches the type of the salary column
new_salary employees.salary%TYPE;
BEGIN
old_salary := OLD.salary;
new_salary := NEW.salary;

IF new_salary <> old_salary THEN
INSERT INTO salary_log(employee_id, old_salary, new_salary, changed_at)
VALUES (NEW.id, old_salary, new_salary, now());
END IF;

RETURN NEW;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER salary_update_trigger
AFTER UPDATE OF salary ON employees
FOR EACH ROW EXECUTE FUNCTION log_salary_change();

CREATE OR REPLACE FUNCTION get_employee_details(emp_id employees.id%Type)
RETURNS public.employees.name%Type AS $$
DECLARE
employee_name employees.name%TYPE;
BEGIN
SELECT name INTO employee_name FROM employees WHERE id = emp_id;
RETURN employee_name;
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION list_high_earners(threshold NUMERIC) RETURNS VOID AS $$
DECLARE
emp_name employees.name%TYPE;
emp_salary employees.salary%TYPE;
BEGIN
FOR emp_name, emp_salary IN
SELECT name, salary FROM employees WHERE salary > threshold
LOOP
RAISE NOTICE 'Employee: %, Salary: %', emp_name, emp_salary;
END LOOP;
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION copy_high_earners(threshold NUMERIC) RETURNS VOID AS $$
DECLARE
temp_salary employees.salary%TYPE;
BEGIN
CREATE TEMP TABLE temp_high_earners AS
SELECT * FROM employees WHERE salary > threshold;

FOR temp_salary IN SELECT salary FROM temp_high_earners LOOP
RAISE NOTICE 'High earner salary: %', temp_salary;
END LOOP;
END;
$$ LANGUAGE plpgsql;
Original file line number Diff line number Diff line change
Expand Up @@ -149,3 +149,27 @@ BEGIN
RAISE NOTICE 'Employee % of age % added successfully.', emp_name, emp_age;
END;
$$;

CREATE OR REPLACE PROCEDURE update_salary(emp_id INT, increment NUMERIC) AS $$
DECLARE
current_salary employees.salary%TYPE; -- Matches the type of the salary column
BEGIN
SELECT salary INTO current_salary FROM employees WHERE id = emp_id;

IF current_salary IS NULL THEN
RAISE NOTICE 'Employee ID % does not exist.', emp_id;
ELSE
UPDATE employees SET salary = current_salary + increment WHERE id = emp_id;
END IF;
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE PROCEDURE get_employee_details_proc(emp_id employees.id%Type, salary employees.salary%TYPE, tax_rate numeric) AS $$
DECLARE
employee_name employees.name%TYPE;
BEGIN
SELECT name INTO employee_name FROM employees e WHERE e.id = emp_id and e.salary = salary and e.tax_rate = tax_rate;

END;
$$ LANGUAGE plpgsql;
Loading

0 comments on commit 5b61d22

Please sign in to comment.