|
| 1 | +-- Bulk Insert Performance Roundtrip Test |
| 2 | +-- Tests roundtrip with 1000 rows and measures time for each operation. |
| 3 | + |
| 4 | +\set testid '18' |
| 5 | +\ir helper_test_init.sql |
| 6 | + |
| 7 | +\connect postgres |
| 8 | +\ir helper_psql_conn_setup.sql |
| 9 | + |
| 10 | +-- Cleanup and create test databases |
| 11 | +DROP DATABASE IF EXISTS cloudsync_test_18a; |
| 12 | +DROP DATABASE IF EXISTS cloudsync_test_18b; |
| 13 | +CREATE DATABASE cloudsync_test_18a; |
| 14 | +CREATE DATABASE cloudsync_test_18b; |
| 15 | + |
| 16 | +-- ============================================================================ |
| 17 | +-- Setup Database A |
| 18 | +-- ============================================================================ |
| 19 | + |
| 20 | +\connect cloudsync_test_18a |
| 21 | +\ir helper_psql_conn_setup.sql |
| 22 | +CREATE EXTENSION IF NOT EXISTS cloudsync; |
| 23 | + |
| 24 | +CREATE TABLE items ( |
| 25 | + id UUID NOT NULL PRIMARY KEY DEFAULT cloudsync_uuid(), |
| 26 | + name TEXT NOT NULL DEFAULT '', |
| 27 | + value DOUBLE PRECISION NOT NULL DEFAULT 0.0, |
| 28 | + quantity INTEGER NOT NULL DEFAULT 0, |
| 29 | + description TEXT |
| 30 | +); |
| 31 | + |
| 32 | +-- Initialize CloudSync |
| 33 | +SELECT cloudsync_init('items', 'CLS', false) AS _init_a \gset |
| 34 | + |
| 35 | +-- ============================================================================ |
| 36 | +-- Record start time |
| 37 | +-- ============================================================================ |
| 38 | + |
| 39 | +SELECT clock_timestamp() AS test_start_time \gset |
| 40 | +\echo [INFO] (:testid) Test started at :test_start_time |
| 41 | + |
| 42 | +-- ============================================================================ |
| 43 | +-- Insert 1000 rows and measure time |
| 44 | +-- ============================================================================ |
| 45 | + |
| 46 | +SELECT clock_timestamp() AS insert_start_time \gset |
| 47 | + |
| 48 | +INSERT INTO items (name, value, quantity, description) |
| 49 | +SELECT |
| 50 | + 'Item ' || i, |
| 51 | + (random() * 1000)::DOUBLE PRECISION, |
| 52 | + (random() * 100)::INTEGER, |
| 53 | + 'Description for item ' || i || ' with some additional text to simulate real data' |
| 54 | +FROM generate_series(1, 1000) AS i; |
| 55 | + |
| 56 | +SELECT clock_timestamp() AS insert_end_time \gset |
| 57 | + |
| 58 | +SELECT EXTRACT(EPOCH FROM (:'insert_end_time'::timestamp - :'insert_start_time'::timestamp)) * 1000 AS insert_time_ms \gset |
| 59 | +\echo [INFO] (:testid) Insert 1000 rows: :insert_time_ms ms |
| 60 | + |
| 61 | +-- ============================================================================ |
| 62 | +-- Verify row count in Database A |
| 63 | +-- ============================================================================ |
| 64 | + |
| 65 | +SELECT COUNT(*) AS count_a FROM items \gset |
| 66 | +SELECT (:count_a = 1000) AS insert_count_ok \gset |
| 67 | +\if :insert_count_ok |
| 68 | +\echo [PASS] (:testid) Inserted 1000 rows successfully |
| 69 | +\else |
| 70 | +\echo [FAIL] (:testid) Expected 1000 rows, got :count_a |
| 71 | +SELECT (:fail::int + 1) AS fail \gset |
| 72 | +\endif |
| 73 | + |
| 74 | +-- ============================================================================ |
| 75 | +-- Compute hash of Database A data |
| 76 | +-- ============================================================================ |
| 77 | + |
| 78 | +SELECT md5( |
| 79 | + COALESCE( |
| 80 | + string_agg( |
| 81 | + id::text || ':' || |
| 82 | + COALESCE(name, 'NULL') || ':' || |
| 83 | + COALESCE(value::text, 'NULL') || ':' || |
| 84 | + COALESCE(quantity::text, 'NULL') || ':' || |
| 85 | + COALESCE(description, 'NULL'), |
| 86 | + '|' ORDER BY id |
| 87 | + ), |
| 88 | + '' |
| 89 | + ) |
| 90 | +) AS hash_a FROM items \gset |
| 91 | + |
| 92 | +\echo [INFO] (:testid) Database A hash: :hash_a |
| 93 | + |
| 94 | +-- ============================================================================ |
| 95 | +-- Encode payload from Database A and measure time |
| 96 | +-- ============================================================================ |
| 97 | + |
| 98 | +SELECT clock_timestamp() AS encode_start_time \gset |
| 99 | + |
| 100 | +SELECT encode( |
| 101 | + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), |
| 102 | + 'hex' |
| 103 | +) AS payload_a_hex |
| 104 | +FROM cloudsync_changes |
| 105 | +WHERE site_id = cloudsync_siteid() \gset |
| 106 | + |
| 107 | +SELECT clock_timestamp() AS encode_end_time \gset |
| 108 | + |
| 109 | +SELECT EXTRACT(EPOCH FROM (:'encode_end_time'::timestamp - :'encode_start_time'::timestamp)) * 1000 AS encode_time_ms \gset |
| 110 | +\echo [INFO] (:testid) Encode payload: :encode_time_ms ms |
| 111 | + |
| 112 | +-- Verify payload was created |
| 113 | +SELECT (length(:'payload_a_hex') > 0) AS payload_created \gset |
| 114 | +\if :payload_created |
| 115 | +\echo [PASS] (:testid) Payload encoded from Database A |
| 116 | +\else |
| 117 | +\echo [FAIL] (:testid) Payload encoded from Database A - Empty payload |
| 118 | +SELECT (:fail::int + 1) AS fail \gset |
| 119 | +\endif |
| 120 | + |
| 121 | +-- Report payload size |
| 122 | +SELECT length(:'payload_a_hex') / 2 AS payload_size_bytes \gset |
| 123 | +\echo [INFO] (:testid) Payload size: :payload_size_bytes bytes |
| 124 | + |
| 125 | +-- ============================================================================ |
| 126 | +-- Setup Database B with same schema |
| 127 | +-- ============================================================================ |
| 128 | + |
| 129 | +\connect cloudsync_test_18b |
| 130 | +\ir helper_psql_conn_setup.sql |
| 131 | +CREATE EXTENSION IF NOT EXISTS cloudsync; |
| 132 | + |
| 133 | +CREATE TABLE items ( |
| 134 | + id UUID NOT NULL PRIMARY KEY DEFAULT cloudsync_uuid(), |
| 135 | + name TEXT NOT NULL DEFAULT '', |
| 136 | + value DOUBLE PRECISION NOT NULL DEFAULT 0.0, |
| 137 | + quantity INTEGER NOT NULL DEFAULT 0, |
| 138 | + description TEXT |
| 139 | +); |
| 140 | + |
| 141 | +-- Initialize CloudSync |
| 142 | +SELECT cloudsync_init('items', 'CLS', false) AS _init_b \gset |
| 143 | + |
| 144 | +-- ============================================================================ |
| 145 | +-- Apply payload to Database B and measure time |
| 146 | +-- ============================================================================ |
| 147 | + |
| 148 | +SELECT clock_timestamp() AS apply_start_time \gset |
| 149 | + |
| 150 | +SELECT cloudsync_payload_apply(decode(:'payload_a_hex', 'hex')) AS apply_result \gset |
| 151 | + |
| 152 | +SELECT clock_timestamp() AS apply_end_time \gset |
| 153 | + |
| 154 | +SELECT EXTRACT(EPOCH FROM (:'apply_end_time'::timestamp - :'apply_start_time'::timestamp)) * 1000 AS apply_time_ms \gset |
| 155 | +\echo [INFO] (:testid) Apply payload: :apply_time_ms ms |
| 156 | + |
| 157 | +-- Verify application succeeded |
| 158 | +SELECT (:apply_result >= 0) AS payload_applied \gset |
| 159 | +\if :payload_applied |
| 160 | +\echo [PASS] (:testid) Payload applied to Database B |
| 161 | +\else |
| 162 | +\echo [FAIL] (:testid) Payload applied to Database B - Apply returned :apply_result |
| 163 | +SELECT (:fail::int + 1) AS fail \gset |
| 164 | +\endif |
| 165 | + |
| 166 | +-- ============================================================================ |
| 167 | +-- Verify data integrity after roundtrip |
| 168 | +-- ============================================================================ |
| 169 | + |
| 170 | +SELECT md5( |
| 171 | + COALESCE( |
| 172 | + string_agg( |
| 173 | + id::text || ':' || |
| 174 | + COALESCE(name, 'NULL') || ':' || |
| 175 | + COALESCE(value::text, 'NULL') || ':' || |
| 176 | + COALESCE(quantity::text, 'NULL') || ':' || |
| 177 | + COALESCE(description, 'NULL'), |
| 178 | + '|' ORDER BY id |
| 179 | + ), |
| 180 | + '' |
| 181 | + ) |
| 182 | +) AS hash_b FROM items \gset |
| 183 | + |
| 184 | +\echo [INFO] (:testid) Database B hash: :hash_b |
| 185 | + |
| 186 | +SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset |
| 187 | +\if :hashes_match |
| 188 | +\echo [PASS] (:testid) Data integrity verified - hashes match |
| 189 | +\else |
| 190 | +\echo [FAIL] (:testid) Data integrity check failed - Database A hash: :hash_a, Database B hash: :hash_b |
| 191 | +SELECT (:fail::int + 1) AS fail \gset |
| 192 | +\endif |
| 193 | + |
| 194 | +-- ============================================================================ |
| 195 | +-- Verify row count |
| 196 | +-- ============================================================================ |
| 197 | + |
| 198 | +SELECT COUNT(*) AS count_b FROM items \gset |
| 199 | + |
| 200 | +SELECT (:count_b = :count_a) AS row_counts_match \gset |
| 201 | +\if :row_counts_match |
| 202 | +\echo [PASS] (:testid) Row counts match (:count_b rows) |
| 203 | +\else |
| 204 | +\echo [FAIL] (:testid) Row counts mismatch - Database A: :count_a, Database B: :count_b |
| 205 | +SELECT (:fail::int + 1) AS fail \gset |
| 206 | +\endif |
| 207 | + |
| 208 | +-- ============================================================================ |
| 209 | +-- Verify sample data integrity |
| 210 | +-- ============================================================================ |
| 211 | + |
| 212 | +SELECT COUNT(*) = 1 AS sample_check_ok |
| 213 | +FROM items |
| 214 | +WHERE name = 'Item 500' \gset |
| 215 | +\if :sample_check_ok |
| 216 | +\echo [PASS] (:testid) Sample row verified (name='Item 500') |
| 217 | +\else |
| 218 | +\echo [FAIL] (:testid) Sample row verification failed |
| 219 | +SELECT (:fail::int + 1) AS fail \gset |
| 220 | +\endif |
| 221 | + |
| 222 | +-- ============================================================================ |
| 223 | +-- Calculate and report total elapsed time |
| 224 | +-- ============================================================================ |
| 225 | + |
| 226 | +SELECT clock_timestamp() AS test_end_time \gset |
| 227 | + |
| 228 | +SELECT EXTRACT(EPOCH FROM (:'test_end_time'::timestamp - :'test_start_time'::timestamp)) * 1000 AS total_time_ms \gset |
| 229 | + |
| 230 | +\echo [INFO] (:testid) Performance summary: |
| 231 | +\echo [INFO] (:testid) - Insert 1000 rows: :insert_time_ms ms |
| 232 | +\echo [INFO] (:testid) - Encode payload: :encode_time_ms ms |
| 233 | +\echo [INFO] (:testid) - Apply payload: :apply_time_ms ms |
| 234 | +\echo [INFO] (:testid) - Total elapsed time: :total_time_ms ms |
| 235 | + |
| 236 | +-- ============================================================================ |
| 237 | +-- Cleanup: Drop test databases if not in DEBUG mode and no failures |
| 238 | +-- ============================================================================ |
| 239 | + |
| 240 | +\ir helper_test_cleanup.sql |
| 241 | +\if :should_cleanup |
| 242 | +DROP DATABASE IF EXISTS cloudsync_test_18a; |
| 243 | +DROP DATABASE IF EXISTS cloudsync_test_18b; |
| 244 | +\endif |
0 commit comments