diff --git a/CHANGELOG.md b/CHANGELOG.md index 2c6624b861ad763c9dd3a8eb4019a3894ee3c599..64a0884f8f622824bb20d2711134e4a4a99e46f7 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -47,6 +47,12 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0 ### Fixed ### +* Fixed the `>=` and `<=` operators for comparisons in POV query filters with + stored DATE values. The fix makes the implementation consistent + However, the current definition and implementation of the + `>=` and `<=` operators for date and datetime is unintuitive and the operators + should have another name. Something like "overlap with or smaller/greater + than". * Semi-fix in `retrieveEntityParents`. The old implementation was buggy and would return no parent name or even a wrong one for old entity versions in some cases. The semi-fix will allways return the current name of the parent diff --git a/procedures/query/getDateTimeWhereClause.sql b/procedures/query/getDateTimeWhereClause.sql index 55f65ea40db84310c1a1c1ddbb7faa58ce4a9ee5..8947e04a6640db0f7950d8475304e5f654921584 100644 --- a/procedures/query/getDateTimeWhereClause.sql +++ b/procedures/query/getDateTimeWhereClause.sql @@ -26,18 +26,18 @@ DELIMITER // CREATE FUNCTION db_2_0.getDateTimeWhereClause(vDateTime VARCHAR(255), operator CHAR(4)) RETURNS VARCHAR(20000) DETERMINISTIC BEGIN - DECLARE sep_loc INTEGER DEFAULT LOCATE('--',vDateTime); + DECLARE sep_loc INTEGER DEFAULT LOCATE('--',vDateTime); DECLARE vDateTimeLow VARCHAR(255) DEFAULT IF(sep_loc != 0, SUBSTRING_INDEX(vDateTime, '--',1), vDateTime); DECLARE vDateTimeUpp VARCHAR(255) DEFAULT IF(sep_loc != 0, SUBSTRING_INDEX(vDateTime, '--',-1), NULL); - + DECLARE vDateTimeSecLow VARCHAR(255) DEFAULT SUBSTRING_INDEX(vDateTimeLow, 'UTC', 1); DECLARE vDateTimeNSLow VARCHAR(255) DEFAULT IF(SUBSTRING_INDEX(vDateTimeLow, 'UTC', -1)='',NULL,SUBSTRING_INDEX(vDateTimeLow, 'UTC', -1)); - + DECLARE vDateTimeSecUpp VARCHAR(255) DEFAULT IF(sep_loc != 0, SUBSTRING_INDEX(vDateTimeUpp, 'UTC', 1), NULL); DECLARE vDateTimeNSUpp VARCHAR(255) DEFAULT IF(sep_loc != 0 AND SUBSTRING_INDEX(vDateTimeUpp, 'UTC', -1)!='',SUBSTRING_INDEX(vDateTimeUpp, 'UTC', -1),NULL); - - - RETURN constructDateTimeWhereClauseForColumn("subdata.value", "subdata.value_ns", vDateTimeSecLow, vDateTimeNSLow, vDateTimeSecUpp, vDateTimeNSUpp, operator); + + + RETURN constructDateTimeWhereClauseForColumn("subdata.value", "subdata.value_ns", vDateTimeSecLow, vDateTimeNSLow, vDateTimeSecUpp, vDateTimeNSUpp, operator); END; // DELIMITER ; @@ -51,44 +51,51 @@ DELIMITER // CREATE FUNCTION db_2_0.constructDateTimeWhereClauseForColumn(seconds_col VARCHAR(255), nanos_col VARCHAR(255), vDateTimeSecLow VARCHAR(255), vDateTimeNSLow VARCHAR(255), vDateTimeSecUpp VARCHAR(255), vDateTimeNSUpp VARCHAR(255), operator CHAR(4)) RETURNS VARCHAR(20000) DETERMINISTIC BEGIN - DECLARE isInterval BOOLEAN DEFAULT vDateTimeSecUpp IS NOT NULL or vDateTimeNSUpp IS NOT NULL; + DECLARE isInterval BOOLEAN DEFAULT vDateTimeSecUpp IS NOT NULL or vDateTimeNSUpp IS NOT NULL; DECLARE operator_prefix CHAR(1) DEFAULT LEFT(operator,1); - IF isInterval THEN - IF operator = '=' THEN - RETURN " 0=1"; + IF isInterval THEN + IF operator = '=' THEN + RETURN " 0=1"; ELSEIF operator = '!=' THEN - RETURN " 0=1"; - ELSEIF operator = '>' or operator = '<=' THEN + RETURN " 0=1"; + ELSEIF operator = '>' or operator = '<=' THEN RETURN CONCAT(" ", seconds_col, operator_prefix, vDateTimeSecUpp); - ELSEIF operator = '<' or operator = '>=' THEN + ELSEIF operator = '<' or operator = '>=' THEN RETURN CONCAT(" ", seconds_col, operator_prefix, vDateTimeSecLow); - ELSEIF operator = "(" THEN + ELSEIF operator = "(" THEN RETURN CONCAT(" ", seconds_col, ">=", vDateTimeSecLow, " AND ",seconds_col, "<", vDateTimeSecUpp); - ELSEIF operator = "!(" THEN + ELSEIF operator = "!(" THEN RETURN CONCAT(" ", seconds_col, "<", vDateTimeSecLow, " OR ", seconds_col, ">=", vDateTimeSecUpp); - END IF; + END IF; ELSE IF operator = '=' THEN RETURN CONCAT(" ", - seconds_col, - "=", vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, CONCAT(' AND ', nanos_col, ' IS NULL'), CONCAT(' AND ', - nanos_col, - '=', vDateTimeNSLow))); + seconds_col, + "=", vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, CONCAT(' AND ', nanos_col, ' IS NULL'), CONCAT(' AND ', + nanos_col, + '=', vDateTimeNSLow))); ELSEIF operator = '!=' THEN RETURN CONCAT(" ", - seconds_col, - "!=", vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, '', CONCAT(' OR ', - nanos_col, - '!=', vDateTimeNSLow))); + seconds_col, + "!=", vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, '', CONCAT(' OR ', + nanos_col, + '!=', vDateTimeNSLow))); ELSEIF operator = '>' or operator = '<' THEN RETURN CONCAT(" ", - seconds_col, operator, vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, '', CONCAT(' OR (',seconds_col,'=', vDateTimeSecLow, ' AND ',nanos_col, operator, vDateTimeNSLow, ')'))); + seconds_col, operator, vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, '', CONCAT(' OR (',seconds_col,'=', vDateTimeSecLow, ' AND ',nanos_col, operator, vDateTimeNSLow, ')'))); ELSEIF operator = '>=' or operator = '<=' THEN - RETURN CONCAT(" ",seconds_col, operator, vDateTimeSecLow, IF(vDateTimeNSLow IS NULL, '', CONCAT(' AND (',seconds_col, operator_prefix, vDateTimeSecLow, ' OR ',nanos_col, operator, vDateTimeNSLow, ')'))); - ELSEIF operator = "(" THEN + RETURN CONCAT( + " ", seconds_col, operator, vDateTimeSecLow, + IF(vDateTimeNSLow IS NULL, + '', + CONCAT( + ' AND (', seconds_col, operator_prefix, vDateTimeSecLow, + ' OR ', nanos_col, operator, vDateTimeNSLow, + ' OR ', nanos_col, ' IS NULL)'))); + ELSEIF operator = "(" THEN RETURN IF(vDateTimeNSLow IS NULL,CONCAT(" ",seconds_col,"=", vDateTimeSecLow),CONCAT(" ",seconds_col,"=",vDateTimeSecLow," AND ",nanos_col,"=",vDateTimeNSLow)); - ELSEIF operator = "!(" THEN + ELSEIF operator = "!(" THEN RETURN IF(vDateTimeNSLow IS NULL,CONCAT(" ",seconds_col,"!=",vDateTimeSecLow, ""),CONCAT(" ",seconds_col,"!=",vDateTimeSecLow," OR ",nanos_col, " IS NULL OR ", nanos_col, "!=",vDateTimeNSLow)); END IF; END IF; @@ -105,22 +112,27 @@ DELIMITER // CREATE FUNCTION db_2_0.getDateWhereClause(vDateTimeDotNotation VARCHAR(255), operator CHAR(4)) RETURNS VARCHAR(20000) DETERMINISTIC BEGIN - DECLARE isInterval INTEGER DEFAULT LOCATE('--',vDateTimeDotNotation); - DECLARE vILB VARCHAR(255) DEFAULT IF(isInterval != 0, SUBSTRING_INDEX(vDateTimeDotNotation, '--', 1), vDateTimeDotNotation); - DECLARE vEUB VARCHAR(255) DEFAULT IF(isInterval != 0, SUBSTRING_INDEX(vDateTimeDotNotation, '--', -1), NULL); - DECLARE vILB_Date INTEGER DEFAULT SUBSTRING_INDEX(vILB, '.', 1); - DECLARE vEUB_Date INTEGER DEFAULT SUBSTRING_INDEX(vEUB, '.', 1); + DECLARE isInterval INTEGER DEFAULT LOCATE('--',vDateTimeDotNotation); + -- ILB is short for Inclusive Lower Boundary + DECLARE vILB VARCHAR(255) DEFAULT IF(isInterval != 0, SUBSTRING_INDEX(vDateTimeDotNotation, '--', 1), vDateTimeDotNotation); + -- EUB is short for Exclusive Upper Boundary + DECLARE vEUB VARCHAR(255) DEFAULT IF(isInterval != 0, SUBSTRING_INDEX(vDateTimeDotNotation, '--', -1), NULL); + DECLARE vILB_Date INTEGER DEFAULT SUBSTRING_INDEX(vILB, '.', 1); + DECLARE vEUB_Date INTEGER DEFAULT SUBSTRING_INDEX(vEUB, '.', 1); + -- hasTime is actually hasNotTime DECLARE hasTime INTEGER DEFAULT LOCATE('.NULL.NULL',vILB); + -- Day of Month (0-31, 0 means any) DECLARE dom INTEGER DEFAULT vILB_Date % 100; - DECLARE mon INTEGER DEFAULT ((vILB_Date % 10000) - dom) / 100; - DECLARE yea INTEGER DEFAULT (vILB_Date - (vILB_Date%10000)) / 10000; - SELECT vILB_Date != vEUB_Date INTO isInterval; + -- Month (0-12, 0 means any) + DECLARE mon INTEGER DEFAULT ((vILB_Date % 10000) - dom) / 100; + -- Year + DECLARE yea INTEGER DEFAULT (vILB_Date - (vILB_Date % 10000)) / 10000; IF operator = '=' and hasTime != 0 THEN RETURN CONCAT(" subdata.value=", vILB_Date); ELSEIF operator = "!=" and hasTime != 0 THEN IF mon != 0 and dom != 0 THEN - RETURN CONCAT(" subdata.value!=", vILB_Date, " and subdata.value%100!=0"); + RETURN CONCAT(" subdata.value!=", vILB_Date, " and subdata.value%100!=0"); ELSEIF mon != 0 THEN RETURN CONCAT(" subdata.value!=", vILB_Date, " and subdata.value%100=0 and subdata.value%10000!=0"); ELSE @@ -161,6 +173,32 @@ BEGIN ELSE RETURN CONCAT(" subdata.value>=",vEUB_Date); END IF; + ELSEIF operator = "<=" THEN + IF mon != 0 and dom != 0 THEN + -- Full date YYYY-MM-DD + RETURN CONCAT(" subdata.value<=", vILB_Date, + " or (subdata.value<=", yea*10000 + mon*100, " and subdata.value%100=0)"); + ELSEIF mon != 0 THEN + -- Date is fragment YYYY-MM + RETURN CONCAT(" subdata.value<", vEUB_Date); + ELSE + -- Date is fragment YYYY + RETURN CONCAT(" subdata.value<", vEUB_Date); + END IF; + ELSEIF operator = ">=" THEN + IF mon != 0 and dom != 0 THEN + -- Full date YYYY-MM-DD + RETURN CONCAT(" subdata.value>=", vILB_Date, + " or (subdata.value>=", yea*10000 + mon*100, " and subdata.value%100=0)" + + " or (subdata.value>=", yea*10000, " and subdata.value%10000=0)"); + ELSEIF mon != 0 THEN + -- Date is fragment YYYY-MM + RETURN CONCAT(" subdata.value>=", yea*10000 + mon*100, + " or (subdata.value>=", yea*10000, " and subdata.value%10000=0)"); + ELSE + -- Date is fragment YYYY + RETURN CONCAT(" subdata.value>=", yea*10000); + END IF; END IF; return ' 0=1';