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

Feat: add aggregate cost center table #5885

Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
18 changes: 18 additions & 0 deletions server/models/admin.sql
Original file line number Diff line number Diff line change
Expand Up @@ -260,5 +260,23 @@ CREATE PROCEDURE zMergeDepots(
DELETE FROM depot WHERE uuid = _old_uuid;
END$$

/*
zRecalculateCostCenterAggregates

Removes all data from the cost_center_aggregate table and rebuilds it.
*/
CREATE PROCEDURE zRecalculateCostCenterAggregates()
BEGIN

-- wipe the cost_center_aggregate table
DELETE FROM cost_center_aggregate;

-- regenerate
INSERT INTO cost_center_aggregate (period_id, credit, debit, cost_center_id, principal_center_id)
SELECT period_id, SUM(credit_equiv) AS credit, SUM(debit_equiv) AS debit, cost_center_id, principal_center_id
FROM general_ledger
WHERE cost_center_id IS NOT NULL
GROUP BY cost_center_id, principal_center_id, period_id;
END $$

DELIMITER ;
35 changes: 35 additions & 0 deletions server/models/migrations/next/migrate.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
/* migrate v1.21.0 to next */

/**
author: @jniles
date: 2021-08-30
description: adds cost columns and indices to relevant tables
*/

DROP TABLE IF EXISTS `cost_center_aggregate`;
CREATE TABLE `cost_center_aggregate` (
`period_id` MEDIUMINT(8) UNSIGNED NOT NULL,
`debit` DECIMAL(19,4) UNSIGNED NOT NULL DEFAULT 0.00,
`credit` DECIMAL(19,4) UNSIGNED NOT NULL DEFAULT 0.00,
`cost_center_id` MEDIUMINT(8) UNSIGNED NOT NULL,
`principal_center_id` MEDIUMINT(8) UNSIGNED NULL,
KEY `cost_center_id` (`cost_center_id`),
KEY `principal_center_id` (`principal_center_id`),
KEY `period_id` (`period_id`),
CONSTRAINT `cost_center_aggregate__period` FOREIGN KEY (`period_id`) REFERENCES `period` (`id`),
CONSTRAINT `cost_center_aggregate__cost_center_id` FOREIGN KEY (`cost_center_id`) REFERENCES `fee_center` (`id`),
CONSTRAINT `cost_center_aggregate__principal_center_id` FOREIGN KEY (`principal_center_id`) REFERENCES `fee_center` (`id`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;

CALL add_column_if_missing('posting_journal', 'cost_center_id', 'MEDIUMINT(8) UNSIGNED NULL');
CALL add_column_if_missing('posting_journal', 'principal_center_id', 'MEDIUMINT(8) UNSIGNED NULL');

ALTER TABLE `posting_journal` ADD CONSTRAINT `pg__cost_center_1` FOREIGN KEY (`cost_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE;
ALTER TABLE `posting_journal` ADD CONSTRAINT `pg__cost_center_2` FOREIGN KEY (`principal_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE;


CALL add_column_if_missing('general_ledger', 'cost_center_id', 'MEDIUMINT(8) UNSIGNED NULL');
CALL add_column_if_missing('general_ledger', 'principal_center_id', 'MEDIUMINT(8) UNSIGNED NULL');

ALTER TABLE `general_ledger` ADD CONSTRAINT `general_ledger__cost_center_1` FOREIGN KEY (`cost_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE;
ALTER TABLE `general_ledger` ADD CONSTRAINT `general_ledger__cost_center_2` FOREIGN KEY (`principal_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE;
44 changes: 36 additions & 8 deletions server/models/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -528,10 +528,10 @@ CREATE TABLE `employee` (
KEY `creditor_uuid` (`creditor_uuid`),
KEY `grade_uuid` (`grade_uuid`),
KEY `patient_uuid` (`patient_uuid`),
CONSTRAINT `employee__fonction` FOREIGN KEY (`fonction_id`) REFERENCES `fonction` (`id`),
CONSTRAINT `employee__service` FOREIGN KEY (`service_uuid`) REFERENCES `service` (`uuid`),
CONSTRAINT `employee__creditor` FOREIGN KEY (`creditor_uuid`) REFERENCES `creditor` (`uuid`),
CONSTRAINT `employee__grade` FOREIGN KEY (`grade_uuid`) REFERENCES `grade` (`uuid`),
CONSTRAINT `employee__fonction` FOREIGN KEY (`fonction_id`) REFERENCES `fonction` (`id`),
CONSTRAINT `employee__service` FOREIGN KEY (`service_uuid`) REFERENCES `service` (`uuid`),
CONSTRAINT `employee__creditor` FOREIGN KEY (`creditor_uuid`) REFERENCES `creditor` (`uuid`),
CONSTRAINT `employee__grade` FOREIGN KEY (`grade_uuid`) REFERENCES `grade` (`uuid`),
CONSTRAINT `employee__patient` FOREIGN KEY (`patient_uuid`) REFERENCES `patient` (`uuid`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;

Expand Down Expand Up @@ -666,8 +666,10 @@ CREATE TABLE `general_ledger` (
`entity_uuid` BINARY(16),
`reference_uuid` BINARY(16),
`comment` TEXT,
`transaction_type_id` TINYINT(3) UNSIGNED NULL,
`user_id` SMALLINT(5) UNSIGNED NOT NULL,
`transaction_type_id` TINYINT(3) UNSIGNED NULL,
`user_id` SMALLINT(5) UNSIGNED NOT NULL,
`cost_center_id` MEDIUMINT(8) UNSIGNED NULL,
`principal_center_id` MEDIUMINT(8) UNSIGNED NULL,
`created_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`updated_at` TIMESTAMP NULL ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`uuid`),
Expand All @@ -676,6 +678,8 @@ CREATE TABLE `general_ledger` (
KEY `period_id` (`period_id`),
KEY `currency_id` (`currency_id`),
KEY `user_id` (`user_id`),
KEY `cost_center_id` (`cost_center_id`),
KEY `principal_center_id` (`principal_center_id`),
jmcameron marked this conversation as resolved.
Show resolved Hide resolved
INDEX `trans_date` (`trans_date`),
INDEX `trans_id` (`trans_id`),
INDEX `record_uuid` (`record_uuid`),
Expand All @@ -688,7 +692,9 @@ CREATE TABLE `general_ledger` (
CONSTRAINT `general_ledger__project` FOREIGN KEY (`project_id`) REFERENCES `project` (`id`) ON UPDATE CASCADE,
CONSTRAINT `general_ledger__currency` FOREIGN KEY (`currency_id`) REFERENCES `currency` (`id`) ON UPDATE CASCADE,
CONSTRAINT `general_ledger__account` FOREIGN KEY (`account_id`) REFERENCES `account` (`id`),
CONSTRAINT `general_ledger__user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ON UPDATE CASCADE
CONSTRAINT `general_ledger__user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ON UPDATE CASCADE,
CONSTRAINT `general_ledger__cost_center_1` FOREIGN KEY (`cost_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE,
CONSTRAINT `general_ledger__cost_center_2` FOREIGN KEY (`principal_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;


Expand Down Expand Up @@ -1307,6 +1313,8 @@ CREATE TABLE `posting_journal` (
`comment` TEXT,
`transaction_type_id` TINYINT(3) UNSIGNED NULL,
`user_id` SMALLINT(5) UNSIGNED NOT NULL,
`cost_center_id` MEDIUMINT(8) UNSIGNED NULL,
`principal_center_id` MEDIUMINT(8) UNSIGNED NULL,
`created_at` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`updated_at` TIMESTAMP NULL ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`uuid`),
Expand All @@ -1315,6 +1323,8 @@ CREATE TABLE `posting_journal` (
KEY `period_id` (`period_id`),
KEY `currency_id` (`currency_id`),
KEY `user_id` (`user_id`),
KEY `cost_center_id` (`cost_center_id`),
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Will it be possible to rename this property fee_center_id or cost_profit_center_id

KEY `principal_center_id` (`principal_center_id`),
INDEX `trans_date` (`trans_date`),
INDEX `trans_id` (`trans_id`),
INDEX `record_uuid` (`record_uuid`),
Expand All @@ -1327,7 +1337,9 @@ CREATE TABLE `posting_journal` (
CONSTRAINT `pg__project` FOREIGN KEY (`project_id`) REFERENCES `project` (`id`) ON UPDATE CASCADE,
CONSTRAINT `pg__account` FOREIGN KEY (`account_id`) REFERENCES `account` (`id`),
CONSTRAINT `pg__currency` FOREIGN KEY (`currency_id`) REFERENCES `currency` (`id`) ON UPDATE CASCADE,
CONSTRAINT `pg__user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ON UPDATE CASCADE
CONSTRAINT `pg__user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ON UPDATE CASCADE,
CONSTRAINT `pg__cost_center_1` FOREIGN KEY (`cost_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE,
CONSTRAINT `pg__cost_center_2` FOREIGN KEY (`principal_center_id`) REFERENCES `fee_center` (`id`) ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;

DROP TABLE IF EXISTS `project`;
Expand Down Expand Up @@ -2561,4 +2573,20 @@ CREATE TABLE `configuration_analysis_tools` (
CONSTRAINT `config_analysis_tools__analysis_tool_type` FOREIGN KEY (`analysis_tool_type_id`) REFERENCES `analysis_tool_type` (`id`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;


DROP TABLE IF EXISTS `cost_center_aggregate`;
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Will it be possible to rename this table fee_center_aggregate or cost_profit_center_aggregate, Just because this way it will make it look like this table is not about profit centers

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I was implementing the proposal from #5861. I think in English, all off the fee centers are called cost centers. But I could be wrong.

@jmcameron has read more of the documentation than i have. @jmcameron do you have a thought on what the best name is?

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Let's wait for his feedback

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@jmcameron has read more of the documentation than i have. @jmcameron do you have a thought on what the best name is?

I suggest "Cost Centers" for all services and cost/profit centers. In a sense this is appropriate: All services or centers have costs. Some centers can generate revenue. These are usually also called revenue centers. But they are still cost centers. Regarding the "Adminstration" center at IMCK: This should probably be split up into a Registration Service which could be treated as revenue center. But Administration is normally a cost center NOT a revenue center.

The term "Cost Center" is not explicitly used in the "Essentials of Healthcare Finance" book (we have its chapter 13). But "Cost Center" is used in the "Annex B" handbook. AND "Cost Center" is used in the list of things Larry wants us to do. So he uses this terminology. So I encourage us to use "Cost Center" as the general term for all services/cost/profit/revenue centers.

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

image
Centre de frais = Cost Center

CREATE TABLE `cost_center_aggregate` (
`period_id` MEDIUMINT(8) UNSIGNED NOT NULL,
jmcameron marked this conversation as resolved.
Show resolved Hide resolved
`debit` DECIMAL(19,4) UNSIGNED NOT NULL DEFAULT 0.00,
`credit` DECIMAL(19,4) UNSIGNED NOT NULL DEFAULT 0.00,
`cost_center_id` MEDIUMINT(8) UNSIGNED NOT NULL,
`principal_center_id` MEDIUMINT(8) UNSIGNED NULL,
KEY `cost_center_id` (`cost_center_id`),
KEY `principal_center_id` (`principal_center_id`),
KEY `period_id` (`period_id`),
CONSTRAINT `cost_center_aggregate__period` FOREIGN KEY (`period_id`) REFERENCES `period` (`id`),
CONSTRAINT `cost_center_aggregate__cost_center_id` FOREIGN KEY (`cost_center_id`) REFERENCES `fee_center` (`id`),
CONSTRAINT `cost_center_aggregate__principal_center_id` FOREIGN KEY (`principal_center_id`) REFERENCES `fee_center` (`id`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;

SET foreign_key_checks = 1;