BOOLEAN datatype with PHP-compatible output

Posted by ads' corner on Monday, 2008-01-07
Posted in [Php][Postgresql-News]

If you use pure PHP (no database abstraction layer) with PostgreSQL, you may run into the problem that your BOOLEAN columns are not recognized by PHP but the value is instead returned as a string.

So any code like:

1
if (!$boolean)

always returns true because the t and f are just strings in PHP.

Other programming languages like Perl, Python or Java and even the newer PHP PDO don’t have this problem so it’s clearly a PHP issue … but I don’t expect this one to be fixed, because this may break a lot existing applications. The column type information is available in the query result information so normally this should not be a big problem.

How to resolve this problem? There are some possibilities, one simple way would be to just use a SMALLINT instead a BOOLEAN, but with the disadvantage that you loose the boolean input values. Another way is to create a new BOOLEAN type and change the output to something PHP-compatible. This new type is binary compatible with the existing BOOLEAN type so casts in either way are not a problem.

Note: I asked around, but it seems, there is no easy solution which does not require updates in the PHP or SQL code. Any workaround like explicit casts to integer are error-prone and you cannot easily find out, because your application will work, but in a wrong way.

  1
  2
  3
  4
  5
  6
  7
  8
  9
 10
 11
 12
 13
 14
 15
 16
 17
 18
 19
 20
 21
 22
 23
 24
 25
 26
 27
 28
 29
 30
 31
 32
 33
 34
 35
 36
 37
 38
 39
 40
 41
 42
 43
 44
 45
 46
 47
 48
 49
 50
 51
 52
 53
 54
 55
 56
 57
 58
 59
 60
 61
 62
 63
 64
 65
 66
 67
 68
 69
 70
 71
 72
 73
 74
 75
 76
 77
 78
 79
 80
 81
 82
 83
 84
 85
 86
 87
 88
 89
 90
 91
 92
 93
 94
 95
 96
 97
 98
 99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
--
-- create PHP compatible BOOLEAN type
--

-- drop the data type, if exist
-- this will drop all functions and drop all columns which use this type
DROP TYPE IF EXISTS boolean2 CASCADE;

-- input and output functions
-- we can use already existing internal functions
CREATE FUNCTION boolean2_in(cstring)
 RETURNS boolean2
 AS 'boolin'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolean2_out(boolean2)
 RETURNS cstring
 AS 'int2out'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolean2_recv(internal)
 RETURNS boolean2
 AS 'boolrecv'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolean2_send(boolean2)
 RETURNS bytea
 AS 'boolsend'
 LANGUAGE internal STRICT;

-- create the data type
CREATE TYPE boolean2 (
 input = boolean2_in,
 output = boolean2_out,
 receive = boolean2_recv,
 send = boolean2_send,
 internallength = 1,
 alignment = char,
 storage = plain,
 passedbyvalue
);
COMMENT ON TYPE boolean2 IS 'boolean, ''1''/''0''';

-- since boolean2 is binary compatible with boolean, we can cast
-- in both ways without need for a supporting function
CREATE CAST (boolean2 AS boolean)
 WITHOUT FUNCTION
 AS ASSIGNMENT;
CREATE CAST (boolean AS boolean2)
 WITHOUT FUNCTION
 AS ASSIGNMENT;

-- create casting functions for integer versus boolean2
CREATE FUNCTION int4(boolean2)
 RETURNS int4
 AS 'bool_int4'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolean2(int4)
 RETURNS boolean2
 AS 'int4_bool'
 LANGUAGE internal STRICT;

-- create the casts
CREATE CAST (boolean2 AS int4)
 WITH FUNCTION int4(boolean2)
 AS ASSIGNMENT;
CREATE CAST (int4 AS boolean2)
 WITH FUNCTION boolean2(int4)
 AS ASSIGNMENT;

-- we need some operators and supporting functions
CREATE FUNCTION boollt(boolean2, boolean)
 RETURNS boolean
 AS 'boollt'
 LANGUAGE internal STRICT;
CREATE FUNCTION boollt(boolean, boolean2)
 RETURNS boolean
 AS 'boollt'
 LANGUAGE internal STRICT;
CREATE FUNCTION boollt(boolean2, boolean2)
 RETURNS boolean
 AS 'boollt'
 LANGUAGE internal STRICT;
CREATE OPERATOR < (
 PROCEDURE = boollt,
 LEFTARG = boolean2,
 RIGHTARG = boolean,
 COMMUTATOR = >,
 NEGATOR = >=,
 RESTRICT = scalarltsel,
 JOIN = scalarltjoinsel
);
CREATE OPERATOR < (
 PROCEDURE = boollt,
 LEFTARG = boolean,
 RIGHTARG = boolean2,
 COMMUTATOR = >,
 NEGATOR = >=,
 RESTRICT = scalarltsel,
 JOIN = scalarltjoinsel
);
CREATE OPERATOR < (
 PROCEDURE = boollt,
 LEFTARG = boolean2,
 RIGHTARG = boolean2,
 COMMUTATOR = >,
 NEGATOR = >=,
 RESTRICT = scalarltsel,
 JOIN = scalarltjoinsel
);

CREATE FUNCTION boolle(boolean2, boolean)
 RETURNS boolean
 AS 'boolle'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolle(boolean, boolean2)
 RETURNS boolean
 AS 'boolle'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolle(boolean2, boolean2)
 RETURNS boolean
 AS 'boolle'
 LANGUAGE internal STRICT;
CREATE OPERATOR <= (
 PROCEDURE = boolle,
 LEFTARG = boolean2,
 RIGHTARG = boolean,
 COMMUTATOR = >=,
 NEGATOR = >,
 RESTRICT = scalarltsel,
 JOIN = scalarltjoinsel
);
CREATE OPERATOR <= (
 PROCEDURE = boolle,
 LEFTARG = boolean,
 RIGHTARG = boolean2,
 COMMUTATOR = >=,
 NEGATOR = >,
 RESTRICT = scalarltsel,
 JOIN = scalarltjoinsel
);
CREATE OPERATOR <= (
 PROCEDURE = boolle,
 LEFTARG = boolean2,
 RIGHTARG = boolean2,
 COMMUTATOR = >=,
 NEGATOR = >,
 RESTRICT = scalarltsel,
 JOIN = scalarltjoinsel
);

CREATE FUNCTION boolne(boolean2, boolean)
 RETURNS boolean
 AS 'boolne'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolne(boolean, boolean2)
 RETURNS boolean
 AS 'boolne'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolne(boolean2, boolean2)
 RETURNS boolean
 AS 'boolne'
 LANGUAGE internal STRICT;
CREATE OPERATOR <> (
 PROCEDURE = boolne,
 LEFTARG = boolean2,
 RIGHTARG = boolean,
 COMMUTATOR = <>,
 NEGATOR = =,
 RESTRICT = neqsel,
 JOIN = neqjoinsel
);
CREATE OPERATOR <> (
 PROCEDURE = boolne,
 LEFTARG = boolean,
 RIGHTARG = boolean2,
 COMMUTATOR = <>,
 NEGATOR = =,
 RESTRICT = neqsel,
 JOIN = neqjoinsel
);
CREATE OPERATOR <> (
 PROCEDURE = boolne,
 LEFTARG = boolean2,
 RIGHTARG = boolean2,
 COMMUTATOR = <>,
 NEGATOR = =,
 RESTRICT = neqsel,
 JOIN = neqjoinsel
);

CREATE FUNCTION booleq(boolean2, boolean)
 RETURNS boolean
 AS 'booleq'
 LANGUAGE internal STRICT;
CREATE FUNCTION booleq(boolean, boolean2)
 RETURNS boolean
 AS 'booleq'
 LANGUAGE internal STRICT;
CREATE FUNCTION booleq(boolean2, boolean2)
 RETURNS boolean
 AS 'booleq'
 LANGUAGE internal STRICT;
CREATE OPERATOR = (
 PROCEDURE = booleq,
 LEFTARG = boolean2,
 RIGHTARG = boolean,
 COMMUTATOR = =,
 NEGATOR = <>,
 HASHES,
 RESTRICT = eqsel,
 JOIN = eqjoinsel,
 SORT1 = <,
 SORT2 = <,
 LTCMP = <,
 GTCMP = >
);
CREATE OPERATOR = (
 PROCEDURE = booleq,
 LEFTARG = boolean,
 RIGHTARG = boolean2,
 COMMUTATOR = =,
 NEGATOR = <>,
 HASHES,
 RESTRICT = eqsel,
 JOIN = eqjoinsel,
 SORT1 = <,
 SORT2 = <,
 LTCMP = <,
 GTCMP = >
);
CREATE OPERATOR = (
 PROCEDURE = booleq,
 LEFTARG = boolean2,
 RIGHTARG = boolean2,
 COMMUTATOR = =,
 NEGATOR = <>,
 HASHES,
 RESTRICT = eqsel,
 JOIN = eqjoinsel,
 SORT1 = <,
 SORT2 = <,
 LTCMP = <,
 GTCMP = >
);

CREATE FUNCTION boolgt(boolean2, boolean)
 RETURNS boolean
 AS 'boolgt'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolgt(boolean, boolean2)
 RETURNS boolean
 AS 'boolgt'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolgt(boolean2, boolean2)
 RETURNS boolean
 AS 'boolgt'
 LANGUAGE internal STRICT;
CREATE OPERATOR > (
 PROCEDURE = boolgt,
 LEFTARG = boolean2,
 RIGHTARG = boolean,
 COMMUTATOR = <,
 NEGATOR = <=,
 RESTRICT = scalargtsel,
 JOIN = scalargtjoinsel
);
CREATE OPERATOR > (
 PROCEDURE = boolgt,
 LEFTARG = boolean,
 RIGHTARG = boolean2,
 COMMUTATOR = <,
 NEGATOR = <=,
 RESTRICT = scalargtsel,
 JOIN = scalargtjoinsel
);
CREATE OPERATOR > (
 PROCEDURE = boolgt,
 LEFTARG = boolean2,
 RIGHTARG = boolean2,
 COMMUTATOR = <,
 NEGATOR = <=,
 RESTRICT = scalargtsel,
 JOIN = scalargtjoinsel
);

CREATE FUNCTION boolge(boolean2, boolean)
 RETURNS boolean
 AS 'boolge'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolge(boolean, boolean2)
 RETURNS boolean
 AS 'boolge'
 LANGUAGE internal STRICT;
CREATE FUNCTION boolge(boolean2, boolean2)
 RETURNS boolean
 AS 'boolge'
 LANGUAGE internal STRICT;
CREATE OPERATOR >= (
 PROCEDURE = boolge,
 LEFTARG = boolean2,
 RIGHTARG = boolean,
 COMMUTATOR = <=,
 NEGATOR = <,
 RESTRICT = scalargtsel,
 JOIN = scalargtjoinsel
);
CREATE OPERATOR >= (
 PROCEDURE = boolge,
 LEFTARG = boolean,
 RIGHTARG = boolean2,
 COMMUTATOR = <=,
 NEGATOR = <,
 RESTRICT = scalargtsel,
 JOIN = scalargtjoinsel
);
CREATE OPERATOR >= (
 PROCEDURE = boolge,
 LEFTARG = boolean2,
 RIGHTARG = boolean2,
 COMMUTATOR = <=,
 NEGATOR = <,
 RESTRICT = scalargtsel,
 JOIN = scalargtjoinsel
);
-- end defining operators

-- create functions supporting operator classes
CREATE FUNCTION btboolcmp(boolean2, boolean)
 RETURNS int4
 AS 'btboolcmp'
 LANGUAGE internal STRICT;
CREATE FUNCTION btboolcmp(boolean, boolean2)
 RETURNS int4
 AS 'btboolcmp'
 LANGUAGE internal STRICT;
CREATE FUNCTION btboolcmp(boolean2, boolean2)
 RETURNS int4
 AS 'btboolcmp'
 LANGUAGE internal STRICT;

-- create operator classes, needed for index support
CREATE OPERATOR CLASS _bool2_ops
 DEFAULT FOR TYPE boolean2[] USING gin AS
 STORAGE boolean2 ,
 OPERATOR 1 &&(anyarray,anyarray) ,
 OPERATOR 2 @>(anyarray,anyarray) ,
 OPERATOR 3 <@(anyarray,anyarray) RECHECK ,
 OPERATOR 4 =(anyarray,anyarray) RECHECK ,
 FUNCTION 1 btboolcmp(boolean2,boolean2) ,
 FUNCTION 2 ginarrayextract(anyarray,internal) ,
 FUNCTION 3 ginarrayextract(anyarray,internal) ,
 FUNCTION 4 ginarrayconsistent(internal,smallint,internal);

CREATE OPERATOR CLASS bool2_ops
 DEFAULT FOR TYPE boolean2 USING btree AS
 OPERATOR 1 <(boolean2,boolean2) ,
 OPERATOR 2 <=(boolean2,boolean2) ,
 OPERATOR 3 =(boolean2,boolean2) ,
 OPERATOR 4 >=(boolean2,boolean2) ,
 OPERATOR 5 >(boolean2,boolean2) ,
 FUNCTION 1 btboolcmp(boolean2,boolean2);

CREATE OPERATOR CLASS bool2_ops
 DEFAULT FOR TYPE boolean2 USING hash AS
 OPERATOR 1 =(boolean2,boolean2) ,
 FUNCTION 1 hashchar("char");

-- create a test case
DROP TABLE IF EXISTS boolean2_test;
CREATE TABLE boolean2_test (
 id SERIAL NOT NULL PRIMARY KEY,
 test boolean2
);

-- true, false, true, false, true, false
INSERT INTO boolean2_test (test) VALUES ('true');
INSERT INTO boolean2_test (test) VALUES ('false');
INSERT INTO boolean2_test (test) VALUES ('1');
INSERT INTO boolean2_test (test) VALUES ('0');
INSERT INTO boolean2_test (test) VALUES ('yes');
INSERT INTO boolean2_test (test) VALUES ('no');
INSERT INTO boolean2_test (test) VALUES ('y');
INSERT INTO boolean2_test (test) VALUES ('n');
-- this should fail
INSERT INTO boolean2_test (test) VALUES ('blub');
-- the output should be 0/1
SELECT * FROM boolean2_test ORDER BY id;

DROP TABLE IF EXISTS boolean2_test2;
CREATE TABLE boolean2_test2 (
 id SERIAL NOT NULL
 UNIQUE,
 t1 INTEGER NOT NULL,
 t2 BOOLEAN2 NOT NULL
 DEFAULT FALSE
);
CREATE INDEX t1_t1 ON boolean2_test2(t1);
CREATE INDEX t1_t2 ON boolean2_test2(t2);

INSERT INTO boolean2_test2 (t1, t2) SELECT *, FALSE FROM generate_series(1,10000);
INSERT INTO boolean2_test2 (t1, t2) SELECT *, TRUE FROM generate_series(1,5000);

-- make sure, PG will try to use the index:
SET enable_seqscan=0;
VACUUM FULL ANALYZE boolean2_test2;

EXPLAIN SELECT COUNT(*) FROM boolean2_test2 WHERE t2='true';
EXPLAIN SELECT COUNT(*) FROM boolean2_test2 WHERE t2='false';
EXPLAIN SELECT COUNT(*) FROM boolean2_test2 WHERE t2='0';
EXPLAIN SELECT COUNT(*) FROM boolean2_test2 WHERE t2='1';

Categories: [Php] [Postgresql-News]
Tags: [Java] [Pdo] [Perl] [Php] [Postgresql] [Psql] [Python] [Stupid] [Vacuum]