电表统计sql优化

master
tq 6 months ago
parent 3965906566
commit 57dd51bfae

@ -16,20 +16,44 @@ public class EmeterEnergyChangeService : BaseServices<EmeterEnergyChange>
public async Task<List<EmeterEnergyChange>> 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_change
`emeter_energy_change`
WHERE
upload_time >= NOW() - INTERVAL 7 DAY
`upload_time` >= NOW() - INTERVAL 8 DAY
GROUP 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
code, date(upload_time);
";
d.`code`, d.`UploadTime`;
";
List<EmeterEnergyChange> emeterEnergies = await _emeterEnergyChangeRep.SqlQueryable(sql);
return emeterEnergies;
@ -55,18 +79,40 @@ public class EmeterEnergyChangeService : BaseServices<EmeterEnergyChange>
public async Task<List<EmeterEnergyChange>> GetTodayHourlyElectricalData()
{
string sql = @"
WITH hourly_max_min AS (
SELECT
code,
DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00') AS Hour,
MAX(value) - MIN(value) AS Value
`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
`emeter_energy_change`
WHERE
DATE(upload_time) = CURDATE()
DATE(`upload_time`) = CURDATE()
GROUP BY
code, DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00')
`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
code, Hour;
h.`code`, h.`Hour`;
";
List<EmeterEnergyChange> emeterEnergies = await _emeterEnergyChangeRep.SqlQueryable(sql);
return emeterEnergies;

@ -20,19 +20,43 @@ public class EmeterEnergyService : BaseServices<EmeterEnergy>
/// <returns></returns>
public async Task<List<EmeterEnergy>> 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)
`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
code, date(upload_time);
d.`code`, d.`UploadTime`;
";
List<EmeterEnergy> emeterEnergies = await this.BaseDal.SqlQueryable(sql);
return emeterEnergies;
@ -67,18 +91,40 @@ public class EmeterEnergyService : BaseServices<EmeterEnergy>
public async Task<List<EmeterEnergy>> GetTodayHourlyElectricalData()
{
string sql = @"
WITH hourly_max_min AS (
SELECT
code,
DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00') AS Hour,
MAX(value) - MIN(value) AS Value
`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
`emeter_energy`
WHERE
DATE(upload_time) = CURDATE()
DATE(`upload_time`) = CURDATE()
GROUP BY
code, DATE_FORMAT(upload_time, '%Y-%m-%d %H:00:00')
`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
code, Hour;
h.`code`, h.`Hour`;
";
List<EmeterEnergy> emeterEnergies = await this.BaseDal.SqlQueryable(sql);

Loading…
Cancel
Save