You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

create.mysql.db.sql 5.6KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157
  1. -- database_script.sql
  2. USE `{{DB_NAME}}`;
  3. -- Drop and create database if it does not exist
  4. DROP DATABASE IF EXISTS globaltempDB;
  5. CREATE DATABASE IF NOT EXISTS globaltempDB;
  6. USE `{{DB_NAME}}`;
  7. DROP PROCEDURE IF EXISTS nextsequence;
  8. DELIMITER //
  9. CREATE PROCEDURE nextsequence(
  10. IN sequencenames VARCHAR(255),
  11. IN node BINARY(16),
  12. IN cluster BINARY(16)
  13. )
  14. BEGIN
  15. DECLARE _next TEXT DEFAULT NULL;
  16. DECLARE _nextlen INT DEFAULT NULL;
  17. DECLARE _value TEXT DEFAULT NULL;
  18. DECLARE EXIT HANDLER FOR SQLEXCEPTION
  19. BEGIN
  20. SHOW ERRORS;
  21. ROLLBACK;
  22. END;
  23. START TRANSACTION;
  24. IF (sequencenames IS null OR TRIM(sequencenames) = '') THEN
  25. SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Either a table name or a sequence name is required.';
  26. END IF;
  27. SET @database = (SELECT DATABASE());
  28. iterator:
  29. LOOP
  30. IF CHAR_LENGTH(TRIM(sequencenames)) = 0 OR sequencenames IS NULL THEN
  31. LEAVE iterator;
  32. END IF;
  33. SET _next = SUBSTRING_INDEX(sequencenames, ',', 1);
  34. SET _nextlen = CHAR_LENGTH(_next);
  35. SET @sequencename = TRIM(_next);
  36. SET sequencenames = INSERT(sequencenames, 1, _nextlen + 1, '');
  37. SET @SQL = CONCAT('SELECT EXISTS(SELECT table_name FROM INFORMATION_SCHEMA.TABLES WHERE table_name LIKE ''', @sequencename, ''' AND table_schema = ''globaltempdb'') INTO @e');
  38. PREPARE stmt FROM @SQL;
  39. EXECUTE stmt;
  40. DEALLOCATE PREPARE stmt;
  41. IF @e = 0 THEN
  42. SET @SQL = CONCAT('CREATE TABLE globaltempDB.', @sequencename, ' ( ', @sequencename, 'iId bigint not null, ', @sequencename, 'CiId bigint null, seq_db VARCHAR(50) not null )');
  43. PREPARE stmt FROM @SQL;
  44. EXECUTE stmt;
  45. DEALLOCATE PREPARE stmt;
  46. SET @SQL = CONCAT('INSERT globaltempDB.', @sequencename, ' (', @sequencename, 'iId, ', @sequencename, 'CiId, seq_db) VALUES(0, 0, ''', @database , ''')');
  47. PREPARE stmt FROM @SQL;
  48. EXECUTE stmt;
  49. DEALLOCATE PREPARE stmt;
  50. END IF;
  51. SET @SQL = CONCAT('UPDATE globaltempDB.', @sequencename, ' SET ', @sequencename, 'iId = LAST_INSERT_ID(', @sequencename, 'iId + 1)');
  52. PREPARE stmt FROM @SQL;
  53. EXECUTE stmt;
  54. DEALLOCATE PREPARE stmt;
  55. SET @SQL = CONCAT('SELECT LAST_INSERT_ID() AS ', @sequencename, 'iId, null AS ', @sequencename, 'CiId');
  56. PREPARE stmt FROM @SQL;
  57. EXECUTE stmt;
  58. DEALLOCATE PREPARE stmt;
  59. END LOOP;
  60. COMMIT;
  61. END //
  62. DELIMITER ;
  63. -- Repeat for the second stored procedure 'receivablerequest'
  64. USE `{{DB_NAME}}`;
  65. DROP PROCEDURE IF EXISTS receivablerequest;
  66. DELIMITER //
  67. CREATE PROCEDURE receivablerequest(
  68. IN `PERIOD` INT
  69. )
  70. BEGIN
  71. SET @PERIOD = 1;
  72. SET @BOD = (SELECT CONVERT_TZ(UTC_DATE(), @@session.time_zone, '+00:00'));
  73. SET @PBEGIN = (SELECT DATE_SUB(@BOD, INTERVAL DAYOFMONTH(@BOD) DAY));
  74. SET @PEND = (SELECT DATE_ADD(DATE_SUB(@BOD, INTERVAL DAYOFMONTH(@BOD) DAY), INTERVAL 1 MONTH));
  75. SELECT `receivablerequest`.`receivablerequestId`,
  76. `receivablerequest`.`comments`,
  77. `receivablerequest`.`from`,
  78. `receivablerequest`.`to`,
  79. `receivablerequest`.`quantity`,
  80. `receivablerequest`.`v1receivablerequestId`,
  81. `receivablerequest`.`receivablerequestCiId`,
  82. `receivablerequest`.`receivablerequestns`,
  83. `receivablerequest`.`receivablerequestiId`,
  84. `receivablerequest`.`datecreated`,
  85. `receivablerequest`.`timestamp`,
  86. `receivablerequest`.`migrationstate`,
  87. `receivablerequest`.`datemodified`,
  88. `receivablerequest`.`requestedbyId`,
  89. `receivablerequest`.`departmentId`,
  90. `receivablerequest`.`itemId`,
  91. `receivablerequest`.`receivablerequestnumber`,
  92. `statechange`.`state`
  93. FROM `receivablerequest`
  94. INNER JOIN statechange ON statechange.statechangeforId = `receivablerequest`.`receivablerequestId`
  95. WHERE `receivablerequest`.from >= @PBEGIN AND `receivablerequest`.from < @PEND
  96. UNION ALL
  97. SELECT uuid() AS `receivablerequestId`,
  98. 'system request for period' AS `comments`,
  99. CONVERT(@PBEGIN, DATETIME) AS `from`,
  100. CONVERT(@PEND , DATETIME) AS `to`,
  101. CASE WHEN consumption.qty IS NULL THEN item.max ELSE consumption.qty END AS `quantity`,
  102. NULL AS `v1receivablerequestId`,
  103. NULL AS `receivablerequestCiId`,
  104. 'sys_auto' AS `receivablerequestns`,
  105. NULL AS `receivablerequestiId`,
  106. UTC_TIMESTAMP() AS `datecreated`,
  107. UTC_TIMESTAMP() AS `timestamp`,
  108. 8 AS `migrationstate`,
  109. UTC_TIMESTAMP() AS `datemodified`,
  110. NULL AS `requestedbyId`,
  111. NULL AS `departmentId`,
  112. `item`.`itemId`,
  113. NULL AS `receivablerequestnumber`,
  114. 'yet to order' AS `state`
  115. FROM item
  116. LEFT JOIN (
  117. SELECT AVG(saleitem.quantity) AS qty, receiveditem.itemId, department.departmentId
  118. FROM saleitem
  119. INNER JOIN receiveditem ON saleitem.billableId = receiveditem.receiveditemId
  120. INNER JOIN encounter ON encounter.encounterId = saleitem.encounterId
  121. INNER JOIN department ON encounter.departmentId = department.departmentId
  122. GROUP BY departmentId
  123. ) consumption ON item.itemId = `consumption`.`itemId`
  124. LEFT JOIN (
  125. SELECT itemId FROM receivablerequest
  126. INNER JOIN statechange ON statechange.statechangeforId = receivablerequest.receivablerequestId
  127. WHERE receivablerequest.datecreated >= @PBEGIN AND receivablerequest.datecreated < @PEND
  128. ) requested ON requested.itemId = item.itemId
  129. WHERE requested.itemId IS NULL;
  130. END //
  131. DELIMITER ;