diff --git a/Service/Ammeter/EmeterEnergyChangeService.cs b/Service/Ammeter/EmeterEnergyChangeService.cs index 6cc4527..a8e09dd 100644 --- a/Service/Ammeter/EmeterEnergyChangeService.cs +++ b/Service/Ammeter/EmeterEnergyChangeService.cs @@ -16,20 +16,44 @@ public class EmeterEnergyChangeService : BaseServices public async Task> SevenDaysElectrical() { + // 根据code分组,取最近7天数据,每天最大值-最小值=当日用电量,如果当天目前只有一条数据,取当天最大值-前一天最大值=当天耗电量 string sql = @" + WITH daily_max_min AS ( + SELECT + `code`, + DATE(`upload_time`) AS `UploadTime`, + MAX(`value`) AS `MaxValue`, + MIN(`value`) AS `MinValue` + FROM + `emeter_energy_change` + WHERE + `upload_time` >= NOW() - INTERVAL 8 DAY + GROUP BY + `code`, DATE(`upload_time`) + ), previous_day_max AS ( + SELECT + `code`, + `UploadTime`, + LAG(`MaxValue`) OVER (PARTITION BY `code` ORDER BY `UploadTime`) AS `PreviousMaxValue` + FROM + daily_max_min + ) SELECT - code, - date(upload_time) AS UploadTime, - MAX(value) - MIN(value) AS Value + d.`code`, + d.`UploadTime`, + CASE + WHEN d.`MaxValue` = d.`MinValue` THEN COALESCE(d.`MaxValue` - p.`PreviousMaxValue`, d.`MaxValue`) + ELSE d.`MaxValue` - d.`MinValue` + END AS `Value` FROM - emeter_energy_change + daily_max_min d + LEFT JOIN + previous_day_max p ON d.`code` = p.`code` AND d.`UploadTime` = p.`UploadTime` WHERE - upload_time >= NOW() - INTERVAL 7 DAY - GROUP BY - code, date(upload_time) + d.`UploadTime` >= NOW() - INTERVAL 7 DAY ORDER BY - code, date(upload_time); -"; + d.`code`, d.`UploadTime`; + "; List emeterEnergies = await _emeterEnergyChangeRep.SqlQueryable(sql); return emeterEnergies; @@ -55,19 +79,41 @@ public class EmeterEnergyChangeService : BaseServices public async Task> GetTodayHourlyElectricalData() { string sql = @" - SELECT - code, - DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00') AS Hour, - MAX(value) - MIN(value) AS Value - FROM - emeter_energy_change - WHERE - DATE(upload_time) = CURDATE() - GROUP BY - code, DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00') - ORDER BY - code, Hour; - "; + WITH hourly_max_min AS ( + SELECT + `code`, + DATE_FORMAT(`upload_time`, '%Y-%m-%d %H:00:00') AS `Hour`, + MAX(`value`) AS `MaxValue`, + MIN(`value`) AS `MinValue`, + COUNT(*) AS `record_count` + FROM + `emeter_energy_change` + WHERE + DATE(`upload_time`) = CURDATE() + GROUP BY + `code`, DATE_FORMAT(`upload_time`, '%Y-%m-%d %H:00:00') + ), previous_hour_max AS ( + SELECT + `code`, + `Hour`, + LAG(`MaxValue`) OVER (PARTITION BY `code` ORDER BY `Hour`) AS `PreviousMaxValue` + FROM + `hourly_max_min` + ) + SELECT + h.`code`, + h.`Hour`, + CASE + WHEN h.`record_count` > 1 THEN h.`MaxValue` - h.`MinValue` + ELSE h.`MaxValue` - COALESCE(p.`PreviousMaxValue`, 0) + END AS `Value` + FROM + `hourly_max_min` h + LEFT JOIN + `previous_hour_max` p ON h.`code` = p.`code` AND h.`Hour` = p.`Hour` + ORDER BY + h.`code`, h.`Hour`; + "; List emeterEnergies = await _emeterEnergyChangeRep.SqlQueryable(sql); return emeterEnergies; } diff --git a/Service/Ammeter/EmeterEnergyService.cs b/Service/Ammeter/EmeterEnergyService.cs index 37f0578..2dc786b 100644 --- a/Service/Ammeter/EmeterEnergyService.cs +++ b/Service/Ammeter/EmeterEnergyService.cs @@ -20,19 +20,43 @@ public class EmeterEnergyService : BaseServices /// public async Task> SevenDaysElectrical() { + // 根据code分组,取最近7天数据,每天最大值-最小值=当日用电量,如果当天目前只有一条数据,取当天最大值-前一天最大值=当天耗电量 string sql = @" + WITH daily_max_min AS ( SELECT - code, - date(upload_time) AS UploadTime, - MAX(value) - MIN(value) AS Value + `code`, + DATE(`upload_time`) AS `UploadTime`, + MAX(`value`) AS `MaxValue`, + MIN(`value`) AS `MinValue` FROM - emeter_energy + `emeter_energy` WHERE - upload_time >= NOW() - INTERVAL 7 DAY + `upload_time` >= NOW() - INTERVAL 8 DAY GROUP BY - code, date(upload_time) - ORDER BY - code, date(upload_time); + `code`, DATE(`upload_time`) + ), previous_day_max AS ( + SELECT + `code`, + `UploadTime`, + LAG(`MaxValue`) OVER (PARTITION BY `code` ORDER BY `UploadTime`) AS `PreviousMaxValue` + FROM + daily_max_min + ) + SELECT + d.`code`, + d.`UploadTime`, + CASE + WHEN d.`MaxValue` = d.`MinValue` THEN COALESCE(d.`MaxValue` - p.`PreviousMaxValue`, d.`MaxValue`) + ELSE d.`MaxValue` - d.`MinValue` + END AS `Value` + FROM + daily_max_min d + LEFT JOIN + previous_day_max p ON d.`code` = p.`code` AND d.`UploadTime` = p.`UploadTime` + WHERE + d.`UploadTime` >= NOW() - INTERVAL 7 DAY + ORDER BY + d.`code`, d.`UploadTime`; "; List emeterEnergies = await this.BaseDal.SqlQueryable(sql); return emeterEnergies; @@ -67,19 +91,41 @@ public class EmeterEnergyService : BaseServices public async Task> GetTodayHourlyElectricalData() { string sql = @" - SELECT - code, - DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00') AS Hour, - MAX(value) - MIN(value) AS Value - FROM - emeter_energy - WHERE - DATE(upload_time) = CURDATE() - GROUP BY - code, DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00') - ORDER BY - code, Hour; - "; + WITH hourly_max_min AS ( + SELECT + `code`, + DATE_FORMAT(`upload_time`, '%Y-%m-%d %H:00:00') AS `Hour`, + MAX(`value`) AS `MaxValue`, + MIN(`value`) AS `MinValue`, + COUNT(*) AS `record_count` + FROM + `emeter_energy` + WHERE + DATE(`upload_time`) = CURDATE() + GROUP BY + `code`, DATE_FORMAT(`upload_time`, '%Y-%m-%d %H:00:00') + ), previous_hour_max AS ( + SELECT + `code`, + `Hour`, + LAG(`MaxValue`) OVER (PARTITION BY `code` ORDER BY `Hour`) AS `PreviousMaxValue` + FROM + `hourly_max_min` + ) + SELECT + h.`code`, + h.`Hour`, + CASE + WHEN h.`record_count` > 1 THEN h.`MaxValue` - h.`MinValue` + ELSE h.`MaxValue` - COALESCE(p.`PreviousMaxValue`, 0) + END AS `Value` + FROM + `hourly_max_min` h + LEFT JOIN + `previous_hour_max` p ON h.`code` = p.`code` AND h.`Hour` = p.`Hour` + ORDER BY + h.`code`, h.`Hour`; + "; List emeterEnergies = await this.BaseDal.SqlQueryable(sql); return emeterEnergies;