Skip to content

Commit

Permalink
Support AWS and GCP special user scenarios (#23)
Browse files Browse the repository at this point in the history
CREATE SUBSCRIPTION requires that the user is superuser, which is why require the user for source and target
url/con string to be superuser. However, AWS and GCP don't have a superuser role but expose dedicated roles
that act as super user (rds_superuser and cloudsqlsuperuser) and can perform create subscription.

This PR now supports passing such user role during bootstrap and config check. We then accordingly ensure that the
internal user we create for replication has been granted the passed in special_user_role accordingly. Its a little
hard to write spec for since we still need grantee role to be superuser.

We have also relaxed permissions during config check. If a special_user_role is passed, we just make sure that user
on the source and target db is a member of the special_user_role. If special_user_role is not passed, we expect
the user to be a superuser.
  • Loading branch information
shayonj committed Jun 24, 2023
1 parent 55faf48 commit 115bbe9
Show file tree
Hide file tree
Showing 10 changed files with 428 additions and 77 deletions.
31 changes: 30 additions & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -15,13 +15,17 @@ Battle tested in production at [Tines](https://www.tines.com/) 🚀
- [Replicating all tables with a single group](#replicating-all-tables-with-a-single-group)
- [Config check](#config-check)
- [Bootstrap](#bootstrap)
- [Bootstrap and Config Check with special user role (AWS/GCP/Custom)](#bootstrap-and-config-check-with-special-user-role--aws-gcp-custom-)
- [Config Check](#config-check)
- [Bootstrap](#bootstrap-1)
- [Start sync](#start-sync)
- [Stats](#stats)
- [Performing switchover](#performing-switchover)
- [Replicating single database with custom tables](#replicating-single-database-with-custom-tables)
- [Switchover strategies with minimal downtime](#switchover-strategies-with-minimal-downtime)
- [Rolling restart strategy](#rolling-restart-strategy)
- [DNS Failover strategy](#dns-failover-strategy)
- [Contributing](#contributing)

## Installation

Expand Down Expand Up @@ -51,7 +55,7 @@ https://hub.docker.com/r/shayonj/pg_easy_replicate

- PostgreSQL 10 and later
- Ruby 2.7 and later
- Database user should have permissions for `SUPERUSER`
- Database user should have permissions for `SUPERUSER` or pass in the special user role that has the privileges to create role, schema, publication and subscription on both databases. More on `--special-user-role` section below.
- Both databases should have the same schema

## Limits
Expand Down Expand Up @@ -116,6 +120,31 @@ $ pg_easy_replicate bootstrap --group-name database-cluster-1
...
```

### Bootstrap and Config Check with special user role (AWS/GCP/Custom)

If you don't want your primary login user to have `superuser` privileges or you are on AWS or GCP, you will need to pass in the special user role that has the privileges to create role, schema, publication and subscription. This is required so `pg_easy_replicate` can create a dedicated user for replication which is granted the respective special user role to carry out its functionalities.

For AWS the special user role is `rds_superuser`, and for GCP it is `cloudsqlsuperuser`. Please refer to docs for the most up to date information.

**Note**: The user in the connection url must be part of the special user role being supplied.

#### Config Check

```bash
$ pg_easy_replicate config_check --special-user-role="rds_superuser"

✅ Config is looking good.
```

#### Bootstrap

```bash
$ pg_easy_replicate bootstrap --group-name database-cluster-1 --special-user-role="rds_superuser"

{"name":"pg_easy_replicate","hostname":"PKHXQVK6DW","pid":21485,"level":30,"time":"2023-06-19T15:51:11.015-04:00","v":0,"msg":"Setting up schema","version":"0.1.0"}
...
```

### Start sync

Once the bootstrap is complete, you can start the sync. Starting the sync sets up the publication, subscription and performs other minor housekeeping things.
Expand Down
141 changes: 115 additions & 26 deletions lib/pg_easy_replicate.rb
Original file line number Diff line number Diff line change
Expand Up @@ -21,17 +21,20 @@ class Error < StandardError
extend Helper

class << self
def config
def config(special_user_role: nil)
abort_with("SOURCE_DB_URL is missing") if source_db_url.nil?
abort_with("TARGET_DB_URL is missing") if target_db_url.nil?

@config ||=
begin
q =
"select name, setting from pg_settings where name in ('max_wal_senders', 'max_worker_processes', 'wal_level', 'max_replication_slots', 'max_logical_replication_workers');"

{
source_db_is_superuser: is_super_user?(source_db_url),
target_db_is_superuser: is_super_user?(target_db_url),
source_db_is_super_user:
is_super_user?(source_db_url, special_user_role),
target_db_is_super_user:
is_super_user?(target_db_url, special_user_role),
source_db:
Query.run(
query: q,
Expand All @@ -50,33 +53,43 @@ def config
end
end

def assert_config
unless assert_wal_level_logical(config.dig(:source_db))
def assert_config(special_user_role: nil)
config_hash = config(special_user_role: special_user_role)

unless assert_wal_level_logical(config_hash.dig(:source_db))
abort_with("WAL_LEVEL should be LOGICAL on source DB")
end

unless assert_wal_level_logical(config.dig(:target_db))
unless assert_wal_level_logical(config_hash.dig(:target_db))
abort_with("WAL_LEVEL should be LOGICAL on target DB")
end

unless config.dig(:source_db_is_superuser)
abort_with("User on source database should be a superuser")
unless config_hash.dig(:source_db_is_super_user)
abort_with("User on source database does not have super user privilege")
end

return if config.dig(:target_db_is_superuser)
abort_with("User on target database should be a superuser")
return if config_hash.dig(:target_db_is_super_user)
abort_with("User on target database does not have super user privilege")
end

def bootstrap(options)
assert_config
logger.info("Setting up schema")
setup_schema

logger.info("Setting up replication user on source database")
create_user(conn_string: source_db_url, group_name: options[:group_name])
create_user(
conn_string: source_db_url,
group_name: options[:group_name],
special_user_role: options[:special_user_role],
grant_permissions_on_schema: true,
)

logger.info("Setting up replication user on target database")
create_user(conn_string: target_db_url, group_name: options[:group_name])
create_user(
conn_string: target_db_url,
group_name: options[:group_name],
special_user_role: options[:special_user_role],
)

logger.info("Setting up groups tables")
Group.setup
Expand Down Expand Up @@ -122,7 +135,10 @@ def drop_schema
query: "DROP SCHEMA IF EXISTS #{internal_schema_name} CASCADE",
connection_url: source_db_url,
schema: internal_schema_name,
user: db_user(target_db_url),
)
rescue => e
raise "Unable to drop schema: #{e.message}"
end

def setup_schema
Expand All @@ -138,6 +154,8 @@ def setup_schema
schema: internal_schema_name,
user: db_user(target_db_url),
)
rescue => e
raise "Unable to setup schema: #{e.message}"
end

def logger
Expand All @@ -159,38 +177,109 @@ def assert_wal_level_logical(db_config)
end
end

def is_super_user?(url)
Query.run(
query:
"select usesuper from pg_user where usename = '#{db_user(url)}';",
connection_url: url,
user: db_user(target_db_url),
).first[
:usesuper
]
def is_super_user?(url, special_user_role = nil)
if special_user_role
sql = <<~SQL
SELECT r.rolname AS username,
r1.rolname AS "role"
FROM pg_catalog.pg_roles r
LEFT JOIN pg_catalog.pg_auth_members m ON (m.member = r.oid)
LEFT JOIN pg_roles r1 ON (m.roleid=r1.oid)
WHERE r.rolname = '#{db_user(url)}'
ORDER BY 1;
SQL

r =
Query.run(
query: sql,
connection_url: url,
user: db_user(target_db_url),
)
# If special_user_role is passed just ensure the url in conn_string has been granted
# the special_user_role
r.any? { |q| q[:role] == special_user_role }
else
r =
Query.run(
query:
"SELECT rolname, rolsuper FROM pg_roles where rolname = '#{db_user(url)}';",
connection_url: url,
user: db_user(target_db_url),
)
r.any? { |q| q[:rolsuper] }
end
rescue => e
raise "Unable to check superuser conditions: #{e.message}"
end

def create_user(conn_string:, group_name:)
def create_user(
conn_string:,
group_name:,
special_user_role: nil,
grant_permissions_on_schema: false
)
password = connection_info(conn_string)[:password].gsub("'") { "''" }

sql = <<~SQL
drop role if exists #{internal_user_name};
create role #{internal_user_name} with password '#{password}' login superuser createdb createrole;
create role #{internal_user_name} with password '#{password}' login createdb createrole;
grant all privileges on database #{db_name(conn_string)} TO #{internal_user_name};
SQL

Query.run(
query: sql,
connection_url: conn_string,
user: db_user(target_db_url),
user: db_user(conn_string),
transaction: false,
)

sql =
if special_user_role
"grant #{special_user_role} to #{internal_user_name};"
else
"alter user #{internal_user_name} with superuser;"
end

Query.run(
query: sql,
connection_url: conn_string,
user: db_user(conn_string),
transaction: false,
)

return unless grant_permissions_on_schema
Query.run(
query:
"grant all on schema #{internal_schema_name} to #{internal_user_name}",
connection_url: conn_string,
user: db_user(conn_string),
transaction: false,
)
rescue => e
raise "Unable to create user: #{e.message}"
end

def drop_user(conn_string:, group_name:)
sql = "drop role if exists #{internal_user_name};"
sql = <<~SQL
revoke all privileges on database #{db_name(conn_string)} from #{internal_user_name};
SQL
Query.run(
query: sql,
connection_url: conn_string,
user: db_user(conn_string),
)

sql = <<~SQL
drop role if exists #{internal_user_name};
SQL

Query.run(
query: sql,
connection_url: conn_string,
user: db_user(conn_string),
)
rescue => e
raise "Unable to drop user: #{e.message}"
end
end
end
14 changes: 12 additions & 2 deletions lib/pg_easy_replicate/cli.rb
Original file line number Diff line number Diff line change
Expand Up @@ -8,8 +8,14 @@ class CLI < Thor

desc "config_check",
"Prints if source and target database have the required config"
def config_check
PgEasyReplicate.assert_config
method_option :special_user_role,
aliases: "-s",
desc:
"Name of the role that has superuser permissions. Usually useful for AWS (rds_superuser) or GCP (cloudsqlsuperuser)."
def config_check(options)
PgEasyReplicate.assert_config(
special_user_role: options[:special_user_role],
)

puts "✅ Config is looking good."
end
Expand All @@ -18,6 +24,10 @@ def config_check
aliases: "-g",
required: true,
desc: "Name of the group to provision"
method_option :special_user_role,
aliases: "-s",
desc:
"Name of the role that has superuser permissions. Usually useful with AWS (rds_superuser) or GCP (cloudsqlsuperuser)."
desc "bootstrap",
"Sets up temporary tables for information required during runtime"
def bootstrap
Expand Down
4 changes: 4 additions & 0 deletions lib/pg_easy_replicate/helper.rb
Original file line number Diff line number Diff line change
Expand Up @@ -60,6 +60,10 @@ def db_user(url)
connection_info(url)[:user]
end

def db_name(url)
connection_info(url)[:dbname]
end

def abort_with(msg)
raise(msg) if test_env?
abort(msg)
Expand Down

0 comments on commit 115bbe9

Please sign in to comment.