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.

234 lines
7.1 KiB

using Entity.Ammeter;
using Entity.Api.Resp;
using HybirdFrameworkCore.Autofac.Attribute;
6 months ago
using Microsoft.Data.SqlClient;
using Repository.Ammeter;
using SqlSugar;
namespace Service.Ammeter;
[Scope("SingleInstance")]
public class EmeterEnergyService : BaseServices<EmeterEnergy>
{
public EmeterEnergyService(EmeterEnergyRepository service)
{
this.BaseDal = service;
}
/// <summary>
/// 获取七天用电量
/// </summary>
/// <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`) AS `MaxValue`,
MIN(`value`) AS `MinValue`,
COUNT(*) AS `Count`
FROM
`emeter_energy`
WHERE
`upload_time` >= NOW() - INTERVAL 8 DAY
GROUP BY
`code`, DATE(`upload_time`)
), previous_day_max AS (
SELECT
`code`,
`UploadTime`,
`MaxValue`,
`MinValue`,
`Count`,
LAG(`MaxValue`) OVER (PARTITION BY `code` ORDER BY `UploadTime`) AS `PreviousMaxValue`
FROM
daily_max_min
), daily_consumption AS (
SELECT
d.`code`,
d.`UploadTime`,
CASE
6 months ago
WHEN d.`Count` > 1 THEN d.`MaxValue` - d.`MinValue`
WHEN d.`Count` = 1 AND d.`PreviousMaxValue` IS NOT NULL THEN d.`MaxValue` - d.`PreviousMaxValue`
ELSE 0
END AS `DailyValue`
FROM
previous_day_max d
WHERE
d.`UploadTime` >= NOW() - INTERVAL 7 DAY
)
SELECT
`UploadTime`,
SUM(`DailyValue`) AS `Value`
FROM
daily_consumption
GROUP BY
`UploadTime`
ORDER BY
`UploadTime`;
6 months ago
";
List<EmeterEnergy> emeterEnergies = await this.BaseDal.SqlQueryable(sql);
return emeterEnergies;
}
/// <summary>
/// 获取全部用电量
/// </summary>
/// <returns></returns>
public async Task<List<EmeterEnergy>> GetAllElectricalData()
{
string sql = @"
SELECT
code,
MAX(value) - MIN(value) AS Value
FROM
emeter_energy
6 months ago
WHERE
upload_time >= DATE_SUB(NOW(), INTERVAL 1 MONTH)
GROUP BY
code
ORDER BY
code;
6 months ago
";
List<EmeterEnergy> emeterEnergies = await this.BaseDal.SqlQueryable(sql);
return emeterEnergies;
}
/// <summary>
/// 根据小时统计电量
/// </summary>
/// <returns></returns>
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`) 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<EmeterEnergy> emeterEnergies = await this.BaseDal.SqlQueryable(sql);
return emeterEnergies;
}
/// <summary>
/// 根据分钟统计电量
/// </summary>
/// <returns></returns>
public async Task<List<EmeterEnergy>> GetTodayMinutelyElectricalData()
{
string sql = @"
WITH minute_max_min AS (
SELECT
`code`,
DATE_FORMAT(`upload_time`, '%Y-%m-%d %H:%i:00') AS `Minute`,
MAX(`value`) AS `MaxValue`,
MIN(`value`) AS `MinValue`,
COUNT(*) AS `record_count`
FROM
`emeter_energy`
WHERE
`upload_time` >= NOW() - INTERVAL 1 HOUR
GROUP BY
`code`, DATE_FORMAT(`upload_time`, '%Y-%m-%d %H:%i:00')
), previous_minute_max AS (
SELECT
`code`,
`Minute`,
LAG(`MaxValue`) OVER (PARTITION BY `code` ORDER BY `Minute`) AS `PreviousMaxValue`
FROM
`minute_max_min`
)
SELECT
m.`code`,
m.`Minute`,
CASE
WHEN m.`record_count` > 1 THEN m.`MaxValue` - m.`MinValue`
6 months ago
WHEN p.`PreviousMaxValue` IS NULL THEN 0
ELSE m.`MaxValue` - p.`PreviousMaxValue`
END AS `Value`
FROM
`minute_max_min` m
LEFT JOIN
`previous_minute_max` p ON m.`code` = p.`code` AND m.`Minute` = p.`Minute`
ORDER BY
6 months ago
m.`code`, m.`Minute`;
";
List<EmeterEnergy> emeterEnergies = await this.BaseDal.SqlQueryable(sql);
return emeterEnergies;
}
/// <summary>
/// 获取直流电表实时数据
/// </summary>
/// <returns></returns>
6 months ago
public async Task<List<EmeterEnergy>> GetEnergyMeterRealTime(string endTime)
{
6 months ago
// 将传入的时间参数转换为DateTime类型
DateTime endDateTime = DateTime.Parse(endTime);
// 根据传入的时间参数计算7天前的时间
6 months ago
DateTime startDateTime = endDateTime.AddMinutes(-1);
6 months ago
// 根据code分组,取最新时间的一条数据,数据范围7天
string sql = @"
6 months ago
SELECT t1.*
FROM emeter_energy t1
JOIN (
SELECT code, MAX(upload_time) as latest_upload_time
FROM emeter_energy
WHERE upload_time >= @StartDateTime AND upload_time <= @EndDateTime
GROUP BY code
) t2 ON t1.code = t2.code AND t1.upload_time = t2.latest_upload_time
WHERE t1.upload_time >= @StartDateTime AND t1.upload_time <= @EndDateTime;
";
6 months ago
// 使用参数化查询防止SQL注入
var parameters = new List<SugarParameter>
{
new SugarParameter("@StartDateTime", startDateTime),
new SugarParameter("@EndDateTime", endDateTime)
};
List<EmeterEnergy> emeterEnergies = this.BaseDal.SqlQuery(sql, parameters);
return emeterEnergies;
}
}