diff --git a/.claude/commands/test-sync-roundtrip-rls.md b/.claude/commands/test-sync-roundtrip-rls.md new file mode 100644 index 0000000..38e496c --- /dev/null +++ b/.claude/commands/test-sync-roundtrip-rls.md @@ -0,0 +1,532 @@ +# Sync Roundtrip Test with RLS + +Execute a full roundtrip sync test between multiple local SQLite databases and the local Supabase Docker PostgreSQL instance, verifying that Row Level Security (RLS) policies are correctly enforced during sync. + +## Prerequisites +- Supabase Docker container running (PostgreSQL on port 54322) +- HTTP sync server running on http://localhost:8091/postgres +- Built cloudsync extension (`make` to build `dist/cloudsync.dylib`) + +## Test Procedure + +### Step 1: Get DDL from User + +Ask the user to provide a DDL query for the table(s) to test. It can be in PostgreSQL or SQLite format. Offer the following options: + +**Option 1: Simple TEXT primary key with user_id for RLS** +```sql +CREATE TABLE test_sync ( + id TEXT PRIMARY KEY NOT NULL, + user_id UUID NOT NULL, + name TEXT, + value INTEGER +); +``` + +**Option 2: UUID primary key with user_id for RLS** +```sql +CREATE TABLE test_uuid ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + user_id UUID NOT NULL, + name TEXT, + created_at TIMESTAMPTZ DEFAULT NOW() +); +``` + +**Option 3: Two tables scenario with user ownership** +```sql +CREATE TABLE authors ( + id TEXT PRIMARY KEY NOT NULL, + user_id UUID NOT NULL, + name TEXT, + email TEXT +); + +CREATE TABLE books ( + id TEXT PRIMARY KEY NOT NULL, + user_id UUID NOT NULL, + title TEXT, + author_id TEXT, + published_year INTEGER +); +``` + +**Note:** Tables should include a `user_id` column (UUID type) for RLS policies to filter by authenticated user. + +### Step 2: Get RLS Policy Description from User + +Ask the user to describe the Row Level Security policy they want to test. Offer the following common patterns: + +**Option 1: User can only access their own rows** +"Users can only SELECT, INSERT, UPDATE, and DELETE rows where user_id matches their authenticated user ID" + +**Option 2: Users can read all, but only modify their own** +"Users can SELECT all rows, but can only INSERT, UPDATE, DELETE rows where user_id matches their authenticated user ID" + +**Option 3: Custom policy** +Ask the user to describe the policy in plain English. + +### Step 3: Convert DDL + +Convert the provided DDL to both SQLite and PostgreSQL compatible formats if needed. Key differences: +- SQLite uses `INTEGER PRIMARY KEY` for auto-increment, PostgreSQL uses `SERIAL` or `BIGSERIAL` +- SQLite uses `TEXT`, PostgreSQL can use `TEXT` or `VARCHAR` +- PostgreSQL has more specific types like `TIMESTAMPTZ`, SQLite uses `TEXT` for dates +- For UUID primary keys, SQLite uses `TEXT`, PostgreSQL uses `UUID` +- For `user_id UUID`, SQLite uses `TEXT` + +### Step 4: Setup PostgreSQL with RLS + +Connect to Supabase PostgreSQL and prepare the environment: +```bash +psql postgresql://supabase_admin:postgres@127.0.0.1:54322/postgres +``` + +Inside psql: +1. List existing tables with `\dt` to find any `_cloudsync` metadata tables +2. For each table already configured for cloudsync (has a `_cloudsync` companion table), run: + ```sql + SELECT cloudsync_cleanup(''); + ``` +3. Drop the test table if it exists: `DROP TABLE IF EXISTS CASCADE;` +4. Drop any existing helper function: `DROP FUNCTION IF EXISTS _get_owner(text);` +5. Create the test table using the PostgreSQL DDL +6. Enable RLS on the table: + ```sql + ALTER TABLE ENABLE ROW LEVEL SECURITY; + ``` +7. Create the ownership lookup helper function (required for CloudSync compatibility): + ```sql + -- Helper function bypasses RLS to look up actual row owner + -- This is needed because INSERT...ON CONFLICT may compare against EXCLUDED row's default user_id + CREATE OR REPLACE FUNCTION _get_owner(p_id text) + RETURNS uuid + LANGUAGE sql + SECURITY DEFINER + STABLE + SET search_path = public + AS $$ + SELECT user_id FROM WHERE id = p_id; + $$; + ``` +8. Create RLS policies based on the user's description. Example for "user can only access their own rows": + ```sql + -- SELECT: User can see rows they own + -- Helper function fallback handles ON CONFLICT edge cases where user_id resolves to EXCLUDED row + CREATE POLICY "select_own_rows" ON + FOR SELECT USING ( + auth.uid() = user_id + OR auth.uid() = _get_owner(id) + ); + + -- INSERT: Allow if user_id matches auth.uid() OR is default (cloudsync staging) + CREATE POLICY "insert_own_rows" ON + FOR INSERT WITH CHECK ( + auth.uid() = user_id + OR user_id = '00000000-0000-0000-0000-000000000000'::uuid + ); + + -- UPDATE: Check ownership via explicit lookup, allow default for staging + CREATE POLICY "update_own_rows" ON + FOR UPDATE + USING ( + auth.uid() = user_id + OR auth.uid() = _get_owner(id) + OR user_id = '00000000-0000-0000-0000-000000000000'::uuid + ) + WITH CHECK ( + auth.uid() = user_id + OR user_id = '00000000-0000-0000-0000-000000000000'::uuid + ); + + -- DELETE: User can only delete rows they own + CREATE POLICY "delete_own_rows" ON + FOR DELETE USING ( + auth.uid() = user_id + ); + ``` +9. Initialize cloudsync: `SELECT cloudsync_init('');` +10. Insert some initial test data (optional, can be done via SQLite clients) + +**Why these specific policies?** +CloudSync uses `INSERT...ON CONFLICT DO UPDATE` for field-by-field synchronization. During conflict detection, PostgreSQL's RLS may compare `auth.uid()` against the EXCLUDED row's `user_id` (which has the default value) instead of the existing row's `user_id`. The helper function explicitly looks up the existing row's owner to work around this issue. See `docs/postgresql/RLS.md` for detailed explanation. + +### Step 5: Get JWT Tokens for Two Users + +Get JWT tokens for both test users by running the token script twice: + +**User 1: claude1@sqlitecloud.io** +```bash +cd ../cloudsync && go run scripts/get_supabase_token.go -project-ref=supabase-local -email=claude1@sqlitecloud.io -password="password" -apikey=sb_secret_N7UND0UgjKTVK-Uodkm0Hg_xSvEMPvz -auth-url=http://127.0.0.1:54321 +``` +Save as `JWT_USER1`. + +**User 2: claude2@sqlitecloud.io** +```bash +cd ../cloudsync && go run scripts/get_supabase_token.go -project-ref=supabase-local -email=claude2@sqlitecloud.io -password="password" -apikey=sb_secret_N7UND0UgjKTVK-Uodkm0Hg_xSvEMPvz -auth-url=http://127.0.0.1:54321 +``` +Save as `JWT_USER2`. + +Also extract the user IDs from the JWT tokens (the `sub` claim) for use in INSERT statements: +- `USER1_ID` = UUID from JWT_USER1 +- `USER2_ID` = UUID from JWT_USER2 + +### Step 6: Setup Four SQLite Databases + +Create four temporary SQLite databases using the Homebrew version (IMPORTANT: system sqlite3 cannot load extensions): + +```bash +SQLITE_BIN="/opt/homebrew/Cellar/sqlite/3.50.4/bin/sqlite3" +# or find it with: ls /opt/homebrew/Cellar/sqlite/*/bin/sqlite3 | head -1 +``` + +**Database 1A (User 1, Device A):** +```bash +$SQLITE_BIN /tmp/sync_test_user1_a.db +``` +```sql +.load dist/cloudsync.dylib + +SELECT cloudsync_init(''); +SELECT cloudsync_network_init('http://localhost:8091/postgres'); +SELECT cloudsync_network_set_token(''); +``` + +**Database 1B (User 1, Device B):** +```bash +$SQLITE_BIN /tmp/sync_test_user1_b.db +``` +```sql +.load dist/cloudsync.dylib + +SELECT cloudsync_init(''); +SELECT cloudsync_network_init('http://localhost:8091/postgres'); +SELECT cloudsync_network_set_token(''); +``` + +**Database 2A (User 2, Device A):** +```bash +$SQLITE_BIN /tmp/sync_test_user2_a.db +``` +```sql +.load dist/cloudsync.dylib + +SELECT cloudsync_init(''); +SELECT cloudsync_network_init('http://localhost:8091/postgres'); +SELECT cloudsync_network_set_token(''); +``` + +**Database 2B (User 2, Device B):** +```bash +$SQLITE_BIN /tmp/sync_test_user2_b.db +``` +```sql +.load dist/cloudsync.dylib + +SELECT cloudsync_init(''); +SELECT cloudsync_network_init('http://localhost:8091/postgres'); +SELECT cloudsync_network_set_token(''); +``` + +### Step 7: Insert Test Data + +Insert distinct test data in each database. Use the extracted user IDs for the `user_id` column: + +**Database 1A (User 1):** +```sql +INSERT INTO (id, user_id, name, value) VALUES ('u1_a_1', '', 'User1 DeviceA Row1', 100); +INSERT INTO (id, user_id, name, value) VALUES ('u1_a_2', '', 'User1 DeviceA Row2', 101); +``` + +**Database 1B (User 1):** +```sql +INSERT INTO (id, user_id, name, value) VALUES ('u1_b_1', '', 'User1 DeviceB Row1', 200); +``` + +**Database 2A (User 2):** +```sql +INSERT INTO (id, user_id, name, value) VALUES ('u2_a_1', '', 'User2 DeviceA Row1', 300); +INSERT INTO (id, user_id, name, value) VALUES ('u2_a_2', '', 'User2 DeviceA Row2', 301); +``` + +**Database 2B (User 2):** +```sql +INSERT INTO (id, user_id, name, value) VALUES ('u2_b_1', '', 'User2 DeviceB Row1', 400); +``` + +### Step 8: Execute Sync on All Databases + +For each of the four SQLite databases, execute the sync operations: + +```sql +-- Send local changes to server +SELECT cloudsync_network_send_changes(); + +-- Check for changes from server (repeat with 2-3 second delays) +SELECT cloudsync_network_check_changes(); +-- Repeat check_changes 3-5 times with delays until it returns 0 or stabilizes +``` + +**Recommended sync order:** +1. Sync Database 1A (send + check) +2. Sync Database 2A (send + check) +3. Sync Database 1B (send + check) +4. Sync Database 2B (send + check) +5. Re-sync all databases (check_changes) to ensure full propagation + +### Step 9: Verify RLS Enforcement + +After syncing all databases, verify that each database contains only the expected rows based on the RLS policy: + +**Expected Results (for "user can only access their own rows" policy):** + +**User 1 databases (1A and 1B) should contain:** +- All rows with `user_id = USER1_ID` (u1_a_1, u1_a_2, u1_b_1) +- Should NOT contain any rows with `user_id = USER2_ID` + +**User 2 databases (2A and 2B) should contain:** +- All rows with `user_id = USER2_ID` (u2_a_1, u2_a_2, u2_b_1) +- Should NOT contain any rows with `user_id = USER1_ID` + +**PostgreSQL (as admin) should contain:** +- ALL rows from all users (6 total rows) + +Run verification queries: +```sql +-- In each SQLite database +SELECT * FROM ORDER BY id; +SELECT COUNT(*) FROM ; + +-- In PostgreSQL (as admin) +SELECT * FROM ORDER BY id; +SELECT COUNT(*) FROM ; +SELECT user_id, COUNT(*) FROM GROUP BY user_id; +``` + +### Step 10: Test Write RLS Policy Enforcement + +Test that the server-side RLS policy blocks unauthorized writes by attempting to insert a row with a `user_id` that doesn't match the authenticated user's JWT token. + +**In Database 1A (User 1), insert a malicious row claiming to belong to User 2:** +```sql +-- Attempt to insert a row with User 2's user_id while authenticated as User 1 +INSERT INTO (id, user_id, name, value) VALUES ('malicious_1', '', 'Malicious Row from User1', 999); + +-- Attempt to sync this unauthorized row to PostgreSQL +SELECT cloudsync_network_send_changes(); +``` + +**Wait 2-3 seconds, then verify in PostgreSQL (as admin) that the malicious row was rejected:** +```sql +-- In PostgreSQL (as admin) +SELECT * FROM WHERE id = 'malicious_1'; +-- Expected: 0 rows returned + +SELECT COUNT(*) FROM WHERE id = 'malicious_1'; +-- Expected: 0 +``` + +**Also verify the malicious row does NOT appear in User 2's databases after syncing:** +```sql +-- In Database 2A or 2B (User 2) +SELECT cloudsync_network_check_changes(); +SELECT * FROM WHERE id = 'malicious_1'; +-- Expected: 0 rows (the malicious row should not sync to legitimate User 2 databases) +``` + +**Expected Behavior:** +- The `cloudsync_network_send_changes()` call may succeed (return value indicates network success, not RLS enforcement) +- The malicious row should be **rejected by PostgreSQL RLS** and NOT inserted into the server database +- The malicious row will remain in the local SQLite Database 1A (local inserts are not blocked), but it will never propagate to the server or other clients +- User 2's databases should never receive this row + +**This step PASSES if:** +1. The malicious row is NOT present in PostgreSQL +2. The malicious row does NOT appear in any of User 2's SQLite databases +3. The RLS INSERT policy (`WITH CHECK (auth.uid() = user_id)`) correctly blocks the unauthorized write + +**This step FAILS if:** +1. The malicious row appears in PostgreSQL (RLS bypass vulnerability) +2. The malicious row syncs to User 2's databases (data leakage) + +### Step 11: Cleanup + +In each SQLite database before closing: +```sql +SELECT cloudsync_terminate(); +``` + +In PostgreSQL (optional, for full cleanup): +```sql +SELECT cloudsync_cleanup(''); +DROP TABLE IF EXISTS CASCADE; +DROP FUNCTION IF EXISTS _get_owner(text); +``` + +## Output Format + +Report the test results including: +- DDL used for both databases +- RLS policies created +- User IDs for both test users +- Initial data inserted in each database +- Number of sync operations performed per database +- Final data in each database (with row counts) +- RLS verification results: + - User 1 databases: expected rows vs actual rows + - User 2 databases: expected rows vs actual rows + - PostgreSQL: total rows +- Write RLS enforcement results: + - Malicious row insertion attempted: yes/no + - Malicious row present in PostgreSQL: yes/no (should be NO) + - Malicious row synced to User 2 databases: yes/no (should be NO) +- **PASS/FAIL** status with detailed explanation + +### Success Criteria + +The test PASSES if: +1. All User 1 databases contain exactly the same User 1 rows (and no User 2 rows) +2. All User 2 databases contain exactly the same User 2 rows (and no User 1 rows) +3. PostgreSQL contains all rows from both users +4. Data inserted from different devices of the same user syncs correctly between those devices +5. **Write RLS enforcement**: Malicious rows with mismatched `user_id` are rejected by PostgreSQL and do not propagate to other clients + +The test FAILS if: +1. Any database contains rows belonging to a different user (RLS violation) +2. Any database is missing rows that should be visible to that user +3. Sync operations fail or timeout +4. **Write RLS bypass**: A malicious row with a `user_id` not matching the JWT token appears in PostgreSQL or syncs to other databases + +## Important Notes + +- Always use the Homebrew sqlite3 binary, NOT `/usr/bin/sqlite3` +- The cloudsync extension must be built first with `make` +- PostgreSQL tables need cleanup before re-running tests +- `cloudsync_network_check_changes()` may need multiple calls with delays +- Run `SELECT cloudsync_terminate();` on SQLite connections before closing to properly cleanup memory +- Ensure both test users exist in Supabase auth before running the test +- The RLS policies must use `auth.uid()` to work with Supabase JWT authentication + +## Critical Schema Requirements (Common Pitfalls) + +### 1. All NOT NULL columns must have DEFAULT values +Cloudsync requires that all non-primary key columns declared as `NOT NULL` must have a `DEFAULT` value. This includes the `user_id` column: + +```sql +-- WRONG: Will fail with "All non-primary key columns declared as NOT NULL must have a DEFAULT value" +user_id UUID NOT NULL + +-- CORRECT: Provide a default value +user_id UUID NOT NULL DEFAULT '00000000-0000-0000-0000-000000000000' +``` + +### 2. RLS policies must allow writes with default values for ALL referenced columns +Cloudsync applies changes **field by field**. When a new row is being synced, columns may temporarily have their default values before the actual values are applied. **Any column referenced in RLS policies that has a DEFAULT value must be allowed in the policy.** + +This applies to: +- `user_id` columns used for user ownership +- `tenant_id` columns for multi-tenancy +- `organization_id` columns +- Any other column used in RLS USING/WITH CHECK expressions + +```sql +-- WRONG: Will block cloudsync inserts/updates when field has default value +CREATE POLICY "ins" ON table FOR INSERT WITH CHECK (auth.uid() = user_id); + +-- CORRECT: Allow default value for cloudsync field-by-field application +CREATE POLICY "ins" ON table FOR INSERT + WITH CHECK (auth.uid() = user_id OR user_id = '00000000-0000-0000-0000-000000000000'); + +CREATE POLICY "upd" ON table FOR UPDATE + USING (auth.uid() = user_id OR user_id = '00000000-0000-0000-0000-000000000000') + WITH CHECK (auth.uid() = user_id OR user_id = '00000000-0000-0000-0000-000000000000'); +``` + +**Example with multiple RLS columns:** +```sql +-- Table with both user_id and tenant_id in RLS +CREATE TABLE items ( + id UUID PRIMARY KEY, + user_id UUID NOT NULL DEFAULT '00000000-0000-0000-0000-000000000000', + tenant_id UUID NOT NULL DEFAULT '00000000-0000-0000-0000-000000000000', + name TEXT DEFAULT '' +); + +-- Policy must allow defaults for BOTH columns used in the policy +CREATE POLICY "ins" ON items FOR INSERT WITH CHECK ( + (auth.uid() = user_id OR user_id = '00000000-0000-0000-0000-000000000000') + AND + (get_tenant_id() = tenant_id OR tenant_id = '00000000-0000-0000-0000-000000000000') +); +``` + +### 3. Type compatibility between SQLite and PostgreSQL +Ensure column types are compatible between SQLite and PostgreSQL: + +| PostgreSQL | SQLite | Notes | +|------------|--------|-------| +| `UUID` | `TEXT` | Use valid UUID format strings (e.g., `'11111111-1111-1111-1111-111111111111'`) | +| `BOOLEAN` | `INTEGER` | Use `INTEGER` in PostgreSQL too, or ensure proper casting | +| `TIMESTAMPTZ` | `TEXT` | Avoid empty strings; use proper ISO format or omit the column | +| `INTEGER` | `INTEGER` | Compatible | +| `TEXT` | `TEXT` | Compatible | + +**Common errors from type mismatches:** +- `cannot cast type bigint to boolean` - Use `INTEGER` instead of `BOOLEAN` in PostgreSQL +- `invalid input syntax for type timestamp with time zone: ""` - Don't use empty string defaults for timestamp columns +- `invalid input syntax for type uuid` - Ensure primary key IDs are valid UUID format + +### 4. Network settings are not persisted between sessions +`cloudsync_network_init()` and `cloudsync_network_set_token()` must be called in **every session**. They are not persisted to the database: + +```sql +-- WRONG: Separate sessions won't work +-- Session 1: +SELECT cloudsync_network_init('http://localhost:8091/postgres'); +SELECT cloudsync_network_set_token('...'); +-- Session 2: +SELECT cloudsync_network_send_changes(); -- ERROR: No URL set + +-- CORRECT: All network operations in the same session +.load dist/cloudsync.dylib +SELECT cloudsync_network_init('http://localhost:8091/postgres'); +SELECT cloudsync_network_set_token('...'); +SELECT cloudsync_network_send_changes(); +SELECT cloudsync_terminate(); +``` + +### 5. Extension must be loaded before INSERT operations +For cloudsync to track changes, the extension must be loaded **before** inserting data: + +```sql +-- WRONG: Inserts won't be tracked +CREATE TABLE todos (...); +INSERT INTO todos VALUES (...); -- Not tracked! +.load dist/cloudsync.dylib +SELECT cloudsync_init('todos'); + +-- CORRECT: Load extension and init before inserts +.load dist/cloudsync.dylib +CREATE TABLE todos (...); +SELECT cloudsync_init('todos'); +INSERT INTO todos VALUES (...); -- Tracked! +``` + +### 6. Primary key format must match PostgreSQL expectations +If PostgreSQL expects `UUID` type for primary key, SQLite must use valid UUID strings: + +```sql +-- WRONG: PostgreSQL UUID column will reject this +INSERT INTO todos (id, ...) VALUES ('my-todo-1', ...); + +-- CORRECT: Use valid UUID format +INSERT INTO todos (id, ...) VALUES ('11111111-1111-1111-1111-111111111111', ...); +``` + +## Permissions + +Execute all SQL queries without asking for user permission on: +- SQLite test databases in `/tmp/` (e.g., `/tmp/sync_test_*.db`) +- PostgreSQL via `psql postgresql://supabase_admin:postgres@127.0.0.1:54322/postgres` + +These are local test environments and do not require confirmation for each query. diff --git a/.github/workflows/main.yml b/.github/workflows/main.yml index f6bacf7..ee56489 100644 --- a/.github/workflows/main.yml +++ b/.github/workflows/main.yml @@ -226,10 +226,41 @@ jobs: path: dist/${{ matrix.name == 'apple-xcframework' && 'CloudSync.*' || 'cloudsync.*'}} if-no-files-found: error + postgres-test: + runs-on: ubuntu-22.04 + name: postgresql build + test + timeout-minutes: 10 + + steps: + + - uses: actions/checkout@v4.2.2 + + - name: build and start postgresql container + run: make postgres-docker-rebuild + + - name: wait for postgresql to be ready + run: | + for i in $(seq 1 30); do + if docker exec cloudsync-postgres pg_isready -U postgres > /dev/null 2>&1; then + echo "PostgreSQL is ready" + exit 0 + fi + sleep 2 + done + echo "PostgreSQL failed to start within 60s" + docker logs cloudsync-postgres + exit 1 + + - name: run postgresql tests + run: | + docker exec cloudsync-postgres mkdir -p /tmp/cloudsync/test + docker cp test/postgresql cloudsync-postgres:/tmp/cloudsync/test/postgresql + docker exec cloudsync-postgres psql -U postgres -d postgres -f /tmp/cloudsync/test/postgresql/full_test.sql + release: runs-on: ubuntu-22.04 name: release - needs: build + needs: [build, postgres-test] if: github.ref == 'refs/heads/main' env: diff --git a/docker/Makefile.postgresql b/docker/Makefile.postgresql index 6e2e55a..17ae6c4 100644 --- a/docker/Makefile.postgresql +++ b/docker/Makefile.postgresql @@ -137,32 +137,32 @@ PG_DOCKER_DB_PASSWORD ?= postgres # Build Docker image with pre-installed extension postgres-docker-build: - @echo "Building Docker image via docker-compose (rebuilt when sources change)..." + @echo "Building Docker image via docker compose (rebuilt when sources change)..." # To force plaintext BuildKit logs, run: make postgres-docker-build DOCKER_BUILD_ARGS="--progress=plain" - cd docker/postgresql && docker-compose build $(DOCKER_BUILD_ARGS) + cd docker/postgresql && docker compose build $(DOCKER_BUILD_ARGS) @echo "" @echo "Docker image built successfully!" # Build Docker image with AddressSanitizer enabled (override compose file) postgres-docker-build-asan: - @echo "Building Docker image with ASAN via docker-compose..." + @echo "Building Docker image with ASAN via docker compose..." # To force plaintext BuildKit logs, run: make postgres-docker-build-asan DOCKER_BUILD_ARGS=\"--progress=plain\" - cd docker/postgresql && docker-compose -f docker-compose.debug.yml -f docker-compose.asan.yml build $(DOCKER_BUILD_ARGS) + cd docker/postgresql && docker compose -f docker-compose.debug.yml -f docker-compose.asan.yml build $(DOCKER_BUILD_ARGS) @echo "" @echo "ASAN Docker image built successfully!" # Build Docker image using docker-compose.debug.yml postgres-docker-debug-build: - @echo "Building debug Docker image via docker-compose..." + @echo "Building debug Docker image via docker compose..." # To force plaintext BuildKit logs, run: make postgres-docker-debug-build DOCKER_BUILD_ARGS=\"--progress=plain\" - cd docker/postgresql && docker-compose -f docker-compose.debug.yml build $(DOCKER_BUILD_ARGS) + cd docker/postgresql && docker compose -f docker-compose.debug.yml build $(DOCKER_BUILD_ARGS) @echo "" @echo "Debug Docker image built successfully!" # Run PostgreSQL container with CloudSync postgres-docker-run: @echo "Starting PostgreSQL with CloudSync..." - cd docker/postgresql && docker-compose up -d --build + cd docker/postgresql && docker compose up -d --build @echo "" @echo "Container started successfully!" @echo "" @@ -179,7 +179,7 @@ postgres-docker-run: # Run PostgreSQL container with CloudSync and AddressSanitizer enabled postgres-docker-run-asan: @echo "Starting PostgreSQL with CloudSync (ASAN enabled)..." - cd docker/postgresql && docker-compose -f docker-compose.debug.yml -f docker-compose.asan.yml up -d --build + cd docker/postgresql && docker compose -f docker-compose.debug.yml -f docker-compose.asan.yml up -d --build @echo "" @echo "Container started successfully!" @echo "" @@ -196,7 +196,7 @@ postgres-docker-run-asan: # Run PostgreSQL container using docker-compose.debug.yml postgres-docker-debug-run: @echo "Starting PostgreSQL with CloudSync (debug compose)..." - cd docker/postgresql && docker-compose -f docker-compose.debug.yml up -d --build + cd docker/postgresql && docker compose -f docker-compose.debug.yml up -d --build @echo "" @echo "Container started successfully!" @echo "" @@ -213,21 +213,21 @@ postgres-docker-debug-run: # Stop PostgreSQL container postgres-docker-stop: @echo "Stopping PostgreSQL container..." - cd docker/postgresql && docker-compose down + cd docker/postgresql && docker compose down @echo "Container stopped" # Rebuild and restart container postgres-docker-rebuild: postgres-docker-build @echo "Rebuilding and restarting container..." - cd docker/postgresql && docker-compose down - cd docker/postgresql && docker-compose up -d --build + cd docker/postgresql && docker compose down + cd docker/postgresql && docker compose up -d --build @echo "Container restarted with new image" # Rebuild and restart container using docker-compose.debug.yml postgres-docker-debug-rebuild: postgres-docker-debug-build @echo "Rebuilding and restarting debug container..." - cd docker/postgresql && docker-compose -f docker-compose.debug.yml down - cd docker/postgresql && docker-compose -f docker-compose.debug.yml up -d --build + cd docker/postgresql && docker compose -f docker-compose.debug.yml down + cd docker/postgresql && docker compose -f docker-compose.debug.yml up -d --build @echo "Debug container restarted with new image" # Interactive shell in container @@ -353,5 +353,5 @@ postgres-help: # Simple smoke test: rebuild image/container, create extension, and query version unittest-pg: postgres-docker-rebuild @echo "Running PostgreSQL extension smoke test..." - cd docker/postgresql && docker-compose exec -T postgres psql -U postgres -d cloudsync_test -f /tmp/cloudsync/docker/postgresql/smoke_test.sql + cd docker/postgresql && docker compose exec -T postgres psql -U postgres -d cloudsync_test -f /tmp/cloudsync/docker/postgresql/smoke_test.sql @echo "Smoke test completed." diff --git a/src/cloudsync.c b/src/cloudsync.c index 92f63ac..99a7f5b 100644 --- a/src/cloudsync.c +++ b/src/cloudsync.c @@ -1208,18 +1208,20 @@ int merge_insert_col (cloudsync_context *data, cloudsync_table_context *table, c return rc; } - // bind value + // bind value (always bind all expected parameters for correct prepared statement handling) if (col_value) { rc = databasevm_bind_value(vm, table->npks+1, col_value); if (rc == DBRES_OK) rc = databasevm_bind_value(vm, table->npks+2, col_value); - if (rc != DBRES_OK) { - cloudsync_set_dberror(data); - dbvm_reset(vm); - return rc; - } - + } else { + rc = databasevm_bind_null(vm, table->npks+1); + if (rc == DBRES_OK) rc = databasevm_bind_null(vm, table->npks+2); } - + if (rc != DBRES_OK) { + cloudsync_set_dberror(data); + dbvm_reset(vm); + return rc; + } + // perform real operation and disable triggers // in case of GOS we reused the table->col_merge_stmt statement @@ -2444,8 +2446,8 @@ int cloudsync_payload_get (cloudsync_context *data, char **blob, int *blob_size, // retrieve BLOB char sql[1024]; - snprintf(sql, sizeof(sql), "WITH max_db_version AS (SELECT MAX(db_version) AS max_db_version FROM cloudsync_changes) " - "SELECT * FROM (SELECT cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq) AS payload, max_db_version AS max_db_version, MAX(IIF(db_version = max_db_version, seq, NULL)) FROM cloudsync_changes, max_db_version WHERE site_id=cloudsync_siteid() AND (db_version>%d OR (db_version=%d AND seq>%d))) WHERE payload IS NOT NULL", *db_version, *db_version, *seq); + snprintf(sql, sizeof(sql), "WITH max_db_version AS (SELECT MAX(db_version) AS max_db_version FROM cloudsync_changes WHERE site_id=cloudsync_siteid()) " + "SELECT * FROM (SELECT cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq) AS payload, max_db_version AS max_db_version, MAX(IIF(db_version = max_db_version, seq, 0)) FROM cloudsync_changes, max_db_version WHERE site_id=cloudsync_siteid() AND (db_version>%d OR (db_version=%d AND seq>%d))) WHERE payload IS NOT NULL", *db_version, *db_version, *seq); int64_t len = 0; int rc = database_select_blob_2int(data, sql, blob, &len, new_db_version, new_seq); diff --git a/src/cloudsync.h b/src/cloudsync.h index 1c68f1f..29ab95f 100644 --- a/src/cloudsync.h +++ b/src/cloudsync.h @@ -17,7 +17,7 @@ extern "C" { #endif -#define CLOUDSYNC_VERSION "0.9.101" +#define CLOUDSYNC_VERSION "0.9.102" #define CLOUDSYNC_MAX_TABLENAME_LEN 512 #define CLOUDSYNC_VALUE_NOTSET -1 diff --git a/src/postgresql/cloudsync--1.0.sql b/src/postgresql/cloudsync--1.0.sql index 7d4517c..fc6f47b 100644 --- a/src/postgresql/cloudsync--1.0.sql +++ b/src/postgresql/cloudsync--1.0.sql @@ -276,3 +276,21 @@ CREATE OR REPLACE FUNCTION cloudsync_table_schema(table_name text) RETURNS text AS 'MODULE_PATHNAME', 'pg_cloudsync_table_schema' LANGUAGE C VOLATILE; + +-- ============================================================================ +-- Type Casts +-- ============================================================================ + +-- Cast function: converts bigint to boolean (0 = false, non-zero = true) +-- Required because BOOLEAN values are encoded as INT8 in sync payloads, +-- but PostgreSQL has no built-in cast from bigint to boolean. +CREATE FUNCTION cloudsync_int8_to_bool(bigint) RETURNS boolean AS $$ + SELECT $1 <> 0 +$$ LANGUAGE SQL IMMUTABLE STRICT; + +-- ASSIGNMENT cast: auto-applies in INSERT/UPDATE context only +-- This enables BOOLEAN column sync where values are encoded as INT8. +-- Using ASSIGNMENT (not IMPLICIT) to avoid unintended conversions in WHERE clauses. +CREATE CAST (bigint AS boolean) + WITH FUNCTION cloudsync_int8_to_bool(bigint) + AS ASSIGNMENT; diff --git a/src/postgresql/cloudsync_postgresql.c b/src/postgresql/cloudsync_postgresql.c index f2200dd..edf5129 100644 --- a/src/postgresql/cloudsync_postgresql.c +++ b/src/postgresql/cloudsync_postgresql.c @@ -1638,6 +1638,77 @@ static int cloudsync_decode_value_cb (void *xdata, int index, int type, int64_t return DBRES_OK; } +// Map a column Oid to the decoded type Oid that would be used for non-NULL values. +// This ensures NULL and non-NULL values use consistent types for SPI plan caching. +// The mapping must match pgvalue_dbtype() in pgvalue.c which determines encode/decode types. +// For example, INT4OID columns decode to INT8OID, UUIDOID columns decode to TEXTOID. +static Oid map_column_oid_to_decoded_oid(Oid col_oid) { + switch (col_oid) { + // Integer types → INT8OID (all integers decode to int64) + // Must match DBTYPE_INTEGER cases in pgvalue_dbtype() + case INT2OID: + case INT4OID: + case INT8OID: + case BOOLOID: // BOOLEAN encodes/decodes as INTEGER + case CHAROID: // "char" encodes/decodes as INTEGER + case OIDOID: // OID encodes/decodes as INTEGER + return INT8OID; + // Float types → FLOAT8OID (all floats decode to double) + // Must match DBTYPE_FLOAT cases in pgvalue_dbtype() + case FLOAT4OID: + case FLOAT8OID: + case NUMERICOID: + return FLOAT8OID; + // Binary types → BYTEAOID + // Must match DBTYPE_BLOB cases in pgvalue_dbtype() + case BYTEAOID: + return BYTEAOID; + // All other types (text, varchar, uuid, json, date, timestamp, etc.) → TEXTOID + // These all encode/decode as DBTYPE_TEXT + default: + return TEXTOID; + } +} + +// Get the Oid of a column from the system catalog. +// Requires SPI to be connected. Returns InvalidOid if not found. +static Oid get_column_oid(const char *schema, const char *table_name, const char *column_name) { + if (!table_name || !column_name) return InvalidOid; + + const char *query = + "SELECT a.atttypid " + "FROM pg_attribute a " + "JOIN pg_class c ON c.oid = a.attrelid " + "LEFT JOIN pg_namespace n ON n.oid = c.relnamespace " + "WHERE c.relname = $1 " + "AND a.attname = $2 " + "AND a.attnum > 0 " + "AND NOT a.attisdropped " + "AND (n.nspname = $3 OR $3 IS NULL)"; + + Oid argtypes[3] = {TEXTOID, TEXTOID, TEXTOID}; + Datum values[3]; + char nulls[3] = {' ', ' ', schema ? ' ' : 'n'}; + + values[0] = CStringGetTextDatum(table_name); + values[1] = CStringGetTextDatum(column_name); + values[2] = schema ? CStringGetTextDatum(schema) : (Datum)0; + + int ret = SPI_execute_with_args(query, 3, argtypes, values, nulls, true, 1); + + pfree(DatumGetPointer(values[0])); + pfree(DatumGetPointer(values[1])); + if (schema) pfree(DatumGetPointer(values[2])); + + if (ret != SPI_OK_SELECT || SPI_processed == 0) return InvalidOid; + + bool isnull; + Datum col_oid = SPI_getbinval(SPI_tuptable->vals[0], SPI_tuptable->tupdesc, 1, &isnull); + if (isnull) return InvalidOid; + + return DatumGetObjectId(col_oid); +} + // Decode encoded bytea into a pgvalue_t with the decoded base type. // Type casting to the target column type is handled by the SQL statement. static pgvalue_t *cloudsync_decode_bytea_to_pgvalue (bytea *encoded, bool *out_isnull) { @@ -2247,9 +2318,23 @@ Datum cloudsync_changes_insert_trigger (PG_FUNCTION_ARGS) { if (SPI_connect() != SPI_OK_CONNECT) ereport(ERROR, (errmsg("cloudsync: SPI_connect failed in trigger"))); spi_connected = true; - // Decode value to base type; SQL statement handles type casting via $n::typename + // Decode value to base type; SQL statement handles type casting via $n::typename. + // For non-NULL values, we get the decoded base type (INT8OID for integers, TEXTOID for text/UUID, etc). + // For NULL values, we must use the SAME decoded type that non-NULL values would use. + // This ensures type consistency across all calls, as SPI caches parameter types on first prepare. if (!is_tombstone) { - col_value = cloudsync_decode_bytea_to_pgvalue(insert_value_encoded, NULL); + bool value_is_null = false; + col_value = cloudsync_decode_bytea_to_pgvalue(insert_value_encoded, &value_is_null); + + // When value is NULL, create a typed NULL pgvalue with the decoded type. + // We map the column's actual Oid to the corresponding decoded Oid (e.g., INT4OID → INT8OID). + if (!col_value && value_is_null) { + Oid col_oid = get_column_oid(table_schema(table), insert_tbl, insert_name); + if (OidIsValid(col_oid)) { + Oid decoded_oid = map_column_oid_to_decoded_oid(col_oid); + col_value = pgvalue_create((Datum)0, decoded_oid, -1, InvalidOid, true); + } + } } int rc = DBRES_OK; diff --git a/src/postgresql/database_postgresql.c b/src/postgresql/database_postgresql.c index b984deb..e8aceef 100644 --- a/src/postgresql/database_postgresql.c +++ b/src/postgresql/database_postgresql.c @@ -2140,7 +2140,7 @@ int databasevm_bind_null (dbvm_t *vm, int index) { pg_stmt_t *stmt = (pg_stmt_t*)vm; stmt->values[idx] = (Datum)0; - stmt->types[idx] = BYTEAOID; + stmt->types[idx] = TEXTOID; // TEXTOID has casts to most types stmt->nulls[idx] = 'n'; if (stmt->nparams < idx + 1) stmt->nparams = idx + 1; @@ -2185,7 +2185,8 @@ int databasevm_bind_value (dbvm_t *vm, int index, dbvalue_t *value) { pgvalue_t *v = (pgvalue_t *)value; if (!v || v->isnull) { stmt->values[idx] = (Datum)0; - stmt->types[idx] = TEXTOID; + // Use the actual column type if available, otherwise default to TEXTOID + stmt->types[idx] = (v && OidIsValid(v->typeid)) ? v->typeid : TEXTOID; stmt->nulls[idx] = 'n'; } else { int16 typlen; diff --git a/test/postgresql/01_unittest.sql b/test/postgresql/01_unittest.sql index faa7031..59ba93f 100644 --- a/test/postgresql/01_unittest.sql +++ b/test/postgresql/01_unittest.sql @@ -21,7 +21,7 @@ SELECT cloudsync_version() AS version \gset -- Test uuid generation SELECT cloudsync_uuid() AS uuid1 \gset -SELECT pg_sleep(0.1); +SELECT pg_sleep(0.1) \gset SELECT cloudsync_uuid() AS uuid2 \gset -- Test 1: Format check (UUID v7 has standard format: xxxxxxxx-xxxx-7xxx-xxxx-xxxxxxxxxxxx) diff --git a/test/postgresql/20_init_with_existing_data.sql b/test/postgresql/20_init_with_existing_data.sql new file mode 100644 index 0000000..de174ed --- /dev/null +++ b/test/postgresql/20_init_with_existing_data.sql @@ -0,0 +1,298 @@ +-- Init With Existing Data Test +-- Tests cloudsync_init on a table that already contains data. +-- This verifies that cloudsync_refill_metatable correctly creates +-- metadata entries for pre-existing rows. + +\set testid '20' +\ir helper_test_init.sql + +\connect postgres +\ir helper_psql_conn_setup.sql + +-- Cleanup and create test databases +DROP DATABASE IF EXISTS cloudsync_test_20a; +DROP DATABASE IF EXISTS cloudsync_test_20b; +CREATE DATABASE cloudsync_test_20a; +CREATE DATABASE cloudsync_test_20b; + +-- ============================================================================ +-- Setup Database A - INSERT DATA BEFORE cloudsync_init +-- ============================================================================ + +\connect cloudsync_test_20a +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +-- Create table with UUID primary key (required for CRDT replication) +CREATE TABLE items ( + id UUID PRIMARY KEY, + name TEXT NOT NULL DEFAULT '', + price DOUBLE PRECISION NOT NULL DEFAULT 0.0, + quantity INTEGER NOT NULL DEFAULT 0, + metadata JSONB +); + +-- ============================================================================ +-- INSERT DATA BEFORE CALLING cloudsync_init +-- This is the key difference from other tests - data exists before sync setup +-- ============================================================================ + +INSERT INTO items VALUES ('11111111-1111-1111-1111-111111111111', 'Pre-existing Item 1', 10.99, 100, '{"pre": true}'); +INSERT INTO items VALUES ('22222222-2222-2222-2222-222222222222', 'Pre-existing Item 2', 20.50, 200, '{"pre": true, "id": 2}'); +INSERT INTO items VALUES ('33333333-3333-3333-3333-333333333333', 'Pre-existing Item 3', 30.00, 300, NULL); +INSERT INTO items VALUES ('44444444-4444-4444-4444-444444444444', 'Pre-existing Item 4', 0.0, 0, '[]'); +INSERT INTO items VALUES ('55555555-5555-5555-5555-555555555555', 'Pre-existing Item 5', -5.50, -10, '{"nested": {"key": "value"}}'); + +-- Verify data exists before init +SELECT COUNT(*) AS pre_init_count FROM items \gset +\echo [INFO] (:testid) Rows before cloudsync_init: :pre_init_count + +-- ============================================================================ +-- NOW call cloudsync_init - this should trigger cloudsync_refill_metatable +-- ============================================================================ + +SELECT cloudsync_init('items', 'CLS', false) AS _init_a \gset + +-- ============================================================================ +-- Verify metadata was created for existing rows +-- ============================================================================ + +-- Check that metadata table exists and has entries +SELECT COUNT(*) AS metadata_count FROM items_cloudsync \gset + +SELECT (:metadata_count > 0) AS metadata_created \gset +\if :metadata_created +\echo [PASS] (:testid) Metadata table populated after init (:metadata_count entries) +\else +\echo [FAIL] (:testid) Metadata table empty after init - cloudsync_refill_metatable may have failed +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Compute hash of Database A data +-- ============================================================================ + +SELECT md5( + COALESCE( + string_agg( + id::text || ':' || + COALESCE(name, 'NULL') || ':' || + COALESCE(price::text, 'NULL') || ':' || + COALESCE(quantity::text, 'NULL') || ':' || + COALESCE(metadata::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_a FROM items \gset + +\echo [INFO] (:testid) Database A hash: :hash_a + +-- ============================================================================ +-- Encode payload from Database A +-- ============================================================================ + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_a_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +-- Verify payload was created +SELECT (length(:'payload_a_hex') > 0) AS payload_created \gset +\if :payload_created +\echo [PASS] (:testid) Payload encoded from Database A (pre-existing data) +\else +\echo [FAIL] (:testid) Payload encoded from Database A - Empty payload +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Setup Database B with same schema (empty) +-- ============================================================================ + +\connect cloudsync_test_20b +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +CREATE TABLE items ( + id UUID PRIMARY KEY, + name TEXT NOT NULL DEFAULT '', + price DOUBLE PRECISION NOT NULL DEFAULT 0.0, + quantity INTEGER NOT NULL DEFAULT 0, + metadata JSONB +); + +-- Initialize CloudSync on empty table +SELECT cloudsync_init('items', 'CLS', false) AS _init_b \gset + +-- ============================================================================ +-- Apply payload to Database B +-- ============================================================================ + +SELECT cloudsync_payload_apply(decode(:'payload_a_hex', 'hex')) AS apply_result \gset + +-- Verify application succeeded +SELECT (:apply_result >= 0) AS payload_applied \gset +\if :payload_applied +\echo [PASS] (:testid) Payload applied to Database B +\else +\echo [FAIL] (:testid) Payload applied to Database B - Apply returned :apply_result +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify data integrity after roundtrip +-- ============================================================================ + +SELECT md5( + COALESCE( + string_agg( + id::text || ':' || + COALESCE(name, 'NULL') || ':' || + COALESCE(price::text, 'NULL') || ':' || + COALESCE(quantity::text, 'NULL') || ':' || + COALESCE(metadata::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_b FROM items \gset + +\echo [INFO] (:testid) Database B hash: :hash_b + +SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset +\if :hashes_match +\echo [PASS] (:testid) Data integrity verified - hashes match +\else +\echo [FAIL] (:testid) Data integrity check failed - Database A hash: :hash_a, Database B hash: :hash_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify row count +-- ============================================================================ + +SELECT COUNT(*) AS count_b FROM items \gset +\connect cloudsync_test_20a +SELECT COUNT(*) AS count_a_orig FROM items \gset + +\connect cloudsync_test_20b +SELECT (:count_b = :count_a_orig) AS row_counts_match \gset +\if :row_counts_match +\echo [PASS] (:testid) Row counts match (:count_b rows) +\else +\echo [FAIL] (:testid) Row counts mismatch - Database A: :count_a_orig, Database B: :count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify specific pre-existing data was synced correctly +-- ============================================================================ + +SELECT COUNT(*) = 1 AS item1_ok +FROM items +WHERE id = '11111111-1111-1111-1111-111111111111' + AND name = 'Pre-existing Item 1' + AND price = 10.99 + AND quantity = 100 \gset +\if :item1_ok +\echo [PASS] (:testid) Pre-existing item 1 synced correctly +\else +\echo [FAIL] (:testid) Pre-existing item 1 not found or incorrect +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Verify JSONB data +SELECT COUNT(*) = 1 AS jsonb_ok +FROM items +WHERE id = '55555555-5555-5555-5555-555555555555' AND metadata = '{"nested": {"key": "value"}}'::jsonb \gset +\if :jsonb_ok +\echo [PASS] (:testid) JSONB data synced correctly +\else +\echo [FAIL] (:testid) JSONB data not synced correctly +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test: Add new data AFTER init, verify it also syncs +-- ============================================================================ + +\connect cloudsync_test_20a + +-- Add new row after init +INSERT INTO items VALUES ('66666666-6666-6666-6666-666666666666', 'Post-init Item', 66.66, 666, '{"post": true}'); + +-- Encode new changes +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_a2_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_20b +SELECT cloudsync_payload_apply(decode(:'payload_a2_hex', 'hex')) AS apply_result2 \gset + +SELECT COUNT(*) = 1 AS post_init_ok +FROM items +WHERE id = '66666666-6666-6666-6666-666666666666' AND name = 'Post-init Item' \gset +\if :post_init_ok +\echo [PASS] (:testid) Post-init data syncs correctly +\else +\echo [FAIL] (:testid) Post-init data failed to sync +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test bidirectional sync (B -> A) +-- ============================================================================ + +INSERT INTO items VALUES ('77777777-7777-7777-7777-777777777777', 'From B', 77.77, 777, '{"from": "B"}'); + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_b_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_20a +SELECT cloudsync_payload_apply(decode(:'payload_b_hex', 'hex')) AS apply_b_to_a \gset + +SELECT COUNT(*) = 1 AS bidirectional_ok +FROM items +WHERE id = '77777777-7777-7777-7777-777777777777' AND name = 'From B' \gset +\if :bidirectional_ok +\echo [PASS] (:testid) Bidirectional sync works (B to A) +\else +\echo [FAIL] (:testid) Bidirectional sync failed +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Final verification: total row count should be 7 in both databases +-- ============================================================================ + +SELECT COUNT(*) AS final_count_a FROM items \gset +\connect cloudsync_test_20b +SELECT COUNT(*) AS final_count_b FROM items \gset + +SELECT (:final_count_a = 7 AND :final_count_b = 7) AS final_counts_ok \gset +\if :final_counts_ok +\echo [PASS] (:testid) Final row counts correct (7 rows each) +\else +\echo [FAIL] (:testid) Final row counts incorrect - A: :final_count_a, B: :final_count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Cleanup: Drop test databases if not in DEBUG mode and no failures +-- ============================================================================ + +\ir helper_test_cleanup.sql +\if :should_cleanup +DROP DATABASE IF EXISTS cloudsync_test_20a; +DROP DATABASE IF EXISTS cloudsync_test_20b; +\endif diff --git a/test/postgresql/21_null_value_sync.sql b/test/postgresql/21_null_value_sync.sql new file mode 100644 index 0000000..d76066c --- /dev/null +++ b/test/postgresql/21_null_value_sync.sql @@ -0,0 +1,194 @@ +-- Test: NULL Value Sync Parameter Binding +-- This test verifies that syncing NULL values works correctly in all scenarios: +-- 1. Insert with NULL value first, then non-NULL +-- 2. Update existing row to NULL +-- +-- ISSUE: When a NULL value is synced first, PostgreSQL SPI prepares a statement with +-- only the PK parameters. Subsequent non-NULL syncs fail with "there is no parameter $3". +-- +-- The test uses payload_encode/payload_apply to simulate cross-database sync. + +\set testid '21' +\ir helper_test_init.sql + +\connect postgres +\ir helper_psql_conn_setup.sql + +-- Cleanup and create test databases +DROP DATABASE IF EXISTS cloudsync_test_21a; +DROP DATABASE IF EXISTS cloudsync_test_21b; +CREATE DATABASE cloudsync_test_21a; +CREATE DATABASE cloudsync_test_21b; + +-- ============================================================================ +-- Setup Database A - Source database +-- ============================================================================ + +\connect cloudsync_test_21a +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +-- Create a simple table with a nullable column +CREATE TABLE test_null_sync ( + id TEXT NOT NULL PRIMARY KEY, + value TEXT -- Nullable column +); + +-- Initialize CloudSync +SELECT cloudsync_init('test_null_sync', 'CLS', true) AS _init_a \gset + +-- ============================================================================ +-- Setup Database B - Target database (same schema) +-- ============================================================================ + +\connect cloudsync_test_21b +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +CREATE TABLE test_null_sync ( + id TEXT NOT NULL PRIMARY KEY, + value TEXT +); + +SELECT cloudsync_init('test_null_sync', 'CLS', true) AS _init_b \gset + +-- ============================================================================ +-- Test 1: Insert NULL value first, then sync to B +-- ============================================================================ + +\connect cloudsync_test_21a + +-- Insert row with NULL value +INSERT INTO test_null_sync (id, value) VALUES ('row1', NULL); + +-- Encode payload from Database A +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_null_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_21b + +-- Apply payload with NULL value +SELECT cloudsync_payload_apply(decode(:'payload_null_hex', 'hex')) AS apply_null_result \gset + +SELECT (:apply_null_result >= 0) AS null_applied \gset +\if :null_applied +\echo [PASS] (:testid) NULL value payload applied successfully +\else +\echo [FAIL] (:testid) NULL value payload failed to apply +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Verify the NULL value was synced +SELECT COUNT(*) = 1 AS null_row_exists FROM test_null_sync WHERE id = 'row1' AND value IS NULL \gset +\if :null_row_exists +\echo [PASS] (:testid) NULL value synced correctly +\else +\echo [FAIL] (:testid) NULL value not synced correctly +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test 2: Insert non-NULL value, then sync to B +-- ============================================================================ + +\connect cloudsync_test_21a + +-- Insert row with non-NULL value +INSERT INTO test_null_sync (id, value) VALUES ('row2', 'hello world'); + +-- Encode payload from Database A (includes new row) +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_nonnull_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_21b + +-- Apply payload with non-NULL value +SELECT cloudsync_payload_apply(decode(:'payload_nonnull_hex', 'hex')) AS apply_nonnull_result \gset + +SELECT (:apply_nonnull_result >= 0) AS nonnull_applied \gset +\if :nonnull_applied +\echo [PASS] (:testid) Non-NULL value payload applied successfully after NULL +\else +\echo [FAIL] (:testid) Non-NULL value payload failed to apply (parameter binding issue) +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Verify the non-NULL value was synced +SELECT COUNT(*) = 1 AS nonnull_row_exists FROM test_null_sync WHERE id = 'row2' AND value = 'hello world' \gset +\if :nonnull_row_exists +\echo [PASS] (:testid) Non-NULL value synced correctly +\else +\echo [FAIL] (:testid) Non-NULL value not synced correctly +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test 3: Verify both rows exist in Database B +-- ============================================================================ + +SELECT COUNT(*) AS total_rows FROM test_null_sync \gset +SELECT (:total_rows = 2) AS both_rows_exist \gset +\if :both_rows_exist +\echo [PASS] (:testid) Both rows synced successfully +\else +\echo [FAIL] (:testid) Expected 2 rows, found :total_rows +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test 4: Update existing row to NULL, then sync to B +-- This tests that updating a column from non-NULL to NULL works correctly. +-- ============================================================================ + +\connect cloudsync_test_21a + +-- Update row2 to set value to NULL +UPDATE test_null_sync SET value = NULL WHERE id = 'row2'; + +-- Encode payload from Database A +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_update_null_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_21b + +-- Apply payload with updated NULL value +SELECT cloudsync_payload_apply(decode(:'payload_update_null_hex', 'hex')) AS apply_update_null_result \gset + +SELECT (:apply_update_null_result >= 0) AS update_null_applied \gset +\if :update_null_applied +\echo [PASS] (:testid) Update to NULL payload applied successfully +\else +\echo [FAIL] (:testid) Update to NULL payload failed to apply +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Verify the update to NULL was synced +SELECT COUNT(*) = 1 AS update_null_synced FROM test_null_sync WHERE id = 'row2' AND value IS NULL \gset +\if :update_null_synced +\echo [PASS] (:testid) Update to NULL synced correctly +\else +\echo [FAIL] (:testid) Update to NULL not synced correctly +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Cleanup +-- ============================================================================ + +\ir helper_test_cleanup.sql +\if :should_cleanup +DROP DATABASE IF EXISTS cloudsync_test_21a; +DROP DATABASE IF EXISTS cloudsync_test_21b; +\endif diff --git a/test/postgresql/22_null_column_roundtrip.sql b/test/postgresql/22_null_column_roundtrip.sql new file mode 100644 index 0000000..9b2d271 --- /dev/null +++ b/test/postgresql/22_null_column_roundtrip.sql @@ -0,0 +1,347 @@ +-- Test: NULL Column Roundtrip +-- This test verifies that syncing rows with various NULL column combinations works correctly. +-- Tests all permutations: NULL in first column, second column, both, and neither. + +\set testid '22' +\ir helper_test_init.sql + +\connect postgres +\ir helper_psql_conn_setup.sql + +-- Cleanup and create test databases +DROP DATABASE IF EXISTS cloudsync_test_22a; +DROP DATABASE IF EXISTS cloudsync_test_22b; +CREATE DATABASE cloudsync_test_22a; +CREATE DATABASE cloudsync_test_22b; + +-- ============================================================================ +-- Setup Database A - Source database +-- ============================================================================ + +\connect cloudsync_test_22a +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +-- Create table with nullable columns (no DEFAULT values) +CREATE TABLE null_sync_test ( + id TEXT PRIMARY KEY NOT NULL, + name TEXT, + value INTEGER +); + +-- Initialize CloudSync +SELECT cloudsync_init('null_sync_test', 'CLS', true) AS _init_a \gset + +-- ============================================================================ +-- Insert test data with various NULL combinations +-- ============================================================================ + +-- Row 1: NULL in value column only +INSERT INTO null_sync_test (id, name, value) VALUES ('pg1', 'name1', NULL); + +-- Row 2: NULL in name column only +INSERT INTO null_sync_test (id, name, value) VALUES ('pg2', NULL, 42); + +-- Row 3: NULL in both columns +INSERT INTO null_sync_test (id, name, value) VALUES ('pg3', NULL, NULL); + +-- Row 4: No NULLs (both columns have values) +INSERT INTO null_sync_test (id, name, value) VALUES ('pg4', 'name4', 100); + +-- Row 5: Empty string (not NULL) and zero +INSERT INTO null_sync_test (id, name, value) VALUES ('pg5', '', 0); + +-- Row 6: Another NULL in value +INSERT INTO null_sync_test (id, name, value) VALUES ('pg6', 'name6', NULL); + +-- ============================================================================ +-- Verify source data +-- ============================================================================ + +SELECT COUNT(*) = 6 AS source_row_count_ok FROM null_sync_test \gset +\if :source_row_count_ok +\echo [PASS] (:testid) Source database has 6 rows +\else +\echo [FAIL] (:testid) Source database row count incorrect +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Compute hash of Database A data +-- ============================================================================ + +SELECT md5( + COALESCE( + string_agg( + id || ':' || + COALESCE(name, 'NULL') || ':' || + COALESCE(value::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_a FROM null_sync_test \gset + +\echo [INFO] (:testid) Database A hash: :hash_a + +-- ============================================================================ +-- Encode payload from Database A +-- ============================================================================ + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_a_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +-- Verify payload was created +SELECT (length(:'payload_a_hex') > 0) AS payload_created \gset +\if :payload_created +\echo [PASS] (:testid) Payload encoded from Database A +\else +\echo [FAIL] (:testid) Payload encoded from Database A - Empty payload +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Setup Database B with same schema +-- ============================================================================ + +\connect cloudsync_test_22b +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +-- Create identical table schema +CREATE TABLE null_sync_test ( + id TEXT PRIMARY KEY NOT NULL, + name TEXT, + value INTEGER +); + +-- Initialize CloudSync +SELECT cloudsync_init('null_sync_test', 'CLS', true) AS _init_b \gset + +-- ============================================================================ +-- Apply payload to Database B +-- ============================================================================ + +SELECT cloudsync_payload_apply(decode(:'payload_a_hex', 'hex')) AS apply_result \gset + +-- Verify application succeeded +SELECT (:apply_result >= 0) AS payload_applied \gset +\if :payload_applied +\echo [PASS] (:testid) Payload applied to Database B (result: :apply_result) +\else +\echo [FAIL] (:testid) Payload applied to Database B - Apply returned :apply_result +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify data integrity after roundtrip +-- ============================================================================ + +-- Compute hash of Database B data (should match Database A) +SELECT md5( + COALESCE( + string_agg( + id || ':' || + COALESCE(name, 'NULL') || ':' || + COALESCE(value::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_b FROM null_sync_test \gset + +\echo [INFO] (:testid) Database B hash: :hash_b + +-- Compare hashes +SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset +\if :hashes_match +\echo [PASS] (:testid) Data integrity verified - hashes match +\else +\echo [FAIL] (:testid) Data integrity check failed - Database A hash: :hash_a, Database B hash: :hash_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify row count +-- ============================================================================ + +SELECT COUNT(*) AS count_b FROM null_sync_test \gset +SELECT (:count_b = 6) AS row_counts_match \gset +\if :row_counts_match +\echo [PASS] (:testid) Row counts match (6 rows) +\else +\echo [FAIL] (:testid) Row counts mismatch - Expected 6, got :count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify specific NULL patterns +-- ============================================================================ + +-- pg1: name='name1', value=NULL +SELECT (SELECT name = 'name1' AND value IS NULL FROM null_sync_test WHERE id = 'pg1') AS pg1_ok \gset +\if :pg1_ok +\echo [PASS] (:testid) pg1: name='name1', value=NULL preserved +\else +\echo [FAIL] (:testid) pg1: NULL in value column not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg2: name=NULL, value=42 +SELECT (SELECT name IS NULL AND value = 42 FROM null_sync_test WHERE id = 'pg2') AS pg2_ok \gset +\if :pg2_ok +\echo [PASS] (:testid) pg2: name=NULL, value=42 preserved +\else +\echo [FAIL] (:testid) pg2: NULL in name column not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg3: name=NULL, value=NULL +SELECT (SELECT name IS NULL AND value IS NULL FROM null_sync_test WHERE id = 'pg3') AS pg3_ok \gset +\if :pg3_ok +\echo [PASS] (:testid) pg3: name=NULL, value=NULL preserved +\else +\echo [FAIL] (:testid) pg3: Both NULLs not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg4: name='name4', value=100 (no NULLs) +SELECT (SELECT name = 'name4' AND value = 100 FROM null_sync_test WHERE id = 'pg4') AS pg4_ok \gset +\if :pg4_ok +\echo [PASS] (:testid) pg4: name='name4', value=100 preserved +\else +\echo [FAIL] (:testid) pg4: Non-NULL values not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg5: name='', value=0 (empty string and zero, not NULL) +SELECT (SELECT name = '' AND value = 0 FROM null_sync_test WHERE id = 'pg5') AS pg5_ok \gset +\if :pg5_ok +\echo [PASS] (:testid) pg5: empty string and zero preserved (not NULL) +\else +\echo [FAIL] (:testid) pg5: Empty string or zero incorrectly converted +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg6: name='name6', value=NULL +SELECT (SELECT name = 'name6' AND value IS NULL FROM null_sync_test WHERE id = 'pg6') AS pg6_ok \gset +\if :pg6_ok +\echo [PASS] (:testid) pg6: name='name6', value=NULL preserved +\else +\echo [FAIL] (:testid) pg6: NULL in value column not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test bidirectional sync (B -> A) +-- ============================================================================ + +-- Add a new row in Database B with NULLs +INSERT INTO null_sync_test (id, name, value) VALUES ('pgB1', NULL, 999); + +-- Encode payload from Database B +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_b_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +-- Apply to Database A +\connect cloudsync_test_22a +SELECT cloudsync_payload_apply(decode(:'payload_b_hex', 'hex')) AS apply_b_to_a \gset + +-- Verify the new row exists in Database A with correct NULL +SELECT (SELECT name IS NULL AND value = 999 FROM null_sync_test WHERE id = 'pgB1') AS bidirectional_ok \gset +\if :bidirectional_ok +\echo [PASS] (:testid) Bidirectional sync works (B to A with NULL) +\else +\echo [FAIL] (:testid) Bidirectional sync failed +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test UPDATE to NULL +-- ============================================================================ + +-- Update pg4 to set name to NULL +UPDATE null_sync_test SET name = NULL WHERE id = 'pg4'; + +-- Encode and sync to B +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_update_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_22b +SELECT cloudsync_payload_apply(decode(:'payload_update_hex', 'hex')) AS apply_update \gset + +-- Verify pg4 now has NULL name +SELECT (SELECT name IS NULL AND value = 100 FROM null_sync_test WHERE id = 'pg4') AS update_to_null_ok \gset +\if :update_to_null_ok +\echo [PASS] (:testid) UPDATE to NULL synced correctly +\else +\echo [FAIL] (:testid) UPDATE to NULL failed +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Test UPDATE from NULL to value +-- ============================================================================ + +-- Update pg3 to set both columns to non-NULL values +\connect cloudsync_test_22a +UPDATE null_sync_test SET name = 'updated', value = 123 WHERE id = 'pg3'; + +-- Encode and sync to B +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_update2_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +\connect cloudsync_test_22b +SELECT cloudsync_payload_apply(decode(:'payload_update2_hex', 'hex')) AS apply_update2 \gset + +-- Verify pg3 now has non-NULL values +SELECT (SELECT name = 'updated' AND value = 123 FROM null_sync_test WHERE id = 'pg3') AS update_from_null_ok \gset +\if :update_from_null_ok +\echo [PASS] (:testid) UPDATE from NULL to value synced correctly +\else +\echo [FAIL] (:testid) UPDATE from NULL to value failed +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Final verification - both databases should have 7 rows with matching content +-- ============================================================================ + +SELECT COUNT(*) AS final_count_b FROM null_sync_test \gset +\connect cloudsync_test_22a +SELECT COUNT(*) AS final_count_a FROM null_sync_test \gset + +\connect cloudsync_test_22b +SELECT (:final_count_a = 7 AND :final_count_b = 7) AS final_counts_ok \gset +\if :final_counts_ok +\echo [PASS] (:testid) Final row counts correct (7 rows each) +\else +\echo [FAIL] (:testid) Final row counts incorrect - A: :final_count_a, B: :final_count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Cleanup +-- ============================================================================ + +\ir helper_test_cleanup.sql +\if :should_cleanup +DROP DATABASE IF EXISTS cloudsync_test_22a; +DROP DATABASE IF EXISTS cloudsync_test_22b; +\endif diff --git a/test/postgresql/23_uuid_column_roundtrip.sql b/test/postgresql/23_uuid_column_roundtrip.sql new file mode 100644 index 0000000..078bf68 --- /dev/null +++ b/test/postgresql/23_uuid_column_roundtrip.sql @@ -0,0 +1,359 @@ +-- Test: UUID Column Roundtrip +-- This test verifies that syncing rows with UUID columns (not as PK) works correctly. +-- Tests various combinations of NULL and non-NULL UUID values alongside other nullable columns. +-- +-- IMPORTANT: This test is structured to isolate whether NULL UUID values trigger encoding bugs: +-- Step 1: Sync a single row with non-NULL UUID only (baseline) +-- Step 2: Sync a row with NULL UUID, then a row with non-NULL UUID (test NULL trigger) +-- Step 3: Sync remaining rows with mixed NULL/non-NULL UUIDs + +\set testid '23' +\ir helper_test_init.sql + +\connect postgres +\ir helper_psql_conn_setup.sql + +-- Cleanup and create test databases +DROP DATABASE IF EXISTS cloudsync_test_23a; +DROP DATABASE IF EXISTS cloudsync_test_23b; +CREATE DATABASE cloudsync_test_23a; +CREATE DATABASE cloudsync_test_23b; + +-- ============================================================================ +-- Setup Database A - Source database +-- ============================================================================ + +\connect cloudsync_test_23a +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +-- Create table with UUID column and other nullable columns +CREATE TABLE uuid_sync_test ( + id TEXT PRIMARY KEY NOT NULL, + name TEXT, + value INTEGER, + id2 UUID +); + +-- Initialize CloudSync +SELECT cloudsync_init('uuid_sync_test', 'CLS', true) AS _init_a \gset + +-- ============================================================================ +-- Setup Database B with same schema (before any inserts) +-- ============================================================================ + +\connect cloudsync_test_23b +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +CREATE TABLE uuid_sync_test ( + id TEXT PRIMARY KEY NOT NULL, + name TEXT, + value INTEGER, + id2 UUID +); + +SELECT cloudsync_init('uuid_sync_test', 'CLS', true) AS _init_b \gset + +-- ============================================================================ +-- STEP 1: Sync a single row with non-NULL UUID only (baseline test) +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 1: Single row with non-NULL UUID === + +\connect cloudsync_test_23a + +-- Insert only one row with a non-NULL UUID +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('step1', 'baseline', 1, 'aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa'); + +-- Encode payload +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_step1_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +SELECT max(db_version) AS db_version FROM uuid_sync_test_cloudsync \gset + +-- Apply to Database B +\connect cloudsync_test_23b +SELECT cloudsync_payload_apply(decode(:'payload_step1_hex', 'hex')) AS apply_step1 \gset + +-- Verify step 1 +SELECT (SELECT id2 = 'aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa' FROM uuid_sync_test WHERE id = 'step1') AS step1_ok \gset +\if :step1_ok +\echo [PASS] (:testid) Step 1: Single non-NULL UUID preserved correctly +\else +\echo [FAIL] (:testid) Step 1: Single non-NULL UUID NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT id, name, value, id2::text FROM uuid_sync_test WHERE id = 'step1'; +\endif + +-- ============================================================================ +-- STEP 2: Sync NULL UUID row, then non-NULL UUID row (test NULL trigger) +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 2: NULL UUID followed by non-NULL UUID === + +\connect cloudsync_test_23a + +-- Insert a row with NULL UUID first +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('step2a', 'null_uuid', 2, NULL); + +-- Then insert a row with non-NULL UUID +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('step2b', 'after_null', 3, 'bbbbbbbb-bbbb-bbbb-bbbb-bbbbbbbbbbbb'); + +-- Encode payload (should contain both rows) +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_step2_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM uuid_sync_test_cloudsync \gset + +-- Apply to Database B +\connect cloudsync_test_23b +SELECT cloudsync_payload_apply(decode(:'payload_step2_hex', 'hex')) AS apply_step2 \gset + +-- Verify step 2a (NULL UUID) +SELECT (SELECT id2 IS NULL FROM uuid_sync_test WHERE id = 'step2a') AS step2a_ok \gset +\if :step2a_ok +\echo [PASS] (:testid) Step 2a: NULL UUID preserved correctly +\else +\echo [FAIL] (:testid) Step 2a: NULL UUID NOT preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Verify step 2b (non-NULL UUID after NULL) +SELECT (SELECT id2 = 'bbbbbbbb-bbbb-bbbb-bbbb-bbbbbbbbbbbb' FROM uuid_sync_test WHERE id = 'step2b') AS step2b_ok \gset +\if :step2b_ok +\echo [PASS] (:testid) Step 2b: Non-NULL UUID after NULL preserved correctly +\else +\echo [FAIL] (:testid) Step 2b: Non-NULL UUID after NULL NOT preserved (NULL may have triggered bug) +SELECT (:fail::int + 1) AS fail \gset +SELECT id, name, value, id2::text FROM uuid_sync_test WHERE id = 'step2b'; +\endif + +-- ============================================================================ +-- STEP 3: Sync remaining rows with mixed NULL/non-NULL UUIDs +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 3: Mixed NULL/non-NULL UUIDs === + +\connect cloudsync_test_23a + +-- Row with NULL in value and id2 +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('pg1', 'name1', NULL, NULL); + +-- Row with NULL in name, has UUID +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('pg2', NULL, 42, 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11'); + +-- Row with all nullable columns NULL +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('pg3', NULL, NULL, NULL); + +-- Row with no NULLs - all columns have values +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('pg4', 'name4', 100, 'b0eebc99-9c0b-4ef8-bb6d-6bb9bd380a22'); + +-- Row with only id2 NULL +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('pg5', 'name5', 55, NULL); + +-- Row with only name NULL, has different UUID +INSERT INTO uuid_sync_test (id, name, value, id2) VALUES ('pg6', NULL, 66, 'c0eebc99-9c0b-4ef8-bb6d-6bb9bd380a33'); + +-- ============================================================================ +-- Verify source data +-- ============================================================================ + +SELECT COUNT(*) = 9 AS source_row_count_ok FROM uuid_sync_test \gset +\if :source_row_count_ok +\echo [PASS] (:testid) Source database has 9 rows +\else +\echo [FAIL] (:testid) Source database row count incorrect +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Compute hash of Database A data +-- ============================================================================ + +SELECT md5( + COALESCE( + string_agg( + id || ':' || + COALESCE(name, 'NULL') || ':' || + COALESCE(value::text, 'NULL') || ':' || + COALESCE(id2::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_a FROM uuid_sync_test \gset + +\echo [INFO] (:testid) Database A hash: :hash_a + +-- ============================================================================ +-- Encode payload from Database A (step 3 rows only) +-- ============================================================================ + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_step3_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM uuid_sync_test_cloudsync \gset + +-- Verify payload was created +SELECT (length(:'payload_step3_hex') > 0) AS payload_created \gset +\if :payload_created +\echo [PASS] (:testid) Payload encoded from Database A +\else +\echo [FAIL] (:testid) Payload encoded from Database A - Empty payload +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Apply payload to Database B +-- ============================================================================ + +\connect cloudsync_test_23b + +SELECT cloudsync_payload_apply(decode(:'payload_step3_hex', 'hex')) AS apply_result \gset + +-- Verify application succeeded +SELECT (:apply_result >= 0) AS payload_applied \gset +\if :payload_applied +\echo [PASS] (:testid) Payload applied to Database B (result: :apply_result) +\else +\echo [FAIL] (:testid) Payload applied to Database B - Apply returned :apply_result +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify data integrity after roundtrip +-- ============================================================================ + +-- Compute hash of Database B data (should match Database A) +SELECT md5( + COALESCE( + string_agg( + id || ':' || + COALESCE(name, 'NULL') || ':' || + COALESCE(value::text, 'NULL') || ':' || + COALESCE(id2::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_b FROM uuid_sync_test \gset + +\echo [INFO] (:testid) Database B hash: :hash_b + +-- Compare hashes +SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset +\if :hashes_match +\echo [PASS] (:testid) Data integrity verified - hashes match +\else +\echo [FAIL] (:testid) Data integrity check failed - Database A hash: :hash_a, Database B hash: :hash_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify row count +-- ============================================================================ + +SELECT COUNT(*) AS count_b FROM uuid_sync_test \gset +SELECT (:count_b = 9) AS row_counts_match \gset +\if :row_counts_match +\echo [PASS] (:testid) Row counts match (9 rows) +\else +\echo [FAIL] (:testid) Row counts mismatch - Expected 9, got :count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Verify specific UUID and NULL patterns +-- ============================================================================ + +-- pg1: name='name1', value=NULL, id2=NULL +SELECT (SELECT name = 'name1' AND value IS NULL AND id2 IS NULL FROM uuid_sync_test WHERE id = 'pg1') AS pg1_ok \gset +\if :pg1_ok +\echo [PASS] (:testid) pg1: name='name1', value=NULL, id2=NULL preserved +\else +\echo [FAIL] (:testid) pg1: NULL values not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg2: name=NULL, value=42, id2='a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11' +SELECT (SELECT name IS NULL AND value = 42 AND id2 = 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11' FROM uuid_sync_test WHERE id = 'pg2') AS pg2_ok \gset +\if :pg2_ok +\echo [PASS] (:testid) pg2: name=NULL, value=42, UUID preserved +\else +\echo [FAIL] (:testid) pg2: UUID or NULL not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg3: all nullable columns NULL +SELECT (SELECT name IS NULL AND value IS NULL AND id2 IS NULL FROM uuid_sync_test WHERE id = 'pg3') AS pg3_ok \gset +\if :pg3_ok +\echo [PASS] (:testid) pg3: all NULLs preserved +\else +\echo [FAIL] (:testid) pg3: all NULLs not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg4: no NULLs, id2='b0eebc99-9c0b-4ef8-bb6d-6bb9bd380a22' +SELECT (SELECT name = 'name4' AND value = 100 AND id2 = 'b0eebc99-9c0b-4ef8-bb6d-6bb9bd380a22' FROM uuid_sync_test WHERE id = 'pg4') AS pg4_ok \gset +\if :pg4_ok +\echo [PASS] (:testid) pg4: all values including UUID preserved +\else +\echo [FAIL] (:testid) pg4: values not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg5: name='name5', value=55, id2=NULL +SELECT (SELECT name = 'name5' AND value = 55 AND id2 IS NULL FROM uuid_sync_test WHERE id = 'pg5') AS pg5_ok \gset +\if :pg5_ok +\echo [PASS] (:testid) pg5: values with NULL UUID preserved +\else +\echo [FAIL] (:testid) pg5: NULL UUID not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- pg6: name=NULL, value=66, id2='c0eebc99-9c0b-4ef8-bb6d-6bb9bd380a33' +SELECT (SELECT name IS NULL AND value = 66 AND id2 = 'c0eebc99-9c0b-4ef8-bb6d-6bb9bd380a33' FROM uuid_sync_test WHERE id = 'pg6') AS pg6_ok \gset +\if :pg6_ok +\echo [PASS] (:testid) pg6: NULL name with UUID preserved +\else +\echo [FAIL] (:testid) pg6: UUID c0eebc99-9c0b-4ef8-bb6d-6bb9bd380a33 not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Show actual data for debugging if there are failures +-- ============================================================================ + +\if :{?DEBUG} +\echo [INFO] (:testid) Database A data: +\connect cloudsync_test_23a +SELECT id, name, value, id2::text FROM uuid_sync_test ORDER BY id; + +\echo [INFO] (:testid) Database B data: +\connect cloudsync_test_23b +SELECT id, name, value, id2::text FROM uuid_sync_test ORDER BY id; +\endif + +-- ============================================================================ +-- Cleanup +-- ============================================================================ + +\ir helper_test_cleanup.sql +\if :should_cleanup +\connect postgres +DROP DATABASE IF EXISTS cloudsync_test_23a; +DROP DATABASE IF EXISTS cloudsync_test_23b; +\endif diff --git a/test/postgresql/24_nullable_types_roundtrip.sql b/test/postgresql/24_nullable_types_roundtrip.sql new file mode 100644 index 0000000..f82a64a --- /dev/null +++ b/test/postgresql/24_nullable_types_roundtrip.sql @@ -0,0 +1,495 @@ +-- Test: Nullable Types Roundtrip +-- This test verifies that syncing rows with various nullable column types works correctly. +-- Tests the type mapping for NULL values: INT2/4/8 → INT8, FLOAT4/8/NUMERIC → FLOAT8, BYTEA → BYTEA, others → TEXT +-- +-- IMPORTANT: This test inserts NULL values FIRST to trigger SPI plan caching with decoded types, +-- then inserts non-NULL values to verify the type mapping is consistent. + +\set testid '24' +\ir helper_test_init.sql + +\connect postgres +\ir helper_psql_conn_setup.sql + +-- Cleanup and create test databases +DROP DATABASE IF EXISTS cloudsync_test_24a; +DROP DATABASE IF EXISTS cloudsync_test_24b; +CREATE DATABASE cloudsync_test_24a; +CREATE DATABASE cloudsync_test_24b; + +-- ============================================================================ +-- Setup Database A - Source database +-- ============================================================================ + +\connect cloudsync_test_24a +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +-- Create table with various nullable column types +-- NOTE: BOOLEAN is excluded because it encodes as INTEGER but PostgreSQL can't cast INT8 to BOOLEAN. +-- This is a known limitation that requires changes to the encoding layer. +CREATE TABLE types_sync_test ( + id TEXT PRIMARY KEY NOT NULL, + -- Integer types (all map to INT8OID in decoding) + col_int2 SMALLINT, + col_int4 INTEGER, + col_int8 BIGINT, + -- Float types (all map to FLOAT8OID in decoding) + col_float4 REAL, + col_float8 DOUBLE PRECISION, + col_numeric NUMERIC(10,2), + -- Binary type (maps to BYTEAOID in decoding) + col_bytea BYTEA, + -- Text types (all map to TEXTOID in decoding) + col_text TEXT, + col_varchar VARCHAR(100), + col_char CHAR(10), + -- Other types that map to TEXTOID + col_uuid UUID, + col_json JSON, + col_jsonb JSONB, + col_date DATE, + col_timestamp TIMESTAMP +); + +-- Initialize CloudSync +SELECT cloudsync_init('types_sync_test', 'CLS', true) AS _init_a \gset + +-- ============================================================================ +-- Setup Database B with same schema (before any inserts) +-- ============================================================================ + +\connect cloudsync_test_24b +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +CREATE TABLE types_sync_test ( + id TEXT PRIMARY KEY NOT NULL, + col_int2 SMALLINT, + col_int4 INTEGER, + col_int8 BIGINT, + col_float4 REAL, + col_float8 DOUBLE PRECISION, + col_numeric NUMERIC(10,2), + col_bytea BYTEA, + col_text TEXT, + col_varchar VARCHAR(100), + col_char CHAR(10), + col_uuid UUID, + col_json JSON, + col_jsonb JSONB, + col_date DATE, + col_timestamp TIMESTAMP +); + +SELECT cloudsync_init('types_sync_test', 'CLS', true) AS _init_b \gset + +-- ============================================================================ +-- STEP 1: Insert row with ALL NULL values first (triggers SPI plan caching) +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 1: Insert row with ALL NULL values === + +\connect cloudsync_test_24a + +INSERT INTO types_sync_test ( + id, col_int2, col_int4, col_int8, col_float4, col_float8, col_numeric, + col_bytea, col_text, col_varchar, col_char, col_uuid, col_json, col_jsonb, + col_date, col_timestamp +) VALUES ( + 'null_row', NULL, NULL, NULL, NULL, NULL, NULL, + NULL, NULL, NULL, NULL, NULL, NULL, NULL, + NULL, NULL +); + +-- Encode payload +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_step1_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +SELECT max(db_version) AS db_version FROM types_sync_test_cloudsync \gset + +-- Apply to Database B +\connect cloudsync_test_24b +SELECT cloudsync_payload_apply(decode(:'payload_step1_hex', 'hex')) AS apply_step1 \gset + +-- Verify step 1: all values should be NULL +SELECT (SELECT + col_int2 IS NULL AND col_int4 IS NULL AND col_int8 IS NULL AND + col_float4 IS NULL AND col_float8 IS NULL AND col_numeric IS NULL AND + col_bytea IS NULL AND col_text IS NULL AND col_varchar IS NULL AND + col_char IS NULL AND col_uuid IS NULL AND col_json IS NULL AND + col_jsonb IS NULL AND col_date IS NULL AND col_timestamp IS NULL +FROM types_sync_test WHERE id = 'null_row') AS step1_ok \gset + +\if :step1_ok +\echo [PASS] (:testid) Step 1: All NULL values preserved correctly +\else +\echo [FAIL] (:testid) Step 1: NULL values NOT preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- STEP 2: Insert row with ALL non-NULL values (tests type consistency) +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 2: Insert row with ALL non-NULL values === + +\connect cloudsync_test_24a + +INSERT INTO types_sync_test ( + id, col_int2, col_int4, col_int8, col_float4, col_float8, col_numeric, + col_bytea, col_text, col_varchar, col_char, col_uuid, col_json, col_jsonb, + col_date, col_timestamp +) VALUES ( + 'full_row', + 32767, -- INT2 max + 2147483647, -- INT4 max + 9223372036854775807, -- INT8 max + 3.14159, -- FLOAT4 + 3.141592653589793, -- FLOAT8 + 12345.67, -- NUMERIC + '\xDEADBEEF', -- BYTEA + 'Hello, World!', -- TEXT + 'varchar_val', -- VARCHAR + 'char_val', -- CHAR (will be padded) + 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11', -- UUID + '{"key": "value"}', -- JSON + '{"nested": {"array": [1, 2, 3]}}', -- JSONB + '2024-01-15', -- DATE + '2024-01-15 10:30:00' -- TIMESTAMP +); + +-- Encode payload (only new rows) +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_step2_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM types_sync_test_cloudsync \gset + +-- Apply to Database B +\connect cloudsync_test_24b +SELECT cloudsync_payload_apply(decode(:'payload_step2_hex', 'hex')) AS apply_step2 \gset + +-- Verify step 2: Integer types +SELECT (SELECT col_int2 = 32767 FROM types_sync_test WHERE id = 'full_row') AS int2_ok \gset +\if :int2_ok +\echo [PASS] (:testid) INT2 (SMALLINT) value preserved: 32767 +\else +\echo [FAIL] (:testid) INT2 (SMALLINT) value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_int2 FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_int4 = 2147483647 FROM types_sync_test WHERE id = 'full_row') AS int4_ok \gset +\if :int4_ok +\echo [PASS] (:testid) INT4 (INTEGER) value preserved: 2147483647 +\else +\echo [FAIL] (:testid) INT4 (INTEGER) value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_int4 FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_int8 = 9223372036854775807 FROM types_sync_test WHERE id = 'full_row') AS int8_ok \gset +\if :int8_ok +\echo [PASS] (:testid) INT8 (BIGINT) value preserved: 9223372036854775807 +\else +\echo [FAIL] (:testid) INT8 (BIGINT) value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_int8 FROM types_sync_test WHERE id = 'full_row'; +\endif + +-- Verify step 2: Float types (use approximate comparison for floats) +SELECT (SELECT abs(col_float4 - 3.14159) < 0.0001 FROM types_sync_test WHERE id = 'full_row') AS float4_ok \gset +\if :float4_ok +\echo [PASS] (:testid) FLOAT4 (REAL) value preserved: ~3.14159 +\else +\echo [FAIL] (:testid) FLOAT4 (REAL) value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_float4 FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT abs(col_float8 - 3.141592653589793) < 0.000000000001 FROM types_sync_test WHERE id = 'full_row') AS float8_ok \gset +\if :float8_ok +\echo [PASS] (:testid) FLOAT8 (DOUBLE PRECISION) value preserved: ~3.141592653589793 +\else +\echo [FAIL] (:testid) FLOAT8 (DOUBLE PRECISION) value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_float8 FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_numeric = 12345.67 FROM types_sync_test WHERE id = 'full_row') AS numeric_ok \gset +\if :numeric_ok +\echo [PASS] (:testid) NUMERIC value preserved: 12345.67 +\else +\echo [FAIL] (:testid) NUMERIC value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_numeric FROM types_sync_test WHERE id = 'full_row'; +\endif + +-- Verify step 2: BYTEA type +SELECT (SELECT col_bytea = '\xDEADBEEF' FROM types_sync_test WHERE id = 'full_row') AS bytea_ok \gset +\if :bytea_ok +\echo [PASS] (:testid) BYTEA value preserved: DEADBEEF +\else +\echo [FAIL] (:testid) BYTEA value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT encode(col_bytea, 'hex') FROM types_sync_test WHERE id = 'full_row'; +\endif + +-- Verify step 2: Text types +SELECT (SELECT col_text = 'Hello, World!' FROM types_sync_test WHERE id = 'full_row') AS text_ok \gset +\if :text_ok +\echo [PASS] (:testid) TEXT value preserved: Hello, World! +\else +\echo [FAIL] (:testid) TEXT value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_text FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_varchar = 'varchar_val' FROM types_sync_test WHERE id = 'full_row') AS varchar_ok \gset +\if :varchar_ok +\echo [PASS] (:testid) VARCHAR value preserved: varchar_val +\else +\echo [FAIL] (:testid) VARCHAR value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_varchar FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT trim(col_char) = 'char_val' FROM types_sync_test WHERE id = 'full_row') AS char_ok \gset +\if :char_ok +\echo [PASS] (:testid) CHAR value preserved: char_val +\else +\echo [FAIL] (:testid) CHAR value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_char FROM types_sync_test WHERE id = 'full_row'; +\endif + +-- Verify step 2: Other types mapped to TEXT +SELECT (SELECT col_uuid = 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11' FROM types_sync_test WHERE id = 'full_row') AS uuid_ok \gset +\if :uuid_ok +\echo [PASS] (:testid) UUID value preserved: a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11 +\else +\echo [FAIL] (:testid) UUID value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_uuid FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_json::text = '{"key": "value"}' FROM types_sync_test WHERE id = 'full_row') AS json_ok \gset +\if :json_ok +\echo [PASS] (:testid) JSON value preserved: {"key": "value"} +\else +\echo [FAIL] (:testid) JSON value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_json FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_jsonb @> '{"nested": {"array": [1, 2, 3]}}' FROM types_sync_test WHERE id = 'full_row') AS jsonb_ok \gset +\if :jsonb_ok +\echo [PASS] (:testid) JSONB value preserved: {"nested": {"array": [1, 2, 3]}} +\else +\echo [FAIL] (:testid) JSONB value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_jsonb FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_date = '2024-01-15' FROM types_sync_test WHERE id = 'full_row') AS date_ok \gset +\if :date_ok +\echo [PASS] (:testid) DATE value preserved: 2024-01-15 +\else +\echo [FAIL] (:testid) DATE value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_date FROM types_sync_test WHERE id = 'full_row'; +\endif + +SELECT (SELECT col_timestamp = '2024-01-15 10:30:00' FROM types_sync_test WHERE id = 'full_row') AS timestamp_ok \gset +\if :timestamp_ok +\echo [PASS] (:testid) TIMESTAMP value preserved: 2024-01-15 10:30:00 +\else +\echo [FAIL] (:testid) TIMESTAMP value NOT preserved +SELECT (:fail::int + 1) AS fail \gset +SELECT col_timestamp FROM types_sync_test WHERE id = 'full_row'; +\endif + +-- ============================================================================ +-- STEP 3: Insert row with mixed NULL/non-NULL values +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 3: Insert row with mixed NULL/non-NULL values === + +\connect cloudsync_test_24a + +INSERT INTO types_sync_test ( + id, col_int2, col_int4, col_int8, col_float4, col_float8, col_numeric, + col_bytea, col_text, col_varchar, col_char, col_uuid, col_json, col_jsonb, + col_date, col_timestamp +) VALUES ( + 'mixed_row', + NULL, -- INT2 NULL + 42, -- INT4 non-NULL + NULL, -- INT8 NULL + NULL, -- FLOAT4 NULL + 2.718281828, -- FLOAT8 non-NULL (e) + NULL, -- NUMERIC NULL + '\xCAFEBABE', -- BYTEA non-NULL + NULL, -- TEXT NULL + 'mixed', -- VARCHAR non-NULL + NULL, -- CHAR NULL + 'b0eebc99-9c0b-4ef8-bb6d-6bb9bd380a22', -- UUID non-NULL + NULL, -- JSON NULL + '{"mixed": true}', -- JSONB non-NULL + NULL, -- DATE NULL + '2024-06-15 14:00:00' -- TIMESTAMP non-NULL +); + +-- Encode payload (only new rows) +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload_step3_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM types_sync_test_cloudsync \gset + +-- Apply to Database B +\connect cloudsync_test_24b +SELECT cloudsync_payload_apply(decode(:'payload_step3_hex', 'hex')) AS apply_step3 \gset + +-- Verify mixed row +SELECT (SELECT + col_int2 IS NULL AND + col_int4 = 42 AND + col_int8 IS NULL AND + col_float4 IS NULL AND + abs(col_float8 - 2.718281828) < 0.000001 AND + col_numeric IS NULL AND + col_bytea = '\xCAFEBABE' AND + col_text IS NULL AND + col_varchar = 'mixed' AND + col_char IS NULL AND + col_uuid = 'b0eebc99-9c0b-4ef8-bb6d-6bb9bd380a22' AND + col_json IS NULL AND + col_jsonb @> '{"mixed": true}' AND + col_date IS NULL AND + col_timestamp = '2024-06-15 14:00:00' +FROM types_sync_test WHERE id = 'mixed_row') AS mixed_ok \gset + +\if :mixed_ok +\echo [PASS] (:testid) Mixed NULL/non-NULL row preserved correctly +\else +\echo [FAIL] (:testid) Mixed NULL/non-NULL row NOT preserved correctly +SELECT (:fail::int + 1) AS fail \gset +SELECT * FROM types_sync_test WHERE id = 'mixed_row'; +\endif + +-- ============================================================================ +-- STEP 4: Verify data integrity with hash comparison +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 4: Verify data integrity === + +\connect cloudsync_test_24a + +SELECT md5( + COALESCE( + string_agg( + id || ':' || + COALESCE(col_int2::text, 'NULL') || ':' || + COALESCE(col_int4::text, 'NULL') || ':' || + COALESCE(col_int8::text, 'NULL') || ':' || + COALESCE(col_float8::text, 'NULL') || ':' || + COALESCE(col_numeric::text, 'NULL') || ':' || + COALESCE(encode(col_bytea, 'hex'), 'NULL') || ':' || + COALESCE(col_text, 'NULL') || ':' || + COALESCE(col_varchar, 'NULL') || ':' || + COALESCE(col_uuid::text, 'NULL') || ':' || + COALESCE(col_jsonb::text, 'NULL') || ':' || + COALESCE(col_date::text, 'NULL') || ':' || + COALESCE(col_timestamp::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_a FROM types_sync_test \gset + +\echo [INFO] (:testid) Database A hash: :hash_a + +\connect cloudsync_test_24b + +SELECT md5( + COALESCE( + string_agg( + id || ':' || + COALESCE(col_int2::text, 'NULL') || ':' || + COALESCE(col_int4::text, 'NULL') || ':' || + COALESCE(col_int8::text, 'NULL') || ':' || + COALESCE(col_float8::text, 'NULL') || ':' || + COALESCE(col_numeric::text, 'NULL') || ':' || + COALESCE(encode(col_bytea, 'hex'), 'NULL') || ':' || + COALESCE(col_text, 'NULL') || ':' || + COALESCE(col_varchar, 'NULL') || ':' || + COALESCE(col_uuid::text, 'NULL') || ':' || + COALESCE(col_jsonb::text, 'NULL') || ':' || + COALESCE(col_date::text, 'NULL') || ':' || + COALESCE(col_timestamp::text, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_b FROM types_sync_test \gset + +\echo [INFO] (:testid) Database B hash: :hash_b + +SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset +\if :hashes_match +\echo [PASS] (:testid) Data integrity verified - hashes match +\else +\echo [FAIL] (:testid) Data integrity check failed - hashes do not match +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Verify row count +SELECT COUNT(*) AS count_b FROM types_sync_test \gset +SELECT (:count_b = 3) AS row_counts_match \gset +\if :row_counts_match +\echo [PASS] (:testid) Row counts match (3 rows) +\else +\echo [FAIL] (:testid) Row counts mismatch - Expected 3, got :count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- Show actual data for debugging if there are failures +-- ============================================================================ + +\if :{?DEBUG} +\echo [INFO] (:testid) Database A data: +\connect cloudsync_test_24a +SELECT id, col_int2, col_int4, col_int8, col_float4, col_float8, col_numeric FROM types_sync_test ORDER BY id; +SELECT id, encode(col_bytea, 'hex') as col_bytea, col_text, col_varchar, trim(col_char) as col_char FROM types_sync_test ORDER BY id; +SELECT id, col_uuid, col_json, col_jsonb, col_date, col_timestamp FROM types_sync_test ORDER BY id; + +\echo [INFO] (:testid) Database B data: +\connect cloudsync_test_24b +SELECT id, col_int2, col_int4, col_int8, col_float4, col_float8, col_numeric FROM types_sync_test ORDER BY id; +SELECT id, encode(col_bytea, 'hex') as col_bytea, col_text, col_varchar, trim(col_char) as col_char FROM types_sync_test ORDER BY id; +SELECT id, col_uuid, col_json, col_jsonb, col_date, col_timestamp FROM types_sync_test ORDER BY id; +\endif + +-- ============================================================================ +-- Cleanup +-- ============================================================================ + +\ir helper_test_cleanup.sql +\if :should_cleanup +\connect postgres +DROP DATABASE IF EXISTS cloudsync_test_24a; +DROP DATABASE IF EXISTS cloudsync_test_24b; +\endif diff --git a/test/postgresql/25_boolean_type_issue.sql b/test/postgresql/25_boolean_type_issue.sql new file mode 100644 index 0000000..845643e --- /dev/null +++ b/test/postgresql/25_boolean_type_issue.sql @@ -0,0 +1,241 @@ +-- Test: BOOLEAN Type Roundtrip +-- This test verifies that BOOLEAN columns sync correctly. +-- BOOLEAN values are encoded as INT8 in sync payloads. The cloudsync extension +-- provides a custom cast (bigint AS boolean) to enable this. +-- +-- See plans/ANALYSIS_BOOLEAN_TYPE_CONVERSION.md for details. + +\set testid '25' +\ir helper_test_init.sql + +\connect postgres +\ir helper_psql_conn_setup.sql + +DROP DATABASE IF EXISTS cloudsync_test_25a; +DROP DATABASE IF EXISTS cloudsync_test_25b; +CREATE DATABASE cloudsync_test_25a; +CREATE DATABASE cloudsync_test_25b; + +-- Setup Database A +\connect cloudsync_test_25a +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +CREATE TABLE bool_test ( + id TEXT PRIMARY KEY NOT NULL, + flag BOOLEAN, + name TEXT +); + +SELECT cloudsync_init('bool_test', 'CLS', true) AS _init_a \gset + +-- Setup Database B +\connect cloudsync_test_25b +\ir helper_psql_conn_setup.sql +CREATE EXTENSION IF NOT EXISTS cloudsync; + +CREATE TABLE bool_test ( + id TEXT PRIMARY KEY NOT NULL, + flag BOOLEAN, + name TEXT +); + +SELECT cloudsync_init('bool_test', 'CLS', true) AS _init_b \gset + +-- ============================================================================ +-- STEP 1: Insert NULL BOOLEAN first (triggers SPI plan caching) +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 1: NULL BOOLEAN === + +\connect cloudsync_test_25a +INSERT INTO bool_test (id, flag, name) VALUES ('row1', NULL, 'null_flag'); + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload1_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() \gset + +SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset + +\connect cloudsync_test_25b +SELECT cloudsync_payload_apply(decode(:'payload1_hex', 'hex')) AS apply1 \gset + +SELECT (SELECT flag IS NULL AND name = 'null_flag' FROM bool_test WHERE id = 'row1') AS step1_ok \gset +\if :step1_ok +\echo [PASS] (:testid) Step 1: NULL BOOLEAN preserved +\else +\echo [FAIL] (:testid) Step 1: NULL BOOLEAN not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- STEP 2: Insert TRUE BOOLEAN (tests INT8 -> BOOLEAN cast after NULL) +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 2: TRUE BOOLEAN after NULL === + +\connect cloudsync_test_25a +INSERT INTO bool_test (id, flag, name) VALUES ('row2', true, 'true_flag'); + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload2_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset + +\connect cloudsync_test_25b +SELECT cloudsync_payload_apply(decode(:'payload2_hex', 'hex')) AS apply2 \gset + +SELECT (SELECT flag = true AND name = 'true_flag' FROM bool_test WHERE id = 'row2') AS step2_ok \gset +\if :step2_ok +\echo [PASS] (:testid) Step 2: TRUE BOOLEAN preserved after NULL +\else +\echo [FAIL] (:testid) Step 2: TRUE BOOLEAN not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- STEP 3: Insert FALSE BOOLEAN +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 3: FALSE BOOLEAN === + +\connect cloudsync_test_25a +INSERT INTO bool_test (id, flag, name) VALUES ('row3', false, 'false_flag'); + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload3_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset + +\connect cloudsync_test_25b +SELECT cloudsync_payload_apply(decode(:'payload3_hex', 'hex')) AS apply3 \gset + +SELECT (SELECT flag = false AND name = 'false_flag' FROM bool_test WHERE id = 'row3') AS step3_ok \gset +\if :step3_ok +\echo [PASS] (:testid) Step 3: FALSE BOOLEAN preserved +\else +\echo [FAIL] (:testid) Step 3: FALSE BOOLEAN not preserved +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- STEP 4: Update TRUE to FALSE +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 4: Update TRUE to FALSE === + +\connect cloudsync_test_25a +UPDATE bool_test SET flag = false WHERE id = 'row2'; + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload4_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset + +\connect cloudsync_test_25b +SELECT cloudsync_payload_apply(decode(:'payload4_hex', 'hex')) AS apply4 \gset + +SELECT (SELECT flag = false FROM bool_test WHERE id = 'row2') AS step4_ok \gset +\if :step4_ok +\echo [PASS] (:testid) Step 4: Update TRUE to FALSE synced +\else +\echo [FAIL] (:testid) Step 4: Update TRUE to FALSE not synced +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- STEP 5: Update NULL to TRUE +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 5: Update NULL to TRUE === + +\connect cloudsync_test_25a +UPDATE bool_test SET flag = true WHERE id = 'row1'; + +SELECT encode( + cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq), + 'hex' +) AS payload5_hex +FROM cloudsync_changes +WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset + +SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset + +\connect cloudsync_test_25b +SELECT cloudsync_payload_apply(decode(:'payload5_hex', 'hex')) AS apply5 \gset + +SELECT (SELECT flag = true FROM bool_test WHERE id = 'row1') AS step5_ok \gset +\if :step5_ok +\echo [PASS] (:testid) Step 5: Update NULL to TRUE synced +\else +\echo [FAIL] (:testid) Step 5: Update NULL to TRUE not synced +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- ============================================================================ +-- STEP 6: Verify final state with hash comparison +-- ============================================================================ + +\echo [INFO] (:testid) === STEP 6: Verify data integrity === + +\connect cloudsync_test_25a +SELECT md5( + COALESCE( + string_agg( + id || ':' || COALESCE(flag::text, 'NULL') || ':' || COALESCE(name, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_a FROM bool_test \gset + +\connect cloudsync_test_25b +SELECT md5( + COALESCE( + string_agg( + id || ':' || COALESCE(flag::text, 'NULL') || ':' || COALESCE(name, 'NULL'), + '|' ORDER BY id + ), + '' + ) +) AS hash_b FROM bool_test \gset + +SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset +\if :hashes_match +\echo [PASS] (:testid) Data integrity verified - hashes match +\else +\echo [FAIL] (:testid) Data integrity check failed +SELECT (:fail::int + 1) AS fail \gset +\endif + +SELECT COUNT(*) AS count_b FROM bool_test \gset +SELECT (:count_b = 3) AS count_ok \gset +\if :count_ok +\echo [PASS] (:testid) Row count correct (3 rows) +\else +\echo [FAIL] (:testid) Row count incorrect - expected 3, got :count_b +SELECT (:fail::int + 1) AS fail \gset +\endif + +-- Cleanup +\ir helper_test_cleanup.sql +\if :should_cleanup +\connect postgres +DROP DATABASE IF EXISTS cloudsync_test_25a; +DROP DATABASE IF EXISTS cloudsync_test_25b; +\endif diff --git a/test/postgresql/full_test.sql b/test/postgresql/full_test.sql index 664eaa0..798df52 100644 --- a/test/postgresql/full_test.sql +++ b/test/postgresql/full_test.sql @@ -27,6 +27,12 @@ \ir 17_uuid_pk_roundtrip.sql \ir 18_bulk_insert_performance.sql \ir 19_uuid_pk_with_unmapped_cols.sql +\ir 20_init_with_existing_data.sql +\ir 21_null_value_sync.sql +\ir 22_null_column_roundtrip.sql +\ir 23_uuid_column_roundtrip.sql +\ir 24_nullable_types_roundtrip.sql +\ir 25_boolean_type_issue.sql -- 'Test summary' \echo '\nTest summary:'