Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

In MariaDB 10.11, "empty" is a reserved word? [ATTN: cjb] #82

Open
wants to merge 1 commit into
base: master
Choose a base branch
from

Conversation

trentbuck
Copy link
Contributor

After upgrading from MariaDB 10.5 to 10.11,

FAILS: SELECT empty('fart');
WORKS: SELECT alloc.empty('fart');
WORKS: SELECT neq(1, 1);
WORKS: SELECT alloc.new(1, 1);

Therefore I speculate that "empty" now has special meaning. Therefore let's try simply renaming it from "empty" to "emptyXXX". As this stored function is only used in this one file, that should be easy?

https://github.com/cyberitsolutions/alloc/blob/1.9.0/installation/db_triggers.sql#L31

This seems to fix my immediate issue on alloc.cyber.com.au.

After upgrading from MariaDB 10.5 to 10.11,

  FAILS: SELECT empty('fart');
  WORKS: SELECT alloc.empty('fart');
  WORKS: SELECT neq(1, 1);
  WORKS: SELECT alloc.new(1, 1);

Therefore I speculate that "empty" now has special meaning.
Therefore let's try simply renaming it from "empty" to "emptyXXX".
As this stored function is only used in this one file, that should be easy?

  https://github.com/cyberitsolutions/alloc/blob/1.9.0/installation/db_triggers.sql#L31

This seems to fix my immediate issue on alloc.cyber.com.au.

14:58 *** twb JOIN ircs://irc.libera.chat/%23mariadb
14:58 ***  TOPIC Welcome to the new and official MariaDB chat server! You can also use https://mariadb.zulipchat.com for more targeted discussions (monty_!~monty_@62.248.255.24 on Wed May 26 23:56:16 2021)
15:00 <twb> Hi, I have an ancient PHP5 web app I have to keep limping along.  I upgraded it to MariaDB mariadb-server 1:10.5.19-0+deb11u2 earlier without issues; I upgraded from that to 1:10.11.3-1 yesterday and now I'm getting errors "Failed to load routine alloc.get_most_recent_non_archived_taskStatus (internal code -6). For more details, run SHOW WARNINGS" which SHOW WARNINGS turns into "Undeclared variable: empty".
15:01 <twb> Looking at the stored procedures I see a lot of stuff like "BEGIN IF empty(NEW.dateFrom) OR empty(NEW.dateTo) THEN ⋯"
15:01 <twb> Is empty() a mariadb thing or is that something the app has invented?
15:04 <twb> OK found it: https://github.com/cyberitsolutions/alloc/blob/1.9.0/installation/db_triggers.sql#L31
15:05 <twb> So the next question I guess is "how do I list all stored procedures?"
15:07 <twb> I can see the "empty" procedure exists

    MariaDB [alloc]> select * from information_schema.routines where specific_name = 'empty';
    *************************** 1. row ***************************
               SPECIFIC_NAME: empty
             ROUTINE_CATALOG: def
              ROUTINE_SCHEMA: alloc
                ROUTINE_NAME: empty
                ROUTINE_TYPE: FUNCTION
                   DATA_TYPE: tinyint
    CHARACTER_MAXIMUM_LENGTH: NULL
      CHARACTER_OCTET_LENGTH: NULL
           NUMERIC_PRECISION: 3
               NUMERIC_SCALE: 0
          DATETIME_PRECISION: NULL
          CHARACTER_SET_NAME: NULL
              COLLATION_NAME: NULL
              DTD_IDENTIFIER: tinyint(1)
                ROUTINE_BODY: SQL
          ROUTINE_DEFINITION: BEGIN RETURN str = '' OR str IS NULL; END
               EXTERNAL_NAME: NULL
           EXTERNAL_LANGUAGE: NULL
             PARAMETER_STYLE: SQL
            IS_DETERMINISTIC: YES
             SQL_DATA_ACCESS: CONTAINS SQL
                    SQL_PATH: NULL
               SECURITY_TYPE: DEFINER
                     CREATED: 2022-11-08 12:46:44
                LAST_ALTERED: 2022-11-08 12:46:44
                    SQL_MODE:
             ROUTINE_COMMENT:
                     DEFINER: root@localhost
        CHARACTER_SET_CLIENT: utf8
        COLLATION_CONNECTION: utf8_general_ci
          DATABASE_COLLATION: utf8mb4_general_ci
    1 row in set, 1 warning (0.007 sec)

15:09 <twb> So I guess this is just an issue with whether triggers can "see" store procedures
15:13 <twb> Correction: it's a stored function not a stored procedure.
15:19 <twb> Fails: MariaDB [alloc]> select empty('fart');  --error--> "You have an error in your SQL syntax"
15:19 <twb> Works: MariaDB [alloc]> select alloc.empty('fart'); --> 0
15:20 <twb> Why do I have to explicitly say the namespace/database, when it's already selected (per the prompt on the left)?
15:22 <twb> I can create a new function delete_me_test_function and then select it as either delete_me_test_function or alloc.delete_me_test_function
15:23 <twb> So this seems like maybe "empty" is a new reserved word???  It's not mentioned in the upgrade notes on https://mariadb.com/kb/en/upgrading/
15:33 <twb> OK that's interesting.  I tried to run this and I got "ERROR 1064 (42000) at line 38: Trigger 'before_update_task' has an error in its body: 'Undeclared variable: empty'"

    -- After upgrading from MariaDB 10.5 to 10.11,
    --   FAILS: SELECT empty('fart');
    --   WORKS: SELECT alloc.empty('fart');
    --   WORKS: SELECT neq(1, 1);
    --   WORKS: SELECT alloc.new(1, 1);
    --
    -- Therefore I speculate that "empty" now has special meaning.
    -- Therefore let's try simply renaming it from "empty" to "emptyXXX".
    -- As this stored function is only used in this one file, that should be easy?
    --   https://github.com/cyberitsolutions/alloc/blob/1.9.0/installation/db_triggers.sql#L31
    DELIMITER $$

    -- if (NOT something) doesn't work for NULLs
    DROP FUNCTION IF EXISTS emptyXXX $$
    CREATE FUNCTION emptyXXX(str text) RETURNS BOOLEAN DETERMINISTIC
    BEGIN RETURN str = '' OR str IS NULL; END $$

    DROP FUNCTION IF EXISTS get_most_recent_non_archived_taskStatus $$
    CREATE FUNCTION get_most_recent_non_archived_taskStatus(tID INTEGER) RETURNS varchar(255) READS SQL DATA
    BEGIN
      DECLARE rtn varchar(255);
      SELECT value INTO rtn FROM audit
       WHERE taskID = tID
         AND value != 'closed_archived'
         AND field = 'taskStatus'
    ORDER BY auditID DESC
       LIMIT 1;

      IF (emptyXXX(rtn)) THEN
        SELECT 'open_notstarted' INTO rtn;
      END IF;
      RETURN rtn;
    END
    $$

    DROP TRIGGER IF EXISTS before_insert_task $$
    CREATE TRIGGER before_insert_task BEFORE INSERT ON task
    FOR EACH ROW
    BEGIN
      DECLARE defTaskLimit DECIMAL(7,2);
      call check_edit_task(NEW.projectID);

      IF (NEW.parentTaskID) THEN CALL check_for_parent_task_loop(NEW.parentTaskID, NULL); END IF;

      SET NEW.creatorID = personID();
      SET NEW.dateCreated = current_timestamp();

      -- inserted closed edge-case
      IF (substring(NEW.taskStatus,1,6) = 'closed') THEN
        SET NEW.dateActualCompletion = current_date();
      END IF;

      IF (emptyXXX(NEW.taskStatus)) THEN SET NEW.taskStatus = 'open_notstarted'; END IF;
      IF (emptyXXX(NEW.priority)) THEN SET NEW.priority = 3; END IF;
      IF (emptyXXX(NEW.taskTypeID)) THEN SET NEW.taskTypeID = 'Task'; END IF;
      IF (NEW.personID) THEN SET NEW.dateAssigned = current_timestamp(); END IF;
      IF (NEW.closerID) THEN SET NEW.dateClosed = current_timestamp(); END IF;
      IF (emptyXXX(NEW.timeLimit)) THEN SET NEW.timeLimit = NEW.timeExpected; END IF;

      IF (emptyXXX(NEW.timeLimit) AND NEW.projectID) THEN
        SELECT defaultTaskLimit INTO defTaskLimit FROM project WHERE projectID = NEW.projectID;
        SET NEW.timeLimit = defTaskLimit;
      END IF;

      IF (emptyXXX(NEW.estimatorID) AND (NEW.timeWorst OR NEW.timeBest OR NEW.timeExpected)) THEN
        SET NEW.estimatorID = personID();
      END IF;

      IF (emptyXXX(NEW.timeWorst) AND emptyXXX(NEW.timeBest) AND emptyXXX(NEW.timeExpected)) THEN
        SET NEW.estimatorID = NULL;
      END IF;

      IF (NEW.taskStatus = 'open_inprogress' AND emptyXXX(NEW.dateActualStart)) THEN
        SET NEW.dateActualStart = current_date();
      END IF;
    END
    $$

    DROP TRIGGER IF EXISTS before_update_task $$
    CREATE TRIGGER before_update_task BEFORE UPDATE ON task
    FOR EACH ROW
    BEGIN
      call check_edit_task(OLD.projectID);

      IF (neq(@in_change_task_status,1) AND neq(OLD.taskStatus,NEW.taskStatus)) THEN
        call alloc_error('Must use: call change_task_status(taskID,status)');
      END IF;

      IF (NEW.parentTaskID) THEN CALL check_for_parent_task_loop(NEW.parentTaskID, OLD.taskID); END IF;

      SET NEW.taskID = OLD.taskID;
      SET NEW.creatorID = OLD.creatorID;
      SET NEW.dateCreated = OLD.dateCreated;
      SET NEW.taskModifiedUser = personID();

      IF (emptyXXX(NEW.taskStatus)) THEN
        SET NEW.taskStatus = OLD.taskStatus;
      END IF;

      IF (emptyXXX(NEW.taskStatus)) THEN
        SET NEW.taskStatus = 'open_notstarted';
      END IF;

      IF (NEW.taskStatus = 'open_inprogress' AND neq(NEW.taskStatus, OLD.taskStatus) AND emptyXXX(NEW.dateActualStart)) THEN
        SET NEW.dateActualStart = current_date();
      END IF;

      IF ((SUBSTRING(NEW.taskStatus,1,4) = 'open' OR SUBSTRING(NEW.taskStatus,1,4) = 'pend')) THEN
        SET NEW.closerID = NULL;
        SET NEW.dateClosed = NULL;
        SET NEW.dateActualCompletion = NULL;
        SET NEW.duplicateTaskID = NULL;
      ELSEIF (SUBSTRING(NEW.taskStatus,1,6) = 'closed' AND neq(NEW.taskStatus, OLD.taskStatus)) THEN
        IF (emptyXXX(NEW.dateActualStart)) THEN SET NEW.dateActualStart = current_date(); END IF;
        IF (emptyXXX(NEW.dateClosed)) THEN SET NEW.dateClosed = current_timestamp(); END IF;
        IF (emptyXXX(NEW.closerID)) THEN SET NEW.closerID = personID(); END IF;
        SET NEW.dateActualCompletion = current_date();
      END IF;

      IF (NEW.personID AND neq(NEW.personID, OLD.personID)) THEN
        SET NEW.dateAssigned = current_timestamp();
      ELSEIF (emptyXXX(NEW.personID)) THEN
        SET NEW.dateAssigned = NULL;
      END IF;

      IF (NEW.closerID AND neq(NEW.closerID, OLD.closerID)) THEN
        SET NEW.dateClosed = current_timestamp();
      ELSEIF (emptyXXX(NEW.closerID)) THEN
        SET NEW.dateClosed = NULL;
      END IF;

      IF ((neq(NEW.timeWorst, OLD.timeWorst) OR neq(NEW.timeBest, OLD.timeBest) OR neq(NEW.timeExpected, OLD.timeExpected))
      AND emptyXXX(NEW.estimatorID)) THEN
        SET NEW.estimatorID = personID();
      END IF;

      IF (emptyXXX(NEW.timeWorst) AND emptyXXX(NEW.timeBest) AND emptyXXX(NEW.timeExpected)) THEN
        SET NEW.estimatorID = NULL;
      END IF;

    END
    $$

    DROP TRIGGER IF EXISTS before_insert_absence $$
    CREATE TRIGGER before_insert_absence BEFORE INSERT ON absence
    FOR EACH ROW
    BEGIN
      IF emptyXXX(NEW.dateFrom) OR emptyXXX(NEW.dateTo) THEN
        call alloc_error('Absence must have a start and end date.');
      END IF;
    END
    $$

    DROP TRIGGER IF EXISTS before_update_absence $$
    CREATE TRIGGER before_update_absence BEFORE UPDATE ON absence
    FOR EACH ROW
    BEGIN
      IF emptyXXX(NEW.dateFrom) OR emptyXXX(NEW.dateTo) THEN
        call alloc_error('Absence must have a start and end date.');
      END IF;
    END
    $$

    DELIMITER ;

15:35 <twb> dropping 2 triggers manually and then re-running seems to have at least not errored.

    MariaDB [alloc]> DROP TRIGGER IF EXISTS before_update_task;
    Query OK, 0 rows affected (0.079 sec)

    MariaDB [alloc]> DROP TRIGGER IF EXISTS before_update_absence;
    Query OK, 0 rows affected (0.093 sec)

    twb@hera[Desktop]$ ssh root@heavy mariadb alloc < alloc_db_triggers_workaround_empty_problem.sql

15:36 <twb> OK I can create timesheets again!  Yay!
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

1 participant