The retention function takes as arguments a set of conditions from 1 to 32 arguments of type Bool that indicate whether a certain condition was met for the event. Any condition can be specified as an argument.
The conditions, except the first, apply in pairs: the result of the second will be true if the first and second are true, of the third if the first and third are true, etc.
To put it simply, the first digit of the return value array indicates whether event_1 is true or false, the second digit represents the truth and falseness of event_1 and event_2, and the third digit represents whether event_1 is true or false and event_3 is true or false, and so on. If event_1 is false, return an array full of false.
RETENTION(<event_1> [, <event_2>, ... , <event_n>]);
| Parameter | Description |
|---|---|
<event_n> | The nth event condition, type Bool. |
CREATE TABLE retention_test( `uid` int COMMENT 'user id', `date` datetime COMMENT 'date time' ) DUPLICATE KEY(uid) DISTRIBUTED BY HASH(uid) BUCKETS AUTO PROPERTIES ( "replication_allocation" = "tag.location.default: 1" ); INSERT into retention_test values (0, '2022-10-12'), (0, '2022-10-13'), (0, '2022-10-14'), (1, '2022-10-12'), (1, '2022-10-13'), (2, '2022-10-12');
SELECT uid, RETENTION(date = '2022-10-12') AS r, RETENTION(date = '2022-10-12', date = '2022-10-13') AS r2, RETENTION(date = '2022-10-12', date = '2022-10-13', date = '2022-10-14') AS r3 FROM retention_test GROUP BY uid ORDER BY uid ASC;
+------+------+--------+-----------+ | uid | r | r2 | r3 | +------+------+--------+-----------+ | 0 | [1] | [1, 1] | [1, 1, 1] | | 1 | [1] | [1, 1] | [1, 1, 0] | | 2 | [1] | [1, 0] | [1, 0, 0] | +------+------+--------+-----------+
CREATE TABLE retention_test2( `uid` int, `flag` boolean, `flag2` boolean ) DUPLICATE KEY(uid) DISTRIBUTED BY HASH(uid) BUCKETS AUTO PROPERTIES ( "replication_allocation" = "tag.location.default: 1" ); INSERT into retention_test2 values (0, false, false), (1, true, NULL); SELECT * from retention_test2;
+------+------+-------+ | uid | flag | flag2 | +------+------+-------+ | 0 | 1 | NULL | | 1 | 0 | 0 | +------+------+-------+
SELECT RETENTION(date = '2022-10-12') AS r FROM retention_test2 where uid is NULL;
+------+ | r | +------+ | NULL | +------+
select retention(flag) from retention_test2;
+-----------------+ | retention(flag) | +-----------------+ | [1] | +-----------------+
select retention(flag,flag2) from retention_test2;
+-----------------------+ | retention(flag,flag2) | +-----------------------+ | [0, 0] | +-----------------------+
select retention(flag,IFNULL(flag2,false)) from retention_test2;;
+-------------------------------------+ | retention(flag,IFNULL(flag2,false)) | +-------------------------------------+ | [1, 0] | +-------------------------------------+