BOOLEAN
Examples
-
Inserting and selecting
CREATE TABLE TBOOL (ID INT, BVAL BOOLEAN); COMMIT; INSERT INTO TBOOL VALUES (1, TRUE); INSERT INTO TBOOL VALUES (2, 2 = 4); INSERT INTO TBOOL VALUES (3, NULL = 1); COMMIT; SELECT * FROM TBOOL; ID BVAL ============ ======= 1 <true> 2 <false> 3 <null>
-
Test for
TRUE
valueSELECT * FROM TBOOL WHERE BVAL; ID BVAL ============ ======= 1 <true>
-
Test for
FALSE
valueSELECT * FROM TBOOL WHERE BVAL IS FALSE; ID BVAL ============ ======= 2 <false>
-
Test for
UNKNOWN
valueSELECT * FROM TBOOL WHERE BVAL IS UNKNOWN; ID BVAL ============ ======= 3 <null>
-
Boolean values in
SELECT
listSELECT ID, BVAL, BVAL AND ID < 2 FROM TBOOL; ID BVAL ============ ======= ======= 1 <true> <true> 2 <false> <false> 3 <null> <false>
-
PSQL declaration with start value
DECLARE VARIABLE VAR1 BOOLEAN = TRUE;
-
Valid syntax, but as with a comparison with
NULL
, will never return any record
SELECT * FROM TBOOL WHERE BVAL = UNKNOWN; SELECT * FROM TBOOL WHERE BVAL <> UNKNOWN;