-
Notifications
You must be signed in to change notification settings - Fork 57
Add docker-compose setup for testing physical replication / hot standby #1490
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Open
fazzone
wants to merge
2
commits into
main
Choose a base branch
from
rmcq/add-hot-standby-example-docker
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
+291
−1
Open
Changes from all commits
Commits
Show all changes
2 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,125 @@ | ||
# PostgreSQL Physical Streaming Replication Setup | ||
|
||
This directory contains a Docker Compose setup for PostgreSQL physical streaming replication with a primary and a hot standby replica instance. | ||
|
||
## Configuration | ||
|
||
- Primary PostgreSQL runs on port `7432` | ||
- Replica PostgreSQL runs on port `7452` | ||
- Admin credentials for both instances (for direct connections): | ||
- Username: `postgres` | ||
- Password: `postgres` | ||
- Database: `postgres` | ||
- Replication user credentials (used for replication stream): | ||
- Username: `replicator` | ||
- Password: `replicator_password` | ||
|
||
## Connection Strings | ||
|
||
### Primary Database | ||
`postgresql://postgres:postgres@localhost:7432/postgres` | ||
|
||
### Replica Database (Read-Only) | ||
`postgresql://postgres:postgres@localhost:7452/postgres` | ||
|
||
## Table Structure (Example) | ||
|
||
The `test_table` created on the primary will be replicated to the replica: | ||
```sql | ||
CREATE TABLE test_table ( | ||
id SERIAL PRIMARY KEY, | ||
name VARCHAR(100), | ||
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP | ||
); | ||
``` | ||
|
||
## Replication Configuration | ||
|
||
- Type: Physical Streaming Replication | ||
- Primary WAL level: `replica` | ||
- Replica mode: `hot_standby` (allows read queries) | ||
- Replication slot name: `replica_physical_slot` (on primary) | ||
|
||
## Setup | ||
|
||
1. Ensure `setup-replica.sh` is executable: | ||
```bash | ||
chmod +x setup-replica.sh | ||
``` | ||
2. Start the containers: | ||
```bash | ||
docker-compose up -d --build # Use --build if you change scripts | ||
``` | ||
3. Wait for both containers to be healthy. The replica might take a bit longer to initialize from base backup. | ||
Check with `docker-compose ps` and `docker-compose logs -f postgres-replica`. | ||
|
||
## Testing the Replication | ||
|
||
### 1. Insert Data into Primary | ||
|
||
Connect to the primary database and insert some test data: | ||
```bash | ||
# Connect to primary | ||
docker exec -it postgres-primary psql -U postgres | ||
|
||
# Once in psql, insert some test data | ||
INSERT INTO test_table (name) VALUES ('physical_test1'); | ||
INSERT INTO test_table (name) VALUES ('physical_test2'); | ||
COMMIT; -- Ensure data is flushed and sent | ||
``` | ||
|
||
### 2. Verify Data on Replica | ||
|
||
Connect to the replica database (it's read-only) and check if the data was replicated: | ||
```bash | ||
# Connect to replica | ||
docker exec -it postgres-replica psql -U postgres | ||
|
||
# Once in psql, verify the data | ||
SELECT * FROM test_table; | ||
``` | ||
You should see the data inserted on the primary. | ||
|
||
### 3. Monitor Replication Status | ||
|
||
**On the Primary:** | ||
Check connected standbys and replication slot status: | ||
```bash | ||
docker exec -it postgres-primary psql -U postgres -c "SELECT * FROM pg_stat_replication;" | ||
docker exec -it postgres-primary psql -U postgres -c "SELECT slot_name, slot_type, active, restart_lsn, confirmed_flush_lsn FROM pg_replication_slots WHERE slot_name = 'replica_physical_slot';" | ||
``` | ||
|
||
**On the Replica:** | ||
Check if it's in recovery mode and WAL replay status: | ||
```bash | ||
docker exec -it postgres-replica psql -U postgres -c "SELECT pg_is_in_recovery();" | ||
# Expected output: t (true) | ||
|
||
docker exec -it postgres-replica psql -U postgres -c "SELECT pg_last_wal_receive_lsn(), pg_last_wal_replay_lsn(), pg_last_xact_replay_timestamp();" | ||
``` | ||
The LSNs should advance, and `pg_last_xact_replay_timestamp` should update after transactions on the primary. | ||
|
||
## Cleanup | ||
|
||
To stop and remove the containers, networks, and volumes: | ||
```bash | ||
docker-compose down -v | ||
``` | ||
|
||
## Troubleshooting | ||
|
||
1. **Replica Fails to Start or Connect:** | ||
* Check `docker-compose logs postgres-replica`. Look for errors from `pg_basebackup` or connection issues to the primary. | ||
* Ensure `postgres-primary` is healthy first (`docker-compose ps`). | ||
* Verify `pg_hba.conf` on the primary allows the `replicator` user from the replica's IP (using `all` as in the script is a broad allow). | ||
* Check `docker-compose logs postgres-primary` for connection attempt logs. | ||
|
||
2. **Data Not Replicating:** | ||
* Verify replication status on primary (`pg_stat_replication`). Is the replica connected? | ||
* Check the replication slot status on primary (`pg_replication_slots`). Is it active? | ||
* Check replica logs for errors related to WAL replay. | ||
|
||
3. **`pg_basebackup` fails:** | ||
* Ensure the `postgres-replica-data` volume is empty if re-running setup. Use `docker-compose down -v` to clear volumes. | ||
* Verify `replicator` user exists on primary with correct password and `REPLICATION` privilege. | ||
* Verify the replication slot `replica_physical_slot` exists on primary. |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,61 @@ | ||
services: | ||
postgres-primary: | ||
image: postgres:17.4 | ||
container_name: postgres-primary | ||
environment: | ||
POSTGRES_USER: postgres | ||
POSTGRES_PASSWORD: postgres | ||
POSTGRES_DB: postgres | ||
ports: | ||
- "7432:5432" | ||
volumes: | ||
- postgres-primary-data:/var/lib/postgresql/data | ||
- ./init-primary.sh:/docker-entrypoint-initdb.d/init-primary.sh | ||
command: > | ||
postgres | ||
-c wal_level=logical | ||
-c max_wal_senders=10 | ||
-c max_replication_slots=10 | ||
-c hot_standby=on | ||
healthcheck: | ||
test: ["CMD-SHELL", "pg_isready -U postgres -d postgres"] | ||
interval: 5s | ||
timeout: 5s | ||
retries: 5 | ||
|
||
postgres-replica: | ||
image: postgres:17.4 | ||
container_name: postgres-replica | ||
environment: | ||
POSTGRES_USER: postgres | ||
POSTGRES_PASSWORD: postgres | ||
POSTGRES_DB: postgres | ||
ports: | ||
- "7452:5432" | ||
volumes: | ||
- postgres-replica-data:/var/lib/postgresql/data | ||
- ./setup-replica.sh:/setup-replica.sh | ||
depends_on: | ||
postgres-primary: | ||
condition: service_healthy | ||
entrypoint: ["/bin/bash", "/setup-replica.sh"] | ||
command: > | ||
postgres | ||
-c hot_standby=on | ||
-c hot_standby_feedback=on | ||
-c archive_mode=on | ||
-c wal_level=logical | ||
-c max_wal_senders=10 | ||
-c max_replication_slots=10 | ||
-c wal_sender_timeout=1000 | ||
-c recovery_target_timeline='latest' | ||
healthcheck: | ||
test: ["CMD-SHELL", "pg_isready -U postgres -d postgres && psql -U postgres -d postgres -c 'SELECT pg_is_in_recovery();' | grep 't'"] | ||
interval: 10s | ||
timeout: 5s | ||
retries: 10 | ||
|
||
volumes: | ||
postgres-primary-data: | ||
postgres-replica-data: | ||
|
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,53 @@ | ||
#!/bin/bash | ||
set -e | ||
|
||
PG_HBA_CONF="$PGDATA/pg_hba.conf" | ||
AUTH_METHOD="md5" | ||
|
||
echo "INFO: Modifying $PG_HBA_CONF in init-primary.sh" | ||
|
||
HBA_POSTGRES_USER_LINE="host all \"$POSTGRES_USER\" all $AUTH_METHOD" | ||
if ! grep -Fxq "$HBA_POSTGRES_USER_LINE" "$PG_HBA_CONF"; then | ||
echo "$HBA_POSTGRES_USER_LINE" >> "$PG_HBA_CONF" | ||
echo "INFO: Added to $PG_HBA_CONF: $HBA_POSTGRES_USER_LINE" | ||
else | ||
echo "INFO: $PG_HBA_CONF already contains: $HBA_POSTGRES_USER_LINE" | ||
fi | ||
|
||
# Ensure 'replicator' user can connect for replication from any IP | ||
HBA_REPLICATOR_LINE="host replication replicator all $AUTH_METHOD" | ||
if ! grep -Fxq "$HBA_REPLICATOR_LINE" "$PG_HBA_CONF"; then | ||
echo "$HBA_REPLICATOR_LINE" >> "$PG_HBA_CONF" | ||
echo "INFO: Added to $PG_HBA_CONF: $HBA_REPLICATOR_LINE" | ||
else | ||
echo "INFO: $PG_HBA_CONF already contains: $HBA_REPLICATOR_LINE" | ||
fi | ||
|
||
|
||
psql -v ON_ERROR_STOP=1 --username "$POSTGRES_USER" --dbname "$POSTGRES_DB" <<-EOSQL | ||
DO \$\$ | ||
BEGIN | ||
IF NOT EXISTS (SELECT FROM pg_catalog.pg_roles WHERE rolname = 'replicator') THEN | ||
CREATE USER replicator WITH REPLICATION LOGIN ENCRYPTED PASSWORD 'replicator_password'; | ||
ELSE | ||
-- Ensure password and REPLICATION attribute are set if user exists | ||
ALTER USER replicator WITH REPLICATION LOGIN ENCRYPTED PASSWORD 'replicator_password'; | ||
END IF; | ||
END | ||
\$\$; | ||
CREATE TABLE IF NOT EXISTS test_table ( | ||
id SERIAL PRIMARY KEY, | ||
name VARCHAR(100), | ||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP | ||
); | ||
-- Create physical replication slot if it doesn't exist | ||
DO \$\$ | ||
BEGIN | ||
IF NOT EXISTS (SELECT 1 FROM pg_replication_slots WHERE slot_name = 'replica_physical_slot' AND slot_type = 'physical') THEN | ||
PERFORM pg_create_physical_replication_slot('replica_physical_slot'); | ||
END IF; | ||
END | ||
\$\$; | ||
EOSQL | ||
|
||
echo "INFO: init-primary.sh finished." |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,51 @@ | ||
#!/bin/bash | ||
set -e | ||
|
||
# Only run setup if PGDATA is empty (first time for this volume) | ||
if [ -z "$(ls -A "$PGDATA" 2>/dev/null)" ]; then | ||
echo "Replica data directory ($PGDATA) is empty. Initializing standby from primary..." | ||
|
||
# Wait for primary to be ready for connections | ||
# Use the main postgres user/pass for this check against the primary. | ||
until PGPASSWORD=$POSTGRES_PASSWORD psql -h postgres-primary -U "$POSTGRES_USER" -d "$POSTGRES_DB" -c '\q'; do | ||
echo "Waiting for primary (postgres-primary) to be ready..." | ||
sleep 2 | ||
done | ||
echo "Primary is ready." | ||
|
||
echo "Performing pg_basebackup..." | ||
# Use the 'replicator' user and its password for pg_basebackup. | ||
# -D $PGDATA : target directory | ||
# -h postgres-primary : primary host | ||
# -U replicator : replication user | ||
# -Fp : format plain (not tar) | ||
# -Xs : stream WAL content while backup is taken | ||
# -P : show progress | ||
# -R : create recovery configuration (standby.signal and adds to postgresql.auto.conf) | ||
# --slot=replica_physical_slot : use the slot created on the primary | ||
PGPASSWORD='replicator_password' pg_basebackup \ | ||
-h postgres-primary \ | ||
-U replicator \ | ||
-D "$PGDATA" \ | ||
-Fp \ | ||
-Xs \ | ||
-P \ | ||
-R \ | ||
--slot='replica_physical_slot' | ||
|
||
echo "pg_basebackup completed." | ||
|
||
# pg_basebackup with -R should correctly set permissions for $PGDATA. | ||
# If needed, ensure postgresql.auto.conf contains hot_standby = on, | ||
# but it's also passed via 'command:' in docker-compose.yaml. | ||
# echo "hot_standby = on" >> "$PGDATA/postgresql.auto.conf" | ||
|
||
else | ||
echo "Replica data directory ($PGDATA) is not empty. Assuming already configured or restored." | ||
fi | ||
|
||
# Execute the original command passed to this script (e.g., "postgres -c hot_standby=on") | ||
# This will invoke the original docker-entrypoint.sh from the postgres image, | ||
# which will then start the PostgreSQL server. | ||
echo "Executing command: $@" | ||
exec /usr/local/bin/docker-entrypoint.sh "$@" |
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
to simplify things, maybe it's better to use "postgres"? because below there's a mix of postgres and replicator examples