[PG-938] Bash script to verify backup/restore functionality using pg_basebackup (#63)

* [PG-938] - Add automated bash script to verify pg_tde backup/restore functionality using pg_basebackup
* [PG-1367] Create separate script for server and tde configuration
pull/209/head
Shahid Ullah 7 months ago committed by GitHub
parent 63c3f94b0b
commit 43f4804ba5
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
  1. 527
      ci_scripts/backup/pg_basebackup_test.sh
  2. 74
      ci_scripts/backup/sql/incremental_data.sql
  3. 451
      ci_scripts/backup/sql/sample_data.sql
  4. 91
      ci_scripts/backup/sql/verify_incremental_data.sql
  5. 135
      ci_scripts/backup/sql/verify_sample_data.sql
  6. 37
      ci_scripts/configure-tde-server.sh
  7. 33
      ci_scripts/make-test-tde.sh

@ -0,0 +1,527 @@
#!/bin/bash
set -e # Exit on errors
set -u # Treat unset variables as errors
set -o pipefail # Stop on pipeline errors
# Configuration Variables
PG_VERSION="17"
INSTALL_DIR="/usr/lib/postgresql/$PG_VERSION"
PG_DATA="/var/lib/postgresql/$PG_VERSION/main"
CONF_DIR="${PG_DATA}"
HOST="127.0.0.1"
BASE_DIR=$(dirname "$(realpath "$0")") # Get the directory of the script
BACKUP_DIR="/var/lib/postgresql/backups"
FULL_BACKUP_DIR="${BACKUP_DIR}/full_backup"
INCREMENTAL_BACKUP_DIR="${BACKUP_DIR}/incremental_backup"
RESTORE_DIR="${BACKUP_DIR}/restore"
KEYLOCATION="${BASE_DIR}/pg_tde_test_keyring.per"
PG_HBA="${CONF_DIR}/pg_hba.conf"
RESTORE_PG_HBA="$RESTORE_DIR/pg_hba.conf"
PG_PORT="5433"
PG_USER="postgres"
DB_NAME="testdb"
REPL_USER="replicator"
REPL_PASS="replicator_pass"
REPO_TYPE="release" # release or testing or experimental
REPO_VERSION="17.2" # 17.0 or 17.1 or 17.2
TABLE_NAME="emp"
SEARCHED_TEXT="SMITH"
SQL_DIR="${BASE_DIR}/sql"
EXPECTED_DIR="${BASE_DIR}/expected"
ACTUAL_DIR="${BASE_DIR}/actual"
LOGFILE="${BACKUP_DIR}/backup_restore.log"
sudo -u "$PG_USER" mkdir -p "$BACKUP_DIR" "$FULL_BACKUP_DIR" "$INCREMENTAL_BACKUP_DIR" "$RESTORE_DIR" "$EXPECTED_DIR" "$ACTUAL_DIR"
# Function to log messages
log_message() {
echo "$(date '+%Y-%m-%d %H:%M:%S') - $1" | sudo -u "$PG_USER" tee -a "$LOGFILE"
}
# Step 1: Setup PostgreSQL Percona repo
setup_percona_repo(){
# RH derivatives and Amazon Linux
if [[ -f /etc/redhat-release ]] || [[ -f /etc/system-release ]]; then
# These are the same installation steps as you will find them here: https://percona.github.io/pg_tde/main/yum.html
sudo dnf module disable postgresql llvm-toolset
sudo yum -y install https://repo.percona.com/yum/percona-release-latest.noarch.rpm
sudo percona-release enable ppg-${REPO_VERSION} ${REPO_TYPE} -y
sudo dnf config-manager --set-enabled ol9_codeready_builder
sudo yum update -y
elif [[ -f /etc/debian_version ]]; then
# These are the same installation steps as you will find them here: https://percona.github.io/pg_tde/main/apt.html
sudo apt-get install -y wget gnupg2 curl lsb-release
sudo wget https://repo.percona.com/apt/percona-release_latest.generic_all.deb
sudo dpkg -i percona-release_latest.generic_all.deb
sudo percona-release enable ppg-${REPO_VERSION} ${REPO_TYPE} -y
sudo apt-get update -y
else
msg "ERROR: Unsupported operating system"
exit 1
fi
}
# Step 2: Install Percona PostgreSQL and start server
install_packages() {
# RH derivatives and Amazon Linux
if [[ -f /etc/redhat-release ]] || [[ -f /etc/system-release ]]; then
sudo yum -y install percona-postgresql-client-common percona-postgresql-common percona-postgresql-server-dev-all percona-postgresql${PG_VERSION} percona-postgresql${PG_VERSION}-contrib percona-postgresql${PG_VERSION}-devel percona-postgresql${PG_VERSION}-libs
sudo /usr/pgsql-${PG_VERSION}/bin/postgresql-${PG_VERSION}-setup initdb
#sudo systemctl start postgresql-${PG_VERSION}
start_server "$PG_DATA"
elif [[ -f /etc/debian_version ]]; then
sudo apt-get install -y percona-postgresql-${PG_VERSION} percona-postgresql-contrib percona-postgresql-server-dev-all
else
msg "ERROR: Unsupported operating system"
exit 1
fi
}
# Step 3: Setup PostgreSQL and Create Sample Data
setup_postgresql() {
echo "Setting up PostgreSQL , enable tde_heap and creating sample data..."
sudo -u "$PG_USER" psql -p $PG_PORT -c "ALTER SYSTEM SET shared_preload_libraries ='pg_tde';"
sudo -u "$PG_USER" psql -p $PG_PORT -c "ALTER SYSTEM SET summarize_wal = 'on';"
sudo -u "$PG_USER" psql -p $PG_PORT -c "ALTER SYSTEM SET wal_level = 'replica';"
sudo -u "$PG_USER" psql -p $PG_PORT -c "ALTER SYSTEM SET wal_log_hints = 'on';"
#sudo -u "$PG_USER" psql -p $PG_PORT -c "ALTER SYSTEM SET pg_tde.wal_encrypt = on;"
if [[ -f /etc/debian_version ]]; then
restart_server "$PG_DATA"
KEYLOCATION="/var/lib/postgresql/pg_tde_test_keyring.per"
else
restart_server "$PG_DATA"
KEYLOCATION="/var/lib/pgsql/pg_tde_test_keyring.per"
fi
}
# Setup TDE Heap
setup_tde_heap(){
# create a sample database
echo "Create a sample database"
sudo -u "$PG_USER" psql -p $PG_PORT -c "DROP DATABASE IF EXISTS $DB_NAME;"
sudo -u "$PG_USER" psql -p $PG_PORT -c "CREATE DATABASE $DB_NAME;"
sudo -u "$PG_USER" psql -d "$DB_NAME" -p "$PG_PORT" -c "CREATE EXTENSION IF NOT EXISTS pg_tde;"
sudo -u "$PG_USER" psql -d "$DB_NAME" -p "$PG_PORT" -c "SELECT pg_tde_add_key_provider_file('file-vault','$KEYLOCATION');"
sudo -u "$PG_USER" psql -d "$DB_NAME" -p "$PG_PORT" -c "SELECT pg_tde_set_principal_key('test-db-master-key','file-vault');"
sudo -u "$PG_USER" psql -p $PG_PORT -c "ALTER DATABASE $DB_NAME SET default_table_access_method='tde_heap';"
sudo -u "$PG_USER" psql -p $PG_PORT -c "SELECT pg_reload_conf();"
}
# Insert some sample data for testing purposes
populate_sample_data(){
# Create a sample database objects like tables, view, indexes etc
run_sql "sample_data.sql"
if [[ $? -ne 0 ]]; then
log_message "Error: Failed to create sample data. ❌"
return 1
else
log_message "Sample data created successfully. ✅ "
fi
}
# Function to run SQL files and capture results
run_sql() {
local sql_file=$1
log_message "[RUNNING] $sql_file"
sudo -u $PG_USER bash <<EOF
psql -d $DB_NAME -p "$PG_PORT" -f "$SQL_DIR/$sql_file" >> $LOGFILE 2>&1
EOF
}
# Create expected files before running backups
create_expected_output() {
local sql_file=$1
log_message "Creating expected output for $sql_file..."
sudo -u $PG_USER bash <<EOF
psql -d $DB_NAME -p $PG_PORT -e -a -f "$SQL_DIR/${sql_file}.sql" -t -A > "$EXPECTED_DIR/${sql_file}.out" 2>&1
EOF
}
# Function to verify expected vs actual output
verify_output() {
local sql_file=$1
local expected_file="$EXPECTED_DIR/$2"
mkdir -p $ACTUAL_DIR
local actual_file="$ACTUAL_DIR/${2%.expected}"
sudo -u $PG_USER bash <<EOF
psql -d $DB_NAME -p $PG_PORT -e -a -f "$SQL_DIR/$sql_file" -t -A > "$actual_file" 2>&1
EOF
if diff -q "$actual_file" "$expected_file" > /dev/null; then
log_message "$sql_file matches expected output. ✅"
else
log_message "$sql_file output mismatch. ❌"
diff "$actual_file" "$expected_file" | sudo -u "$PG_USER" tee -a $LOGFILE
fi
}
# Function to Update pg_hba.conf for Backup
update_pg_hba_for_backup() {
echo "Updating pg_hba.conf for backup..."
sudo -u "$PG_USER" bash -c "echo 'host replication $REPL_USER 127.0.0.1/32 md5' >> $PG_HBA"
sudo -u "$PG_USER" bash -c "echo 'host replication $REPL_USER ::1/128 md5' >> $PG_HBA"
#sudo systemctl reload postgresql
restart_server "$PG_DATA"
echo "pg_hba.conf updated for backup. ✅ "
}
# Configure Replication user for pg_basebackup
setup_replication_user() {
echo "Configuring replication user..."
# Create a replication user in PostgreSQL
#CREATE ROLE $REPL_USER WITH REPLICATION LOGIN PASSWORD '$REPL_PASS';
sudo -u "$PG_USER" psql -p $PG_PORT -c "
DO \$\$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_roles WHERE rolname = '$REPL_USER') THEN
EXECUTE format('CREATE ROLE %I WITH LOGIN PASSWORD %L', '$REPL_USER', '$REPL_PASS');
END IF;
END \$\$;"
# Update pg_hba.conf to allow replication
update_pg_hba_for_backup
# create .pgpass file for replication user and password
sudo -u $PG_USER bash <<EOF
echo "127.0.0.1:${PG_PORT}:*:replicator:replicator_pass" > /var/lib/postgresql/.pgpass
chmod 600 /var/lib/postgresql/.pgpass
EOF
# Reload PostgreSQL configuration
#sudo systemctl reload postgresql
restart_server "$PG_DATA"
echo "Replication user configured successfully. ✅ "
}
# Perform Full Backup Using pg_basebackup
perform_full_backup() {
backup_command_options=" -Fp -Xs -P -R "
log_message "Starting full backup with pg_basebackup with options ${backup_command_options}..."
sudo -u "$PG_USER" rm -rf "$FULL_BACKUP_DIR"
sudo -u "$PG_USER" mkdir -p "$FULL_BACKUP_DIR"
sudo -u "$PG_USER" $INSTALL_DIR/bin/pg_basebackup -h "$HOST" -p "$PG_PORT" \
-D "$FULL_BACKUP_DIR" $backup_command_options
if [[ $? -ne 0 ]]; then
log_message "Error: Backup failed. ❌"
return 1
else
log_message "Backup completed successfully. ✅ "
fi
}
# Update pg_hba.conf for Restore if configuration is different
update_pg_hba_for_restore() {
echo "Updating pg_hba.conf for restore..."
# Ensure the restored directory contains pg_hba.conf
sudo -u $PG_USER bash <<EOF
if [[ -f "$RESTORE_PG_HBA" ]]; then
echo "Adding local access for postgres to pg_hba.conf in the restored directory..."
echo "local all postgres trust" >> "$RESTORE_PG_HBA"
echo "host all all 127.0.0.1/32 md5" >> "$RESTORE_PG_HBA"
echo "host all all ::1/128 md5" >> "$RESTORE_PG_HBA"
else
log_message "Error: Restored pg_hba.conf not found at $RESTORE_PG_HBA. ❌"
exit 1
fi
EOF
log_message "pg_hba.conf updated for restore. ✅ "
}
# initate the database
initialize_server() {
DATADIR="${1:-$PG_DATA}"
sudo -u $PG_USER rm -fr $DATADIR
sudo -u $PG_USER mkdir -p $DATADIR
sudo -u $PG_USER bash <<EOF
$INSTALL_DIR/bin/initdb -D $DATADIR
EOF
}
# Start the server with specific data directory
start_server() {
DATADIR="${1:-$PG_DATA}"
PORT="${2:-$PG_PORT}"
sudo -u $PG_USER bash <<EOF
$INSTALL_DIR/bin/pg_ctl -D $DATADIR start -o "-p $PORT" -l $DATADIR/logfile
EOF
}
# Stop the server with specific data directory
stop_server() {
DATADIR="${1:-$PG_DATA}"
PORT="${2:-$PG_PORT}"
sudo -u $PG_USER bash <<EOF
$INSTALL_DIR/bin/pg_ctl -D $DATADIR stop -o "-p $PORT" -l $DATADIR/logfile
EOF
}
# Restart the server with specific data directory
restart_server() {
DATADIR="${1:-$PG_DATA}"
PORT="${2:-$PG_PORT}"
sudo -u $PG_USER bash <<EOF
$INSTALL_DIR/bin/pg_ctl -D $DATADIR restart -o "-p $PORT" -l $DATADIR/logfile
EOF
}
# Restore full backup to a new directory
restore_full_backup() {
log_message "Restoring full backup for verification... $RESTORE_DIR"
#sudo systemctl stop postgresql
stop_server "$PG_DATA"
sudo -u $PG_USER bash <<EOF
rm -rf "$RESTORE_DIR" && mkdir -p "$RESTORE_DIR"
cp -R "$FULL_BACKUP_DIR/"* "$RESTORE_DIR"
chown -R ${PG_USER}:${PG_USER} "$RESTORE_DIR"
chmod -R 700 "$RESTORE_DIR"
EOF
# Update pg_hba.conf for the restored directory
update_pg_hba_for_restore
# Update `postgresql.conf` for the restored directory
echo "data_directory = '$RESTORE_DIR'" | sudo -u "$PG_USER" tee -a "$RESTORE_DIR/postgresql.conf"
# Start PostgreSQL with the restored directory
#sudo -u "$PG_USER" $INSTALL_DIR/bin/pg_ctl -D "$RESTORE_DIR" start &>/dev/null
start_server "$RESTORE_DIR"
if [[ $? -ne 0 ]]; then
log_message "Error: Failed to start PostgreSQL with restored directory. ❌"
return 1
fi
log_message "Backup restored successfully. ✅ "
}
# Take an incremental backup
perform_incremental_backup() {
# stop the restored server
stop_server "$RESTORE_DIR"
# start the full backup server
#sudo systemctl start postgresql
start_server "$PG_DATA"
# Insert some data
run_sql "incremental_data.sql"
create_expected_output "verify_incremental_data"
# Perform incremental backup
log_message "Taking incremental backup..."
sudo -u "$PG_USER" rm -fr "$INCREMENTAL_BACKUP_DIR"
sudo -u "$PG_USER" mkdir -p "$INCREMENTAL_BACKUP_DIR"
sudo -u "$PG_USER" $INSTALL_DIR/bin/pg_basebackup -h "$HOST" -p "$PG_PORT" --incremental="$FULL_BACKUP_DIR/backup_manifest" -D "$INCREMENTAL_BACKUP_DIR"
if [ $? -ne 0 ]; then
log_message "Incremental backup failed!"
exit 1
fi
log_message "Incremental backup completed successfully."
# stop the full backup server
# sudo systemctl stop postgresql
stop_server "$PG_DATA"
}
# Restore the incremental backup
restore_incremental_backup() {
log_message "Restoring incremental backup..."
sudo -u $PG_USER bash <<EOF
rm -rf "$RESTORE_DIR" && mkdir -p "$RESTORE_DIR"
chown -R ${PG_USER}:${PG_USER} "$RESTORE_DIR"
chmod -R 700 "$RESTORE_DIR"
$INSTALL_DIR/bin/pg_combinebackup "$FULL_BACKUP_DIR" "$INCREMENTAL_BACKUP_DIR" -o "$RESTORE_DIR"
EOF
# Update pg_hba.conf for the restored directory
update_pg_hba_for_restore
# Update `postgresql.conf` for the restored directory
echo "data_directory = '$RESTORE_DIR'" | sudo -u "$PG_USER" tee -a "$RESTORE_DIR/postgresql.conf"
# Start PostgreSQL with restored backup to verify
log_message "Starting PostgreSQL for verification..."
start_server "$RESTORE_DIR"
sleep 5
}
# Verify Data Encryption at Rest
verify_encrypted_data_at_rest() {
# Get Data File Path
DATA_PATH=$(sudo -u "$PG_USER" psql -p $PG_PORT -d "$DB_NAME" -t -c "SELECT pg_relation_filepath('$TABLE_NAME');" | xargs)
DATA_DIR=$(sudo -u "$PG_USER" psql -p $PG_PORT -d "$DB_NAME" -t -c "SHOW data_directory" | xargs)
DATA_FILE="$DATA_DIR/$DATA_PATH"
log_message "Verifying data encryption at rest for table: $TABLE_NAME"
# Extract first 10 lines of raw data
RAW_DATA=$(sudo hexdump -C "$DATA_FILE" | head -n 10 || true)
log_message "$RAW_DATA"
READABLE_TEXT=$(sudo strings "$DATA_FILE" | grep "$SEARCHED_TEXT" || true)
# Check if there is readable text in the data file
if [[ -n "$READABLE_TEXT" ]]; then
log_message "Readable text detected! Data appears UNENCRYPTED.❌ "
else
log_message "Test Passed: Data appears to be encrypted! ✅ "
fi
}
# Verify PGDATA/pg_tde folder exists
verify_tde_folder() {
log_message "Verifying PGDATA/pg_tde folder exists..."
# Get PGDATA directory
PGDATA=$(sudo -u "$PG_USER" psql -p $PG_PORT -d "$DB_NAME" -t -c "SHOW data_directory;" | xargs)
# Define the TDE directory path
TDE_DIR="$PGDATA/pg_tde"
sudo -u "$PG_USER" ls "$TDE_DIR" &>/dev/null
if [[ $? -eq 0 ]]; then
log_message "$TDE_DIR folder exists. ✅ "
else
log_message "Error: $TDE_DIR folder not found. ❌"
fi
}
verify_tde_files(){
log_message "Verifying required TDE files for database OID..."
# Get PGDATA directory
PGDATA=$(sudo -u "$PG_USER" psql -p $PG_PORT -d "$DB_NAME" -t -c "SHOW data_directory;" | xargs)
# Get relation filepath (returns something like base/16543/16632)
REL_FILE_PATH=$(sudo -u "$PG_USER" psql -p $PG_PORT -d "$DB_NAME" -t -c "SELECT pg_relation_filepath('$TABLE_NAME');" | xargs)
# Extract the database OID (second field from the relation path)
DB_OID=$(sudo echo "$REL_FILE_PATH" | awk -F'/' '{print $2}')
# Define the TDE directory path
TDE_DIR="$PGDATA/pg_tde"
# Define expected files
KEYRING_FILE="$TDE_DIR/pg_tde_${DB_OID}_keyring"
DAT_FILE="$TDE_DIR/pg_tde_${DB_OID}_dat"
MAP_FILE="$TDE_DIR/pg_tde_${DB_OID}_map"
# Verify required TDE files
log_message "Checking required TDE files for database OID $DB_OID..."
MISSING_FILES=0
for FILE in "$KEYRING_FILE" "$DAT_FILE" "$MAP_FILE"; do
sudo -u "$PG_USER" ls "$FILE" &>/dev/null
if [[ $? -ne 0 ]]; then
log_message "Missing file: $FILE"
MISSING_FILES=$((MISSING_FILES + 1))
else
log_message "File exists: $FILE"
fi
done
# Final Test Result
if [[ "$MISSING_FILES" -gt 0 ]]; then
log_message "One or more required TDE files are missing! ❌"
else
log_message "All required TDE files exist! ✅"
fi
}
# Step 7: Verify Restored Data
verify_restored_data() {
file_name=$1
echo "Verifying restored data..."
verify_output "${file_name}.sql" "${file_name}.out"
}
verify_sql_files() {
echo "Verifying SQL files..."
}
verify_backup_integrity() {
backup_dir="${1:-$FULL_BACKUP_DIR}"
echo "Verifying backup integrity..."
sudo -u "$PG_USER" ${INSTALL_DIR}/bin/pg_verifybackup "$backup_dir"
if [[ $? -eq 0 ]]; then
echo "Backup integrity verified successfully. ✅ "
else
echo "Backup integrity verification failed! ❌"
return 1
fi
}
# Verify restore backup with different scenarios
test_scenarios() {
backup_dir="${1:-$FULL_BACKUP_DIR}"
restore_dir="${2:-$RESTORE_DIR}"
data_file="${3:-verify_sample_data}"
echo "Verifying backup restored testing scenarios..."
# Simulate encryption at rest
verify_encrypted_data_at_rest "$restore_dir"
# Scenario 2: Simulate backup integrity verification
verify_backup_integrity "$backup_dir"
# Scenario 3: Verify that the pg_tde directory exists
verify_tde_folder
# Scenario 4: Verify that the required TDE files exist
verify_tde_files
}
# Main Script Execution
main() {
echo "=== Starting pg_basebackup Test Automation ==="
#setup_percona_repo
#install_packages
initialize_server
start_server
setup_postgresql
setup_tde_heap
setup_replication_user
populate_sample_data
create_expected_output "verify_sample_data"
log_message "Backing up PostgreSQL database..."
perform_full_backup
log_message "Restoring and verifying backups..."
restore_full_backup
log_message "Running different tests to verify restored data..."
test_scenarios
#Verify restored data
verify_restored_data "verify_sample_data"
echo "====================================="
echo "=== Performing Incremental Backup ==="
echo "====================================="
log_message "Performing incremental backup..."
perform_incremental_backup
log_message "Restoring incremental backup..."
restore_incremental_backup
log_message "Running different tests to verify incremental restored data..."
test_scenarios "$INCREMENTAL_BACKUP_DIR" "$RESTORE_DIR"
#Verify both fullbackup & incremental backup data
verify_restored_data "verify_sample_data"
verify_restored_data "verify_incremental_data"
# "Do we need to cover other backup tools like pgBackRest/Barman?"
# TO be implemented
# # Verify wal encryption in restored data
# To be implemented
# "Scenarios to cover the keys, key rotation, key management, etc."
# TO be implemented
#echo "when you change the keyering file"
#echo "Need to verify the data after server restart"
echo "Verify other pg_basebackup options like checksum, wal options etc"
echo "=== pg_basebackup Test Automation Completed! === 🚀"
}
# Run Main Function
main

@ -0,0 +1,74 @@
-- Creating encrypted tables
CREATE TABLE tde_table (
id SERIAL PRIMARY KEY,
name TEXT
) USING tde_heap;
CREATE TABLE tde_child (
id SERIAL PRIMARY KEY,
parent_id INT REFERENCES tde_table(id)
) USING tde_heap;
-- Inserting test data
INSERT INTO tde_table (name) VALUES ('Alice'), ('Bob');
INSERT INTO tde_child (parent_id) VALUES (1);
-- Creating index on encrypted table
CREATE INDEX idx_tde_name ON tde_table(name);
SELECT tablename FROM pg_tables WHERE schemaname = 'public' ORDER BY tablename;
-- Adding constraints
ALTER TABLE tde_table ADD CONSTRAINT unique_name UNIQUE(name);
ALTER TABLE tde_table ADD CONSTRAINT check_name_length CHECK (LENGTH(name) > 3);
SELECT conname, conrelid::regclass, contype FROM pg_constraint WHERE connamespace = 'public'::regnamespace ORDER BY conrelid;
-- Creating test function
CREATE FUNCTION get_tde_data() RETURNS TABLE(id INT, name TEXT) AS $$
SELECT * FROM tde_table;
$$ LANGUAGE SQL;
-- Running function
SELECT * FROM get_tde_data();
-- Creating partitioned table
CREATE TABLE part_table (
id INT,
data TEXT
) PARTITION BY RANGE (id);
-- Creating partitions using TDE
CREATE TABLE part1 PARTITION OF part_table
FOR VALUES FROM (1) TO (100) USING tde_heap;
-- Insert test data
INSERT INTO part_table VALUES (10, 'Partitioned Data');
-- Querying data
SELECT inhrelid::regclass, inhparent::regclass FROM pg_inherits ORDER BY inhparent;
-- Creating audit log table
CREATE TABLE audit_log (
id SERIAL PRIMARY KEY,
table_name TEXT,
operation TEXT
) USING tde_heap;
-- Creating trigger function
CREATE FUNCTION audit_tde_changes() RETURNS TRIGGER AS $$
BEGIN
INSERT INTO audit_log (table_name, operation)
VALUES (TG_TABLE_NAME, TG_OP);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Creating trigger
CREATE TRIGGER tde_audit
AFTER INSERT OR UPDATE OR DELETE ON tde_table
FOR EACH ROW EXECUTE FUNCTION audit_tde_changes();
SELECT tgname, relname FROM pg_trigger JOIN pg_class ON pg_trigger.tgrelid = pg_class.oid WHERE NOT tgisinternal ORDER BY relname;
-- Check WAL logs for plaintext leaks
-- SELECT * FROM pg_walfile_name_offset(pg_current_wal_lsn());

@ -0,0 +1,451 @@
SET datestyle TO 'iso, dmy';
--
-- Script that creates the 'sample' tde encrypted tables, views
-- functions, triggers, etc.
--
-- Start new transaction - commit all or nothing
--
BEGIN;
--
-- Create and load tables used in the documentation examples.
--
-- Create the 'dept' table
--
CREATE TABLE dept (
deptno NUMERIC(2) NOT NULL CONSTRAINT dept_pk PRIMARY KEY,
dname VARCHAR(14) CONSTRAINT dept_dname_uq UNIQUE,
loc VARCHAR(13)
)using tde_heap;
--
-- Create the 'emp' table
--
CREATE TABLE emp (
empno NUMERIC(4) NOT NULL CONSTRAINT emp_pk PRIMARY KEY,
ename VARCHAR(10),
job VARCHAR(9),
mgr NUMERIC(4),
hiredate DATE,
sal NUMERIC(7,2) CONSTRAINT emp_sal_ck CHECK (sal > 0),
comm NUMERIC(7,2),
deptno NUMERIC(2) CONSTRAINT emp_ref_dept_fk
REFERENCES dept(deptno)
)using tde_heap;
--
-- Create the 'jobhist' table
--
CREATE TABLE jobhist (
empno NUMERIC(4) NOT NULL,
startdate TIMESTAMP(0) NOT NULL,
enddate TIMESTAMP(0),
job VARCHAR(9),
sal NUMERIC(7,2),
comm NUMERIC(7,2),
deptno NUMERIC(2),
chgdesc VARCHAR(80),
CONSTRAINT jobhist_pk PRIMARY KEY (empno, startdate),
CONSTRAINT jobhist_ref_emp_fk FOREIGN KEY (empno)
REFERENCES emp(empno) ON DELETE CASCADE,
CONSTRAINT jobhist_ref_dept_fk FOREIGN KEY (deptno)
REFERENCES dept (deptno) ON DELETE SET NULL,
CONSTRAINT jobhist_date_chk CHECK (startdate <= enddate)
)using tde_heap;
--
-- Create the 'salesemp' view
--
CREATE OR REPLACE VIEW salesemp AS
SELECT empno, ename, hiredate, sal, comm FROM emp WHERE job = 'SALESMAN';
--
-- Sequence to generate values for function 'new_empno'.
--
CREATE SEQUENCE next_empno START WITH 8000 INCREMENT BY 1;
--
-- Issue PUBLIC grants
--
GRANT ALL ON emp TO PUBLIC;
GRANT ALL ON dept TO PUBLIC;
GRANT ALL ON jobhist TO PUBLIC;
GRANT ALL ON salesemp TO PUBLIC;
GRANT ALL ON next_empno TO PUBLIC;
--
-- Load the 'dept' table
--
INSERT INTO dept VALUES (10,'ACCOUNTING','NEW YORK');
INSERT INTO dept VALUES (20,'RESEARCH','DALLAS');
INSERT INTO dept VALUES (30,'SALES','CHICAGO');
INSERT INTO dept VALUES (40,'OPERATIONS','BOSTON');
--
-- Load the 'emp' table
--
INSERT INTO emp VALUES (7369,'SMITH','CLERK',7902,'17-DEC-80',800,NULL,20);
INSERT INTO emp VALUES (7499,'ALLEN','SALESMAN',7698,'20-FEB-81',1600,300,30);
INSERT INTO emp VALUES (7521,'WARD','SALESMAN',7698,'22-FEB-81',1250,500,30);
INSERT INTO emp VALUES (7566,'JONES','MANAGER',7839,'02-APR-81',2975,NULL,20);
INSERT INTO emp VALUES (7654,'MARTIN','SALESMAN',7698,'28-SEP-81',1250,1400,30);
INSERT INTO emp VALUES (7698,'BLAKE','MANAGER',7839,'01-MAY-81',2850,NULL,30);
INSERT INTO emp VALUES (7782,'CLARK','MANAGER',7839,'09-JUN-81',2450,NULL,10);
INSERT INTO emp VALUES (7788,'SCOTT','ANALYST',7566,'19-APR-87',3000,NULL,20);
INSERT INTO emp VALUES (7839,'KING','PRESIDENT',NULL,'17-NOV-81',5000,NULL,10);
INSERT INTO emp VALUES (7844,'TURNER','SALESMAN',7698,'08-SEP-81',1500,0,30);
INSERT INTO emp VALUES (7876,'ADAMS','CLERK',7788,'23-MAY-87',1100,NULL,20);
INSERT INTO emp VALUES (7900,'JAMES','CLERK',7698,'03-DEC-81',950,NULL,30);
INSERT INTO emp VALUES (7902,'FORD','ANALYST',7566,'03-DEC-81',3000,NULL,20);
INSERT INTO emp VALUES (7934,'MILLER','CLERK',7782,'23-JAN-82',1300,NULL,10);
--
-- Load the 'jobhist' table
--
INSERT INTO jobhist VALUES (7369,'17-DEC-80',NULL,'CLERK',800,NULL,20,'New Hire');
INSERT INTO jobhist VALUES (7499,'20-FEB-81',NULL,'SALESMAN',1600,300,30,'New Hire');
INSERT INTO jobhist VALUES (7521,'22-FEB-81',NULL,'SALESMAN',1250,500,30,'New Hire');
INSERT INTO jobhist VALUES (7566,'02-APR-81',NULL,'MANAGER',2975,NULL,20,'New Hire');
INSERT INTO jobhist VALUES (7654,'28-SEP-81',NULL,'SALESMAN',1250,1400,30,'New Hire');
INSERT INTO jobhist VALUES (7698,'01-MAY-81',NULL,'MANAGER',2850,NULL,30,'New Hire');
INSERT INTO jobhist VALUES (7782,'09-JUN-81',NULL,'MANAGER',2450,NULL,10,'New Hire');
INSERT INTO jobhist VALUES (7788,'19-APR-87','12-APR-88','CLERK',1000,NULL,20,'New Hire');
INSERT INTO jobhist VALUES (7788,'13-APR-88','04-MAY-89','CLERK',1040,NULL,20,'Raise');
INSERT INTO jobhist VALUES (7788,'05-MAY-90',NULL,'ANALYST',3000,NULL,20,'Promoted to Analyst');
INSERT INTO jobhist VALUES (7839,'17-NOV-81',NULL,'PRESIDENT',5000,NULL,10,'New Hire');
INSERT INTO jobhist VALUES (7844,'08-SEP-81',NULL,'SALESMAN',1500,0,30,'New Hire');
INSERT INTO jobhist VALUES (7876,'23-MAY-87',NULL,'CLERK',1100,NULL,20,'New Hire');
INSERT INTO jobhist VALUES (7900,'03-DEC-81','14-JAN-83','CLERK',950,NULL,10,'New Hire');
INSERT INTO jobhist VALUES (7900,'15-JAN-83',NULL,'CLERK',950,NULL,30,'Changed to Dept 30');
INSERT INTO jobhist VALUES (7902,'03-DEC-81',NULL,'ANALYST',3000,NULL,20,'New Hire');
INSERT INTO jobhist VALUES (7934,'23-JAN-82',NULL,'CLERK',1300,NULL,10,'New Hire');
--
-- Populate statistics table and view (pg_statistic/pg_stats)
--
ANALYZE dept;
ANALYZE emp;
ANALYZE jobhist;
--
-- Function that lists all employees' numbers and names
-- from the 'emp' table using a cursor.
--
CREATE OR REPLACE FUNCTION list_emp() RETURNS VOID
AS $$
DECLARE
v_empno NUMERIC(4);
v_ename VARCHAR(10);
emp_cur CURSOR FOR
SELECT empno, ename FROM emp ORDER BY empno;
BEGIN
OPEN emp_cur;
RAISE INFO 'EMPNO ENAME';
RAISE INFO '----- -------';
LOOP
FETCH emp_cur INTO v_empno, v_ename;
EXIT WHEN NOT FOUND;
RAISE INFO '% %', v_empno, v_ename;
END LOOP;
CLOSE emp_cur;
RETURN;
END;
$$ LANGUAGE 'plpgsql';
--
-- Function that selects an employee row given the employee
-- number and displays certain columns.
--
CREATE OR REPLACE FUNCTION select_emp (
p_empno NUMERIC
) RETURNS VOID
AS $$
DECLARE
v_ename emp.ename%TYPE;
v_hiredate emp.hiredate%TYPE;
v_sal emp.sal%TYPE;
v_comm emp.comm%TYPE;
v_dname dept.dname%TYPE;
v_disp_date VARCHAR(10);
BEGIN
SELECT INTO
v_ename, v_hiredate, v_sal, v_comm, v_dname
ename, hiredate, sal, COALESCE(comm, 0), dname
FROM emp e, dept d
WHERE empno = p_empno
AND e.deptno = d.deptno;
IF NOT FOUND THEN
RAISE INFO 'Employee % not found', p_empno;
RETURN;
END IF;
v_disp_date := TO_CHAR(v_hiredate, 'MM/DD/YYYY');
RAISE INFO 'Number : %', p_empno;
RAISE INFO 'Name : %', v_ename;
RAISE INFO 'Hire Date : %', v_disp_date;
RAISE INFO 'Salary : %', v_sal;
RAISE INFO 'Commission: %', v_comm;
RAISE INFO 'Department: %', v_dname;
RETURN;
EXCEPTION
WHEN OTHERS THEN
RAISE INFO 'The following is SQLERRM : %', SQLERRM;
RAISE INFO 'The following is SQLSTATE: %', SQLSTATE;
RETURN;
END;
$$ LANGUAGE 'plpgsql';
--
-- A RECORD type used to format the return value of
-- function, 'emp_query'.
--
CREATE TYPE emp_query_type AS (
empno NUMERIC,
ename VARCHAR(10),
job VARCHAR(9),
hiredate DATE,
sal NUMERIC
);
--
-- Function that queries the 'emp' table based on
-- department number and employee number or name. Returns
-- employee number and name as INOUT parameters and job,
-- hire date, and salary as OUT parameters. These are
-- returned in the form of a record defined by
-- RECORD type, 'emp_query_type'.
--
CREATE OR REPLACE FUNCTION emp_query (
IN p_deptno NUMERIC,
INOUT p_empno NUMERIC,
INOUT p_ename VARCHAR,
OUT p_job VARCHAR,
OUT p_hiredate DATE,
OUT p_sal NUMERIC
)
AS $$
BEGIN
SELECT INTO
p_empno, p_ename, p_job, p_hiredate, p_sal
empno, ename, job, hiredate, sal
FROM emp
WHERE deptno = p_deptno
AND (empno = p_empno
OR ename = UPPER(p_ename));
END;
$$ LANGUAGE 'plpgsql';
--
-- Function to call 'emp_query_caller' with IN and INOUT
-- parameters. Displays the results received from INOUT and
-- OUT parameters.
--
CREATE OR REPLACE FUNCTION emp_query_caller() RETURNS VOID
AS $$
DECLARE
v_deptno NUMERIC;
v_empno NUMERIC;
v_ename VARCHAR;
v_rows INTEGER;
r_emp_query EMP_QUERY_TYPE;
BEGIN
v_deptno := 30;
v_empno := 0;
v_ename := 'Martin';
r_emp_query := emp_query(v_deptno, v_empno, v_ename);
RAISE INFO 'Department : %', v_deptno;
RAISE INFO 'Employee No: %', (r_emp_query).empno;
RAISE INFO 'Name : %', (r_emp_query).ename;
RAISE INFO 'Job : %', (r_emp_query).job;
RAISE INFO 'Hire Date : %', (r_emp_query).hiredate;
RAISE INFO 'Salary : %', (r_emp_query).sal;
RETURN;
EXCEPTION
WHEN OTHERS THEN
RAISE INFO 'The following is SQLERRM : %', SQLERRM;
RAISE INFO 'The following is SQLSTATE: %', SQLSTATE;
RETURN;
END;
$$ LANGUAGE 'plpgsql';
--
-- Function to compute yearly compensation based on semimonthly
-- salary.
--
CREATE OR REPLACE FUNCTION emp_comp (
p_sal NUMERIC,
p_comm NUMERIC
) RETURNS NUMERIC
AS $$
BEGIN
RETURN (p_sal + COALESCE(p_comm, 0)) * 24;
END;
$$ LANGUAGE 'plpgsql';
--
-- Function that gets the next number from sequence, 'next_empno',
-- and ensures it is not already in use as an employee number.
--
CREATE OR REPLACE FUNCTION new_empno() RETURNS INTEGER
AS $$
DECLARE
v_cnt INTEGER := 1;
v_new_empno INTEGER;
BEGIN
WHILE v_cnt > 0 LOOP
SELECT INTO v_new_empno nextval('next_empno');
SELECT INTO v_cnt COUNT(*) FROM emp WHERE empno = v_new_empno;
END LOOP;
RETURN v_new_empno;
END;
$$ LANGUAGE 'plpgsql';
--
-- Function that adds a new clerk to table 'emp'.
--
CREATE OR REPLACE FUNCTION hire_clerk (
p_ename VARCHAR,
p_deptno NUMERIC
) RETURNS NUMERIC
AS $$
DECLARE
v_empno NUMERIC(4);
v_ename VARCHAR(10);
v_job VARCHAR(9);
v_mgr NUMERIC(4);
v_hiredate DATE;
v_sal NUMERIC(7,2);
v_comm NUMERIC(7,2);
v_deptno NUMERIC(2);
BEGIN
v_empno := new_empno();
INSERT INTO emp VALUES (v_empno, p_ename, 'CLERK', 7782,
CURRENT_DATE, 950.00, NULL, p_deptno);
SELECT INTO
v_empno, v_ename, v_job, v_mgr, v_hiredate, v_sal, v_comm, v_deptno
empno, ename, job, mgr, hiredate, sal, comm, deptno
FROM emp WHERE empno = v_empno;
RAISE INFO 'Department : %', v_deptno;
RAISE INFO 'Employee No: %', v_empno;
RAISE INFO 'Name : %', v_ename;
RAISE INFO 'Job : %', v_job;
RAISE INFO 'Manager : %', v_mgr;
RAISE INFO 'Hire Date : %', v_hiredate;
RAISE INFO 'Salary : %', v_sal;
RAISE INFO 'Commission : %', v_comm;
RETURN v_empno;
EXCEPTION
WHEN OTHERS THEN
RAISE INFO 'The following is SQLERRM : %', SQLERRM;
RAISE INFO 'The following is SQLSTATE: %', SQLSTATE;
RETURN -1;
END;
$$ LANGUAGE 'plpgsql';
--
-- Function that adds a new salesman to table 'emp'.
--
CREATE OR REPLACE FUNCTION hire_salesman (
p_ename VARCHAR,
p_sal NUMERIC,
p_comm NUMERIC
) RETURNS NUMERIC
AS $$
DECLARE
v_empno NUMERIC(4);
v_ename VARCHAR(10);
v_job VARCHAR(9);
v_mgr NUMERIC(4);
v_hiredate DATE;
v_sal NUMERIC(7,2);
v_comm NUMERIC(7,2);
v_deptno NUMERIC(2);
BEGIN
v_empno := new_empno();
INSERT INTO emp VALUES (v_empno, p_ename, 'SALESMAN', 7698,
CURRENT_DATE, p_sal, p_comm, 30);
SELECT INTO
v_empno, v_ename, v_job, v_mgr, v_hiredate, v_sal, v_comm, v_deptno
empno, ename, job, mgr, hiredate, sal, comm, deptno
FROM emp WHERE empno = v_empno;
RAISE INFO 'Department : %', v_deptno;
RAISE INFO 'Employee No: %', v_empno;
RAISE INFO 'Name : %', v_ename;
RAISE INFO 'Job : %', v_job;
RAISE INFO 'Manager : %', v_mgr;
RAISE INFO 'Hire Date : %', v_hiredate;
RAISE INFO 'Salary : %', v_sal;
RAISE INFO 'Commission : %', v_comm;
RETURN v_empno;
EXCEPTION
WHEN OTHERS THEN
RAISE INFO 'The following is SQLERRM : %', SQLERRM;
RAISE INFO 'The following is SQLSTATE: %', SQLSTATE;
RETURN -1;
END;
$$ LANGUAGE 'plpgsql';
--
-- Rule to INSERT into view 'salesemp'
--
CREATE OR REPLACE RULE salesemp_i AS ON INSERT TO salesemp
DO INSTEAD
INSERT INTO emp VALUES (NEW.empno, NEW.ename, 'SALESMAN', 7698,
NEW.hiredate, NEW.sal, NEW.comm, 30);
--
-- Rule to UPDATE view 'salesemp'
--
CREATE OR REPLACE RULE salesemp_u AS ON UPDATE TO salesemp
DO INSTEAD
UPDATE emp SET empno = NEW.empno,
ename = NEW.ename,
hiredate = NEW.hiredate,
sal = NEW.sal,
comm = NEW.comm
WHERE empno = OLD.empno;
--
-- Rule to DELETE from view 'salesemp'
--
CREATE OR REPLACE RULE salesemp_d AS ON DELETE TO salesemp
DO INSTEAD
DELETE FROM emp WHERE empno = OLD.empno;
--
-- After statement-level trigger that displays a message after
-- an insert, update, or deletion to the 'emp' table. One message
-- per SQL command is displayed.
--
CREATE OR REPLACE FUNCTION user_audit_trig() RETURNS TRIGGER
AS $$
DECLARE
v_action VARCHAR(24);
v_text TEXT;
BEGIN
IF TG_OP = 'INSERT' THEN
v_action := ' added employee(s) on ';
ELSIF TG_OP = 'UPDATE' THEN
v_action := ' updated employee(s) on ';
ELSIF TG_OP = 'DELETE' THEN
v_action := ' deleted employee(s) on ';
END IF;
v_text := 'User ' || USER || v_action || CURRENT_DATE;
RAISE INFO ' %', v_text;
RETURN NULL;
END;
$$ LANGUAGE 'plpgsql';
CREATE TRIGGER user_audit_trig
AFTER INSERT OR UPDATE OR DELETE ON emp
FOR EACH STATEMENT EXECUTE PROCEDURE user_audit_trig();
--
-- Before row-level trigger that displays employee number and
-- salary of an employee that is about to be added, updated,
-- or deleted in the 'emp' table.
--
CREATE OR REPLACE FUNCTION emp_sal_trig() RETURNS TRIGGER
AS $$
DECLARE
sal_diff NUMERIC(7,2);
BEGIN
IF TG_OP = 'INSERT' THEN
RAISE INFO 'Inserting employee %', NEW.empno;
RAISE INFO '..New salary: %', NEW.sal;
RETURN NEW;
END IF;
IF TG_OP = 'UPDATE' THEN
sal_diff := NEW.sal - OLD.sal;
RAISE INFO 'Updating employee %', OLD.empno;
RAISE INFO '..Old salary: %', OLD.sal;
RAISE INFO '..New salary: %', NEW.sal;
RAISE INFO '..Raise : %', sal_diff;
RETURN NEW;
END IF;
IF TG_OP = 'DELETE' THEN
RAISE INFO 'Deleting employee %', OLD.empno;
RAISE INFO '..Old salary: %', OLD.sal;
RETURN OLD;
END IF;
END;
$$ LANGUAGE 'plpgsql';
CREATE TRIGGER emp_sal_trig
BEFORE DELETE OR INSERT OR UPDATE ON emp
FOR EACH ROW EXECUTE PROCEDURE emp_sal_trig();
COMMIT;

@ -0,0 +1,91 @@
-- ===============================================
-- 1. Verify TDE Tables Exist
-- ===============================================
SELECT table_name
FROM information_schema.tables
WHERE table_schema = 'public'
AND table_name IN ('tde_table', 'tde_child', 'audit_log', 'part_table', 'part1')
ORDER BY table_name;
-- ===============================================
-- 2. Verify Columns of Tables
-- ===============================================
SELECT column_name, data_type, table_name
FROM information_schema.columns
WHERE table_name IN ('tde_table', 'tde_child', 'audit_log', 'part_table', 'part1')
ORDER BY table_name, ordinal_position;
-- ===============================================
-- 3. Verify Constraints Exist
-- ===============================================
SELECT conname, conrelid::regclass, contype
FROM pg_constraint
WHERE connamespace = 'public'::regnamespace
AND conrelid::regclass::text IN ('tde_table', 'tde_child')
ORDER BY conrelid;
-- ===============================================
-- 4. Verify Index Exists
-- ===============================================
SELECT indexname, tablename
FROM pg_indexes
WHERE schemaname = 'public' AND tablename = 'tde_table';
-- ===============================================
-- 5. Verify Functions Exist
-- ===============================================
SELECT proname, prorettype::regtype
FROM pg_proc
JOIN pg_namespace ON pg_proc.pronamespace = pg_namespace.oid
WHERE nspname = 'public'
AND proname = 'get_tde_data';
-- ===============================================
-- 6. Verify Function Output
-- ===============================================
SELECT * FROM get_tde_data();
-- ===============================================
-- 7. Verify Partitioning
-- ===============================================
SELECT inhrelid::regclass AS partition_name, inhparent::regclass AS parent_table
FROM pg_inherits
WHERE inhparent::regclass::text = 'part_table'
ORDER BY inhparent;
-- ===============================================
-- 8. Verify Triggers Exist
-- ===============================================
SELECT tgname, relname
FROM pg_trigger
JOIN pg_class ON pg_trigger.tgrelid = pg_class.oid
WHERE NOT tgisinternal AND relname = 'tde_table';
-- ===============================================
-- 9. Verify Data Integrity
-- ===============================================
-- Check data counts
SELECT 'tde_table' AS table_name, COUNT(*) FROM tde_table
UNION ALL
SELECT 'tde_child', COUNT(*) FROM tde_child
UNION ALL
SELECT 'audit_log', COUNT(*) FROM audit_log
UNION ALL
SELECT 'part_table', COUNT(*) FROM part_table;
-- Ensure tde_child references valid parent_id
SELECT tde_child.id, tde_child.parent_id
FROM tde_child
LEFT JOIN tde_table ON tde_child.parent_id = tde_table.id
WHERE tde_table.id IS NULL;
-- ===============================================
-- 10. Verify tables are encrypted
-- ===============================================
-- Verify all tables exist and are encrypted
SELECT tablename, pg_tde_is_encrypted(tablename::TEXT) AS is_encrypted
FROM pg_tables
WHERE schemaname = 'public'
AND tablename IN ('tde_table', 'tde_child', 'part1','part_table')
ORDER BY tablename;

@ -0,0 +1,135 @@
-- Set datestyle for consistency
SET datestyle TO 'iso, dmy';
-- =====================================================
-- 1. Verify Tables Exist
-- =====================================================
SELECT table_name
FROM information_schema.tables
WHERE table_schema = 'public'
AND table_name IN ('dept', 'emp', 'jobhist');
-- =====================================================
-- 2. Verify Views Exist
-- =====================================================
SELECT table_name
FROM information_schema.views
WHERE table_schema = 'public'
AND table_name = 'salesemp';
-- =====================================================
-- 3. Verify Columns of Tables
-- =====================================================
-- Dept Table
SELECT column_name, data_type
FROM information_schema.columns
WHERE table_name = 'dept'
ORDER BY ordinal_position;
-- Emp Table
SELECT column_name, data_type
FROM information_schema.columns
WHERE table_name = 'emp'
ORDER BY ordinal_position;
-- Jobhist Table
SELECT column_name, data_type
FROM information_schema.columns
WHERE table_name = 'jobhist'
ORDER BY ordinal_position;
-- =====================================================
-- 4. Verify Sequences Exist
-- =====================================================
SELECT relname
FROM pg_class
WHERE relkind = 'S'
AND relname = 'next_empno';
-- =====================================================
-- 5. Verify Functions Exist
-- =====================================================
SELECT proname, prorettype::regtype
FROM pg_proc
JOIN pg_namespace ON pg_proc.pronamespace = pg_namespace.oid
WHERE nspname = 'public'
AND proname IN ('list_emp', 'select_emp', 'emp_query', 'emp_query_caller',
'emp_comp', 'new_empno', 'hire_clerk', 'hire_salesman');
-- =====================================================
-- 6. Verify Data in Tables
-- =====================================================
-- Count rows in each table
SELECT 'dept' AS table_name, COUNT(*) FROM dept
UNION ALL
SELECT 'emp', COUNT(*) FROM emp
UNION ALL
SELECT 'jobhist', COUNT(*) FROM jobhist;
-- Check if `emp` employees belong to valid `dept`
SELECT emp.empno, emp.ename, emp.deptno, dept.deptno
FROM emp
LEFT JOIN dept ON emp.deptno = dept.deptno
WHERE dept.deptno IS NULL;
-- Check if `jobhist` records have valid `empno`
SELECT jobhist.empno, jobhist.job, jobhist.sal
FROM jobhist
LEFT JOIN emp ON jobhist.empno = emp.empno
WHERE emp.empno IS NULL;
-- =====================================================
-- 7. Verify Expected Data in Tables
-- =====================================================
-- Sample Data from `dept`
SELECT * FROM dept LIMIT 5;
-- Sample Data from `emp`
SELECT * FROM emp ORDER BY empno LIMIT 5;
-- Sample Data from `jobhist`
SELECT * FROM jobhist ORDER BY empno LIMIT 5;
SELECT * FROM salesemp;
-- Validate if department names follow expected values
SELECT deptno, dname FROM dept
WHERE dname NOT IN ('HR', 'Finance', 'Sales', 'IT', 'Admin');
-- Validate if `emp` salaries are within expected range
SELECT empno, ename, job, sal
FROM emp
WHERE sal < 3000 OR sal > 20000;
-- Check if any employees were hired before 2000 (if expected)
SELECT empno, ename, hiredate FROM emp
WHERE hiredate < '2000-01-01';
-- Verify sequence correctness (Check latest employee number)
-- SELECT last_value FROM next_empno;
-- Verify if function `new_empno()` returns next expected value
-- SELECT new_empno();
-- =====================================================
-- 8. Verify Referential Integrity
-- =====================================================
-- Ensure all employees in `jobhist` exist in `emp`
SELECT jobhist.empno FROM jobhist
LEFT JOIN emp ON jobhist.empno = emp.empno
WHERE emp.empno IS NULL;
-- Ensure `emp.deptno` exists in `dept`
SELECT emp.empno, emp.deptno FROM emp
LEFT JOIN dept ON emp.deptno = dept.deptno
WHERE dept.deptno IS NULL;
-- ===============================================
-- 9. Verify tables are encrypted
-- ===============================================
-- Verify all tables exist and are encrypted
SELECT tablename, pg_tde_is_encrypted(tablename::TEXT) AS is_encrypted
FROM pg_tables
WHERE schemaname = 'public'
AND tablename IN ('dept', 'emp', 'jobhist')
ORDER BY tablename;

@ -0,0 +1,37 @@
#!/bin/bash
# This script is used to configure a TDE server for testing purposes.
export TDE_MODE=1
SCRIPT_DIR="$(cd -- "$(dirname "$0")" >/dev/null 2>&1; pwd -P)"
INSTALL_DIR="$SCRIPT_DIR/../../pginst"
cd "$SCRIPT_DIR/.."
export PATH=$INSTALL_DIR/bin:$PATH
export PGDATA=$INSTALL_DIR/data
if pgrep -x "postgres" > /dev/null; then
pg_ctl -D $PGDATA stop
fi
if pgrep -x "postgres" > /dev/null; then
echo "Error: a postgres process is already running"
exit 1
fi
if [ -d $PGDATA ]; then
rm -rf $PGDATA
fi
initdb -D $PGDATA
echo "shared_preload_libraries ='pg_tde'" >> $PGDATA/postgresql.conf
pg_ctl -D $PGDATA start
createdb setup_helper
psql setup_helper < $SCRIPT_DIR/tde_setup_global.sql
echo "pg_tde.wal_encrypt = on" >> $PGDATA/postgresql.conf
pg_ctl -D $PGDATA restart

@ -3,38 +3,7 @@
export TDE_MODE=1
SCRIPT_DIR="$(cd -- "$(dirname "$0")" >/dev/null 2>&1; pwd -P)"
INSTALL_DIR="$SCRIPT_DIR/../../pginst"
cd "$SCRIPT_DIR/.."
export PATH=$INSTALL_DIR/bin:$PATH
export PGDATA=$INSTALL_DIR/data
if pgrep -x "postgres" > /dev/null; then
pg_ctl -D $PGDATA stop
fi
if pgrep -x "postgres" > /dev/null; then
echo "Error: a postgres process is already running"
exit 1
fi
if [ -d $PGDATA ]; then
rm -rf $PGDATA
fi
initdb -D $PGDATA
echo "shared_preload_libraries ='pg_tde'" >> $PGDATA/postgresql.conf
pg_ctl -D $PGDATA start
createdb setup_helper
psql setup_helper < $SCRIPT_DIR/tde_setup_global.sql
echo "pg_tde.wal_encrypt = on" >> $PGDATA/postgresql.conf
pg_ctl -D $PGDATA restart
source $SCRIPT_DIR/configure-tde-server.sh
ADD_FLAGS=

Loading…
Cancel
Save