Consider the following schema:
CREATE TABLE IF NOT EXISTS `numbers` ( `number` int(20) UNSIGNED NOT NULL AUTO_INCREMENT, UNIQUE KEY `number` (`number`) ) ENGINE=MyISAM AUTO_INCREMENT=8 DEFAULT CHARSET=utf8; INSERT INTO `numbers` (`number`) VALUES (1), (2), (3), (4), (5), (6), (7); CREATE VIEW `calendar_3_months` AS select date_format((curdate() + interval (-(`numbers`.`number`) + 1) month),'%Y-%m') AS `date` from `numbers` limit 3 ; CREATE TABLE IF NOT EXISTS `investments` ( `id` int(11) UNSIGNED NOT NULL AUTO_INCREMENT, `uuid` char(36) NOT NULL, `name` varchar(64) NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `uuid` (`uuid`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; INSERT INTO `investments` (`id`, `uuid`, `name`) VALUES (1, 'f684a5a0-0c42-11e9-b39f-00163e2daa7c', 'Dom'), (2, 'f200018c-0c43-11e9-b39f-00163e2daa7c', 'Dom2'); CREATE TABLE IF NOT EXISTS `schedules` ( `id` int(10) UNSIGNED NOT NULL AUTO_INCREMENT, `uuid` char(36) NOT NULL, `id_investment` int(10) UNSIGNED NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `uuid` (`uuid`), KEY `id_investment` (`id_investment`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; INSERT INTO `schedules` (`id`, `uuid`, `id_investment`) VALUES (1, 'f684c2d2-0c42-11e9-b39f-00163e2daa7c', 1), (2, 'f2018aeb-0c43-11e9-b39f-00163e2daa7c', 2); CREATE TABLE IF NOT EXISTS `schedule_items` ( `id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT, `id_schedule` int(10) UNSIGNED NOT NULL, `uuid` char(36) NOT NULL, `name` varchar(128) CHARACTER SET utf8mb4 NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `uuid` (`uuid`), KEY `id_schedule` (`id_schedule`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; INSERT INTO `schedule_items` (`id`, `id_schedule`, `uuid`, `name`) VALUES (1, 1, 'f684e067-0c42-11e9-b39f-00163e2daa7c', ''), (2, 1, 'f684ed90-0c42-11e9-b39f-00163e2daa7c', 'I. Stan zerowy'), (3, 1, 'f685bc4f-0c42-11e9-b39f-00163e2daa7c', 'Roboty ziemne'), (4, 1, 'f685d614-0c42-11e9-b39f-00163e2daa7c', 'Fundamenty'), (5, 1, 'f6868511-0c42-11e9-b39f-00163e2daa7c', 'Izolacje'), (6, 2, 'f201a5a7-0c43-11e9-b39f-00163e2daa7c', ''), (7, 2, 'f203bfe5-0c43-11e9-b39f-00163e2daa7c', 'II. Stan surowy zamknięty'), (8, 2, 'f2048a51-0c43-11e9-b39f-00163e2daa7c', 'Ściany konstrukcyjne'), (9, 2, 'f204a3fa-0c43-11e9-b39f-00163e2daa7c', 'Stropy i kominy'), (10, 2, 'f204c0ff-0c43-11e9-b39f-00163e2daa7c', 'Schody'), (11, 2, 'f204ebd5-0c43-11e9-b39f-00163e2daa7c', 'Ściany działowe'); CREATE TABLE IF NOT EXISTS `expenses` ( `id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT, `uuid` char(36) NOT NULL, `price` decimal(12,2) NOT NULL, `name` varchar(128) CHARACTER SET utf8mb4 NOT NULL, `creation_time` datetime NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `uuid` (`uuid`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; INSERT INTO `expenses` (`id`, `uuid`, `price`, `name`, `creation_time`) VALUES (1, 'b0701faf-0ffd-11e9-b39f-00163e2daa7c', '122.00', 'dokumentacja', '2019-11-04 09:49:47'), (2, '480fcc4b-11bd-11e9-befe-00163e2daa7c', '2000.00', 'koparka', '2019-07-06 15:13:46'), (3, '081a5d1f-129a-11e9-befe-00163e2daa7c', '3500.00', 'beton', '2019-12-07 17:33:58'), (4, 'f7e93abd-1501-11e9-befe-00163e2daa7c', '7430.00', 'pustaki', '2020-01-10 19:03:00'), (5, '38c310a1-1900-11e9-befe-00163e2daa7c', '1750.00', 'piasek', '2020-01-15 21:00:35'), (6, '09e39ee1-1b1a-11e9-b1e6-00163e2daa7c', '11600.00', 'dachowka', '2019-10-18 13:10:26'), (7, '1c196498-5c77-11e9-92a6-00163e2daa7c', '22036.94', 'cegly', '2019-09-11 18:30:25'), (8, 'ee8255a9-5c77-11e9-92a6-00163e2daa7c', '5300.00', 'beton b20', '2019-08-11 18:36:18'), (9, '3141fd72-5c8a-11e9-92a6-00163e2daa7c', '10509.30', 'podsypka', '2019-11-11 20:47:01'), (10, '510f9ee1-5c8a-11e9-92a6-00163e2daa7c', '1083.96', 'pcv', '2019-12-11 20:47:54'); CREATE TABLE IF NOT EXISTS `schedule_expenses` ( `id_expense` bigint(20) UNSIGNED NOT NULL, `id_item` bigint(20) UNSIGNED NOT NULL, KEY `id_expense` (`id_expense`), KEY `id_schedule` (`id_item`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; INSERT INTO `schedule_expenses` (`id_expense`, `id_item`) VALUES (1, 1), (2, 2), (3, 2), (4, 1), (5, 8), (7, 3), (7, 3), (7, 1), (7, 9), (10, 9);
I need to come up with single SQL query, that will produce something like this
date | investment ID | total --------------------------------- 2020-01 | 1 | 0 2019-12 | 1 | 1000.00 2019-11 | 1 | 0 2020-01 | 2 | 750.00 2019-12 | 2 | 14345.67 2019-11 | 2 | 0 2020-01 | ... | ... 2019-12 | ... | ... 2019-11 | ... | ...
Date must include 3 last months and should be dynamic (when query is executed in Jan 2020, it includes Jan 2020, Dec 2019 and Nov 2019; if in Aug 2020, it should include June, July and August 2020). In general, query should a report about sum of all expenses per investment within last 3 months, including months without any expenses.
Description of tables being involved: Investments – stores information about investments, like houses, apartments being built; Schedules – Each investment follows specific schedule Schedule_Items – Schedule elements Expenses – stores information about expenses Schedule_expenses – relation table between expenses and schedule items
What I did so far: I created a view called ‘calendar_3_months’ that contains dynamic values, always 3 last months, formatted like: “%Y-%m”. I came up with a query that produces almost expected result (incorrect ‘total’ values). I tried different joints but they are not giving me a desired outcome. The best I came up with was:
SELECT `date` as `calendar_date`, `investments`.`id`, COALESCE(sum(`expenses`.`price`), 0) as `total` FROM (`investments`, `calendar_3_months`) inner join `schedules` on `schedules`.`id_investment` = `investments`.`id` inner join `schedule_items` on `schedule_items`.`id_schedule` = `schedules`.`id` left join `schedule_expenses` ON `schedule_expenses`.`id_item` = `schedule_items`.`id` left join `expenses` ON `schedule_expenses`.`id_expense` = `expenses`.`id` GROUP BY `calendar_date`, `investments`.`id` ORDER BY `investments`.`id`
http://sqlfiddle.com/#!9/5e2f3f/1
Please let me know the direction of changes to get this done?
Advertisement
Answer
If your problem is the missing 0
row, then this includes it:
SELECT c.date as calendar_date, i.id, COALESCE(sum(e.price), 0) as `total` FROM investments i CROSS JOIN calendar_3_months c LEFT JOIN schedules s ON s.id_investment = i.id LEFT JOIN schedule_items si ON si.id_schedule = s.id LEFT JOIN schedule_expenses se ON se.id_item = si.id LEFT JOIN expenses e ON se.id_expense = e.id AND DATE_FORMAT(e.creation_time, '%Y-%m') = c.date GROUP BY calendar_date, i.id ORDER BY i.id, calendar_date;
Here is a SQL Fiddle.