fix: enp drain2serializer sql查询优化

This commit is contained in:
caoqianming 2024-04-17 11:18:15 +08:00
parent fdc7ceff8d
commit 92bf0ac29e
2 changed files with 62 additions and 63 deletions

View File

@ -6,6 +6,7 @@ from rest_framework import serializers
from django.utils import timezone
from datetime import datetime
from apps.utils.sql import query_all_dict
from apps.enp.sql import duration_hour_one_equip
class DrainSerializer(CustomModelSerializer):
@ -38,72 +39,27 @@ class Drain2Serializer(CustomModelSerializer):
today = str(now)[:10] + " 00:00:00"
today_last = str(now)[:10] + " 23:59:59"
odata = equips.values("id", "name", "type", "running_state")
eids = [f"'{e['id']}'" for e in odata]
eids_str = ",".join(eids)
sql_str = f"""
SELECT
equipment_id,
AVG ( tsp ) AS avg_tsp,
SUM ( duration_online ) AS total_duration_online,
SUM ( duration_run ) AS total_duration_run,
SUM ( duration_standby ) AS total_duration_standby,
MAX ( last_running_state ) AS last_running_state
FROM
(
SELECT
equipment_id,
tsp,
running_state,
CASE
WHEN running_state != 50 THEN
TIME - LAG ( TIME ) OVER ( PARTITION BY equipment_id ORDER BY TIME ) ELSE'0'
END AS duration_online,
CASE
WHEN running_state = 10 THEN
TIME - LAG ( TIME ) OVER ( PARTITION BY equipment_id ORDER BY TIME ) ELSE'0'
END AS duration_run,
CASE
WHEN running_state in (20, 30, 40) THEN
TIME - LAG ( TIME ) OVER ( PARTITION BY equipment_id ORDER BY TIME ) ELSE'0'
END AS duration_standby,
CASE
WHEN ROW_NUMBER ( ) OVER ( PARTITION BY equipment_id ORDER BY TIME DESC ) = 1 THEN
running_state ELSE NULL
END AS last_running_state
FROM
enp_envdata
WHERE
TIMEX >= '{today}' -- 替换成想查询的开始时间
AND TIMEX <= '{today_last}' -- 替换成想查询的结束时间
AND equipment_id IN ( {eids_str} )
) AS durations
GROUP BY
equipment_id;
"""
res = query_all_dict(sql_str)
data = {}
for i in res:
data[i["equipment_id"]] = i
# eids = [f"'{e['id']}'" for e in odata]
# eids_str = ",".join(eids)
for i in odata:
i.update(
data.get(
i["id"],
{
"avg_tsp": None,
"total_duration_online": 0,
"total_duration_run": 0,
"total_duration_standby": 0,
"last_running_state": 50,
},
)
"duration_offline": 0,
"duration_run": 0,
"duration_stop": 0,
}
)
equipment_id = i["id"]
sql_str = duration_hour_one_equip.format(equipment_id=equipment_id, start_time=today, end_time=today_last)
res = query_all_dict(sql_str)
# data = {}
# for i in res:
# data[i["equipment_id"]] = i
# for i in odata:
if res:
i.update(res[0])
return odata

43
apps/enp/sql.py Normal file
View File

@ -0,0 +1,43 @@
# 一些sql语句
duration_hour_one_equip = """
WITH time_data AS (
SELECT
TO_CHAR( G.TIMEX, 'YYYY-MM-DD HH24:MI:SS' ) AS TIMEX
FROM
generate_series ( '{start_time}' :: TIMESTAMP, '{end_time}' :: TIMESTAMP, '1 minute' ) G ( TIMEX )
),
ev_data AS (
SELECT
TO_CHAR( time_bucket ( '1 minute', TIMEX ) AT TIME ZONE'Asia/Shanghai', 'YYYY-MM-DD HH24:MI:SS' ) AS timex,
MAX ( running_state ) AS running_state,
AVG ( tsp ) AS avg_tsp
FROM
enp_envdata envdata
WHERE
envdata.equipment_id = '{equipment_id}'
AND envdata.TIMEX AT TIME ZONE'Asia/Shanghai' >= '{start_time}'
AND envdata.TIMEX AT TIME ZONE'Asia/Shanghai' <= '{end_time}'
GROUP BY
time_bucket ( '1 minute', TIMEX ) AT TIME ZONE'Asia/Shanghai'
ORDER BY
timex
),
state_d AS (
SELECT
avg_tsp,
COALESCE
( ed.running_state, 50 ) AS running_state
FROM
time_data td
LEFT JOIN ev_data ed ON ed.timex = td.timex
ORDER BY
td.timex
) SELECT
ROUND( cast(AVG ( avg_tsp ) as numeric), 4) AS avg_tsp,
ROUND( SUM ( CASE WHEN running_state = 10 THEN 1 ELSE 0 END ) / 60.0, 2 ) AS duration_run,
ROUND( SUM ( CASE WHEN running_state = 30 THEN 1 ELSE 0 END ) / 60.0, 2 ) AS duration_stop,
ROUND( SUM ( CASE WHEN running_state = 50 THEN 1 ELSE 0 END ) / 60.0, 2 ) AS duration_offline
FROM
state_d;
"""