Skip to content

Commit 9a1b4c0

Browse files
committed
fix(postgres): add bigint to boolean cast for BOOLEAN column sync
BOOLEAN values are encoded as INT8 in sync payloads for SQLite interoperability, but PostgreSQL has no built-in cast from bigint to boolean. Add a custom ASSIGNMENT cast that enables BOOLEAN columns to sync correctly. The cast uses ASSIGNMENT context (not IMPLICIT) to avoid unintended conversions in WHERE clauses while still enabling INSERT/UPDATE operations used by merge_insert. The write direction (BOOL → INT encoding flow) "just works" because DatumGetBool() naturally returns 0 or 1. The problem was only on the read side where PostgreSQL refused to cast the decoded INT8 back to BOOLEAN without our custom cast.
1 parent 6889598 commit 9a1b4c0

File tree

3 files changed

+260
-0
lines changed

3 files changed

+260
-0
lines changed

src/postgresql/cloudsync--1.0.sql

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -276,3 +276,21 @@ CREATE OR REPLACE FUNCTION cloudsync_table_schema(table_name text)
276276
RETURNS text
277277
AS 'MODULE_PATHNAME', 'pg_cloudsync_table_schema'
278278
LANGUAGE C VOLATILE;
279+
280+
-- ============================================================================
281+
-- Type Casts
282+
-- ============================================================================
283+
284+
-- Cast function: converts bigint to boolean (0 = false, non-zero = true)
285+
-- Required because BOOLEAN values are encoded as INT8 in sync payloads,
286+
-- but PostgreSQL has no built-in cast from bigint to boolean.
287+
CREATE FUNCTION cloudsync_int8_to_bool(bigint) RETURNS boolean AS $$
288+
SELECT $1 <> 0
289+
$$ LANGUAGE SQL IMMUTABLE STRICT;
290+
291+
-- ASSIGNMENT cast: auto-applies in INSERT/UPDATE context only
292+
-- This enables BOOLEAN column sync where values are encoded as INT8.
293+
-- Using ASSIGNMENT (not IMPLICIT) to avoid unintended conversions in WHERE clauses.
294+
CREATE CAST (bigint AS boolean)
295+
WITH FUNCTION cloudsync_int8_to_bool(bigint)
296+
AS ASSIGNMENT;
Lines changed: 241 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,241 @@
1+
-- Test: BOOLEAN Type Roundtrip
2+
-- This test verifies that BOOLEAN columns sync correctly.
3+
-- BOOLEAN values are encoded as INT8 in sync payloads. The cloudsync extension
4+
-- provides a custom cast (bigint AS boolean) to enable this.
5+
--
6+
-- See plans/ANALYSIS_BOOLEAN_TYPE_CONVERSION.md for details.
7+
8+
\set testid '25'
9+
\ir helper_test_init.sql
10+
11+
\connect postgres
12+
\ir helper_psql_conn_setup.sql
13+
14+
DROP DATABASE IF EXISTS cloudsync_test_25a;
15+
DROP DATABASE IF EXISTS cloudsync_test_25b;
16+
CREATE DATABASE cloudsync_test_25a;
17+
CREATE DATABASE cloudsync_test_25b;
18+
19+
-- Setup Database A
20+
\connect cloudsync_test_25a
21+
\ir helper_psql_conn_setup.sql
22+
CREATE EXTENSION IF NOT EXISTS cloudsync;
23+
24+
CREATE TABLE bool_test (
25+
id TEXT PRIMARY KEY NOT NULL,
26+
flag BOOLEAN,
27+
name TEXT
28+
);
29+
30+
SELECT cloudsync_init('bool_test', 'CLS', true) AS _init_a \gset
31+
32+
-- Setup Database B
33+
\connect cloudsync_test_25b
34+
\ir helper_psql_conn_setup.sql
35+
CREATE EXTENSION IF NOT EXISTS cloudsync;
36+
37+
CREATE TABLE bool_test (
38+
id TEXT PRIMARY KEY NOT NULL,
39+
flag BOOLEAN,
40+
name TEXT
41+
);
42+
43+
SELECT cloudsync_init('bool_test', 'CLS', true) AS _init_b \gset
44+
45+
-- ============================================================================
46+
-- STEP 1: Insert NULL BOOLEAN first (triggers SPI plan caching)
47+
-- ============================================================================
48+
49+
\echo [INFO] (:testid) === STEP 1: NULL BOOLEAN ===
50+
51+
\connect cloudsync_test_25a
52+
INSERT INTO bool_test (id, flag, name) VALUES ('row1', NULL, 'null_flag');
53+
54+
SELECT encode(
55+
cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq),
56+
'hex'
57+
) AS payload1_hex
58+
FROM cloudsync_changes
59+
WHERE site_id = cloudsync_siteid() \gset
60+
61+
SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset
62+
63+
\connect cloudsync_test_25b
64+
SELECT cloudsync_payload_apply(decode(:'payload1_hex', 'hex')) AS apply1 \gset
65+
66+
SELECT (SELECT flag IS NULL AND name = 'null_flag' FROM bool_test WHERE id = 'row1') AS step1_ok \gset
67+
\if :step1_ok
68+
\echo [PASS] (:testid) Step 1: NULL BOOLEAN preserved
69+
\else
70+
\echo [FAIL] (:testid) Step 1: NULL BOOLEAN not preserved
71+
SELECT (:fail::int + 1) AS fail \gset
72+
\endif
73+
74+
-- ============================================================================
75+
-- STEP 2: Insert TRUE BOOLEAN (tests INT8 -> BOOLEAN cast after NULL)
76+
-- ============================================================================
77+
78+
\echo [INFO] (:testid) === STEP 2: TRUE BOOLEAN after NULL ===
79+
80+
\connect cloudsync_test_25a
81+
INSERT INTO bool_test (id, flag, name) VALUES ('row2', true, 'true_flag');
82+
83+
SELECT encode(
84+
cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq),
85+
'hex'
86+
) AS payload2_hex
87+
FROM cloudsync_changes
88+
WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset
89+
90+
SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset
91+
92+
\connect cloudsync_test_25b
93+
SELECT cloudsync_payload_apply(decode(:'payload2_hex', 'hex')) AS apply2 \gset
94+
95+
SELECT (SELECT flag = true AND name = 'true_flag' FROM bool_test WHERE id = 'row2') AS step2_ok \gset
96+
\if :step2_ok
97+
\echo [PASS] (:testid) Step 2: TRUE BOOLEAN preserved after NULL
98+
\else
99+
\echo [FAIL] (:testid) Step 2: TRUE BOOLEAN not preserved
100+
SELECT (:fail::int + 1) AS fail \gset
101+
\endif
102+
103+
-- ============================================================================
104+
-- STEP 3: Insert FALSE BOOLEAN
105+
-- ============================================================================
106+
107+
\echo [INFO] (:testid) === STEP 3: FALSE BOOLEAN ===
108+
109+
\connect cloudsync_test_25a
110+
INSERT INTO bool_test (id, flag, name) VALUES ('row3', false, 'false_flag');
111+
112+
SELECT encode(
113+
cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq),
114+
'hex'
115+
) AS payload3_hex
116+
FROM cloudsync_changes
117+
WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset
118+
119+
SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset
120+
121+
\connect cloudsync_test_25b
122+
SELECT cloudsync_payload_apply(decode(:'payload3_hex', 'hex')) AS apply3 \gset
123+
124+
SELECT (SELECT flag = false AND name = 'false_flag' FROM bool_test WHERE id = 'row3') AS step3_ok \gset
125+
\if :step3_ok
126+
\echo [PASS] (:testid) Step 3: FALSE BOOLEAN preserved
127+
\else
128+
\echo [FAIL] (:testid) Step 3: FALSE BOOLEAN not preserved
129+
SELECT (:fail::int + 1) AS fail \gset
130+
\endif
131+
132+
-- ============================================================================
133+
-- STEP 4: Update TRUE to FALSE
134+
-- ============================================================================
135+
136+
\echo [INFO] (:testid) === STEP 4: Update TRUE to FALSE ===
137+
138+
\connect cloudsync_test_25a
139+
UPDATE bool_test SET flag = false WHERE id = 'row2';
140+
141+
SELECT encode(
142+
cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq),
143+
'hex'
144+
) AS payload4_hex
145+
FROM cloudsync_changes
146+
WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset
147+
148+
SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset
149+
150+
\connect cloudsync_test_25b
151+
SELECT cloudsync_payload_apply(decode(:'payload4_hex', 'hex')) AS apply4 \gset
152+
153+
SELECT (SELECT flag = false FROM bool_test WHERE id = 'row2') AS step4_ok \gset
154+
\if :step4_ok
155+
\echo [PASS] (:testid) Step 4: Update TRUE to FALSE synced
156+
\else
157+
\echo [FAIL] (:testid) Step 4: Update TRUE to FALSE not synced
158+
SELECT (:fail::int + 1) AS fail \gset
159+
\endif
160+
161+
-- ============================================================================
162+
-- STEP 5: Update NULL to TRUE
163+
-- ============================================================================
164+
165+
\echo [INFO] (:testid) === STEP 5: Update NULL to TRUE ===
166+
167+
\connect cloudsync_test_25a
168+
UPDATE bool_test SET flag = true WHERE id = 'row1';
169+
170+
SELECT encode(
171+
cloudsync_payload_encode(tbl, pk, col_name, col_value, col_version, db_version, site_id, cl, seq),
172+
'hex'
173+
) AS payload5_hex
174+
FROM cloudsync_changes
175+
WHERE site_id = cloudsync_siteid() AND db_version > :db_version \gset
176+
177+
SELECT max(db_version) AS db_version FROM bool_test_cloudsync \gset
178+
179+
\connect cloudsync_test_25b
180+
SELECT cloudsync_payload_apply(decode(:'payload5_hex', 'hex')) AS apply5 \gset
181+
182+
SELECT (SELECT flag = true FROM bool_test WHERE id = 'row1') AS step5_ok \gset
183+
\if :step5_ok
184+
\echo [PASS] (:testid) Step 5: Update NULL to TRUE synced
185+
\else
186+
\echo [FAIL] (:testid) Step 5: Update NULL to TRUE not synced
187+
SELECT (:fail::int + 1) AS fail \gset
188+
\endif
189+
190+
-- ============================================================================
191+
-- STEP 6: Verify final state with hash comparison
192+
-- ============================================================================
193+
194+
\echo [INFO] (:testid) === STEP 6: Verify data integrity ===
195+
196+
\connect cloudsync_test_25a
197+
SELECT md5(
198+
COALESCE(
199+
string_agg(
200+
id || ':' || COALESCE(flag::text, 'NULL') || ':' || COALESCE(name, 'NULL'),
201+
'|' ORDER BY id
202+
),
203+
''
204+
)
205+
) AS hash_a FROM bool_test \gset
206+
207+
\connect cloudsync_test_25b
208+
SELECT md5(
209+
COALESCE(
210+
string_agg(
211+
id || ':' || COALESCE(flag::text, 'NULL') || ':' || COALESCE(name, 'NULL'),
212+
'|' ORDER BY id
213+
),
214+
''
215+
)
216+
) AS hash_b FROM bool_test \gset
217+
218+
SELECT (:'hash_a' = :'hash_b') AS hashes_match \gset
219+
\if :hashes_match
220+
\echo [PASS] (:testid) Data integrity verified - hashes match
221+
\else
222+
\echo [FAIL] (:testid) Data integrity check failed
223+
SELECT (:fail::int + 1) AS fail \gset
224+
\endif
225+
226+
SELECT COUNT(*) AS count_b FROM bool_test \gset
227+
SELECT (:count_b = 3) AS count_ok \gset
228+
\if :count_ok
229+
\echo [PASS] (:testid) Row count correct (3 rows)
230+
\else
231+
\echo [FAIL] (:testid) Row count incorrect - expected 3, got :count_b
232+
SELECT (:fail::int + 1) AS fail \gset
233+
\endif
234+
235+
-- Cleanup
236+
\ir helper_test_cleanup.sql
237+
\if :should_cleanup
238+
\connect postgres
239+
DROP DATABASE IF EXISTS cloudsync_test_25a;
240+
DROP DATABASE IF EXISTS cloudsync_test_25b;
241+
\endif

test/postgresql/full_test.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -32,6 +32,7 @@
3232
\ir 22_null_column_roundtrip.sql
3333
\ir 23_uuid_column_roundtrip.sql
3434
\ir 24_nullable_types_roundtrip.sql
35+
\ir 25_boolean_type_issue.sql
3536

3637
-- 'Test summary'
3738
\echo '\nTest summary:'

0 commit comments

Comments
 (0)