Bonus-Transfer-Machines/machines/维修.py

351 lines
11 KiB
Python
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

import configparser
import pandas as pd
from sqlalchemy import create_engine
from urllib.parse import quote_plus
# 读取配置文件
config = configparser.ConfigParser()
config.read('config.ini')
# 获取数据库连接配置
source_config = {
'host': config.get('source_db', 'host'),
'user': config.get('source_db', 'user'),
'password': config.get('source_db', 'password'),
'database': config.get('source_db', 'database'),
'port': config.getint('source_db', 'port')
}
target_config = {
'host': config.get('target_db', 'host'),
'user': config.get('target_db', 'user'),
'password': config.get('target_db', 'password'),
'database': config.get('target_db', 'database'),
'port': config.getint('target_db', 'port')
}
# 创建数据库引擎
source_engine = create_engine(
f"mysql+pymysql://{source_config['user']}:{quote_plus(source_config['password'])}@{source_config['host']}:{source_config['port']}/{source_config['database']}?charset=utf8mb4"
)
target_engine = create_engine(
f"mysql+pymysql://{target_config['user']}:{quote_plus(target_config['password'])}@{target_config['host']}:{target_config['port']}/{target_config['database']}?charset=utf8mb4"
)
def safe_convert_to_int(series):
"""安全转换为整数"""
return pd.to_numeric(series, errors='coerce').fillna(0).astype(int)
def safe_convert_to_float(series):
"""安全转换为浮点数"""
return pd.to_numeric(series, errors='coerce').fillna(0.0)
def process_tm_task():
"""处理维修任务主表"""
try:
sql = """
SELECT
tt.ID as task_id,
4 as task_type,
IF(tt.`STATUS` = 6, 1, 0) AS task_status,
bmr.APPLY_NUMBER AS code,
bmr.CREATOR as create_by,
bmr.CREATE_TIME
FROM
ba_ma_repair bmr
LEFT JOIN tm_task tt on bmr.ID = tt.ID
LEFT JOIN tm_task_status tts on tt.`STATUS` = tts.`CODE`
WHERE bmr.company_id = 1
"""
df = pd.read_sql(sql, source_engine)
# 转换状态字段
df['task_status'] = safe_convert_to_int(df['task_status'])
df.to_sql('tm_task', target_engine, if_exists='append', index=False)
print(f"成功导入 {len(df)} 条维修任务主表数据")
return True
except Exception as e:
print(f"处理维修任务主表时出错: {str(e)}")
return False
def process_tm_task_agreement():
"""处理维修任务关联表"""
try:
sql = """
SELECT
bmr.ID as task_id,
bat.AGREEMENT_ID as agreement_id
FROM
ba_ma_repair bmr
LEFT JOIN ba_agreement_task bat on bmr.ID = bat.TASK_ID
WHERE bmr.company_id = 1
"""
df = pd.read_sql(sql, source_engine)
# 过滤空agreement_id
df = df.dropna(subset=['agreement_id'])
df.to_sql('tm_task_agreement', target_engine, if_exists='append', index=False)
print(f"成功导入 {len(df)} 条维修任务关联数据")
return True
except Exception as e:
print(f"处理维修任务关联表时出错: {str(e)}")
return False
def process_repair_apply_details():
"""处理维修申请明细(合并三个来源)"""
try:
# 来源1数量申请维修
sql1 = """
SELECT
bmr.ID as task_id,
ttmt.MA_TYPE_ID as type_id,
NULL as ma_id,
ttmt.MACHINES_NUM as repair_num,
ttmt.ACTUAL_NUM as repaired_num,
ttmt2.MACHINES_NUM as scrap_num,
ttmt.IS_SURE as status,
bmr.CREATOR as create_by,
bmr.CREATE_TIME,
bmr.BACK_ID as back_id,
IF(tt.`STATUS` = 6, 0, 1) AS is_ds
FROM
ba_ma_repair bmr
LEFT JOIN tm_task tt on bmr.ID = tt.ID
LEFT JOIN tm_task_ma_type ttmt on bmr.ID = ttmt.TASK_ID
LEFT JOIN ba_ma_scarp bms on bms.REPAIR_ID = bmr.ID
LEFT JOIN tm_task_ma_type ttmt2 on bms.ID = ttmt2.TASK_ID AND ttmt.MA_TYPE_ID = ttmt2.MA_TYPE_ID
WHERE ttmt.IS_COUNT = 1
GROUP BY ttmt.TASK_ID, ttmt.MA_TYPE_ID
"""
# 来源2编码申请维修
sql2 = """
SELECT
bmr.ID AS task_id,
mm.type AS type_id,
mm.ID AS ma_id,
1 AS repair_num,
IF
( tt.`STATUS` = 6, 1, 0 ) AS repaired_num,
0 AS scrap_num,
IF
( tt.`STATUS` = 6, 1, 0 ) AS status,
bmr.CREATOR AS create_by,
bmr.CREATE_TIME,
bmr.BACK_ID AS back_id,
IF
( tt.`STATUS` = 6, 0, 1 ) AS is_ds
FROM
ba_ma_repair_pass brp
LEFT JOIN ba_ma_repair bmr ON brp.repair_id = bmr.ID
LEFT JOIN tm_task tt ON bmr.ID = tt.ID
LEFT JOIN ma_machines mm ON brp.ma_id = mm.id
"""
# 来源3编码申请维修含报废
sql3 = """
SELECT
bmr.ID as task_id,
mm.type AS type_id,
tmsr.MA_ID as ma_id,
1 as repair_num,
0 as repaired_num,
1 as scrap_num,
1 as status,
bmr.CREATOR as create_by,
bmr.CREATE_TIME,
bmr.BACK_ID as back_id,
IF(tt.`STATUS` = 6, 0, 1) AS is_ds
FROM
ba_ma_scarp bms
LEFT JOIN ba_ma_repair bmr on bms.repair_id = bmr.ID
LEFT JOIN tm_task tt on bmr.ID = tt.ID
LEFT JOIN tm_ma_scarp_reason tmsr on bms.ID = tmsr.TASK_ID
LEFT JOIN ma_machines mm on tmsr.ma_id = mm.id
WHERE tmsr.IS_COUNT = 0
"""
# 合并三个来源的数据
df1 = pd.read_sql(sql1, source_engine)
df2 = pd.read_sql(sql2, source_engine)
df3 = pd.read_sql(sql3, source_engine)
df = pd.concat([df1, df2, df3], ignore_index=True)
# 转换数值字段
num_cols = ['repair_num', 'repaired_num', 'scrap_num', 'status', 'is_ds']
for col in num_cols:
df[col] = safe_convert_to_int(df[col])
df.to_sql('repair_apply_details', target_engine, if_exists='append', index=False)
print(f"成功导入 {len(df)} 条维修申请明细合并3个来源")
return True
except Exception as e:
print(f"处理维修申请明细时出错: {str(e)}")
return False
def process_repair_apply_record():
"""处理维修申请记录(合并四个来源)"""
try:
# 来源1数量维修合格
sql1 = """
SELECT
bmr.ID as task_id,
ttmt.MA_TYPE_ID as type_id,
NULL as ma_id,
ttmt.ACTUAL_NUM as repair_num,
0 as scrap_num,
ttmt.IS_SURE as status,
bmr.CREATOR as create_by,
IFNULL(bmr.REPAIR_TIME, bmr.CREATE_TIME) as create_time,
NULL as scrap_type,
NULL as scrap_reason
FROM
ba_ma_repair bmr
LEFT JOIN tm_task_ma_type ttmt on bmr.ID = ttmt.TASK_ID
LEFT JOIN ba_ma_scarp bms on bms.REPAIR_ID = bmr.ID
LEFT JOIN tm_task_ma_type ttmt2 on bms.ID = ttmt2.TASK_ID AND ttmt.MA_TYPE_ID = ttmt2.MA_TYPE_ID
WHERE ttmt.IS_COUNT = 1
GROUP BY ttmt.TASK_ID, ttmt.MA_TYPE_ID
HAVING repair_num > 0
"""
# 来源2数量维修报废
sql2 = """
SELECT
bmr.ID as task_id,
ttmt.MA_TYPE_ID as type_id,
NULL as ma_id,
0 as repair_num,
ttmt2.MACHINES_NUM as scrap_num,
ttmt.IS_SURE as status,
bmr.CREATOR as create_by,
bmr.REPAIR_TIME as create_time,
tmsr.DAMAGE as scrap_type,
tmsr.SCARP_REASON as scrap_reason
FROM
ba_ma_repair bmr
LEFT JOIN tm_task_ma_type ttmt on bmr.ID = ttmt.TASK_ID
LEFT JOIN ba_ma_scarp bms on bms.REPAIR_ID = bmr.ID
LEFT JOIN tm_ma_scarp_reason tmsr on bms.ID = tmsr.TASK_ID
LEFT JOIN tm_task_ma_type ttmt2 on bms.ID = ttmt2.TASK_ID AND ttmt.MA_TYPE_ID = ttmt2.MA_TYPE_ID
WHERE ttmt.IS_COUNT = 1
GROUP BY ttmt.TASK_ID, ttmt.MA_TYPE_ID
HAVING scrap_num > 0
"""
# 来源3编码维修合格
sql3 = """
SELECT
bmr.ID as task_id,
mm.type as type_id,
mm.ID as ma_id,
1 as repair_num,
0 as scrap_num,
1 as status,
bmr.CREATOR as create_by,
bmr.REPAIR_TIME as create_time,
NULL as scrap_type,
NULL as scrap_reason
FROM
ba_ma_repair_pass brp
LEFT JOIN ba_ma_repair bmr on brp.repair_id = bmr.ID
LEFT JOIN ma_machines mm on brp.ma_id = mm.id
"""
# 来源4编码维修报废
sql4 = """
SELECT
bmr.ID as task_id,
mm.type as type_id,
tmsr.MA_ID as ma_id,
0 as repair_num,
1 as scrap_num,
1 as status,
bmr.CREATOR as create_by,
bmr.REPAIR_TIME as create_time,
tmsr.DAMAGE as scrap_type,
tmsr.SCARP_REASON as scrap_reason
FROM
ba_ma_scarp bms
LEFT JOIN ba_ma_repair bmr on bms.repair_id = bmr.ID
LEFT JOIN tm_ma_scarp_reason tmsr on bms.ID = tmsr.TASK_ID
LEFT JOIN ma_machines mm on tmsr.ma_id = mm.id
WHERE tmsr.IS_COUNT = 0
"""
# 合并四个来源的数据
df1 = pd.read_sql(sql1, source_engine)
df2 = pd.read_sql(sql2, source_engine)
df3 = pd.read_sql(sql3, source_engine)
df4 = pd.read_sql(sql4, source_engine)
df = pd.concat([df1, df2, df3, df4], ignore_index=True)
# 转换数值字段
num_cols = ['repair_num', 'scrap_num', 'status']
for col in num_cols:
df[col] = safe_convert_to_int(df[col])
df.to_sql('repair_apply_record', target_engine, if_exists='append', index=False)
print(f"成功导入 {len(df)} 条维修申请记录合并4个来源")
return True
except Exception as e:
print(f"处理维修申请记录时出错: {str(e)}")
return False
def process_repair_cost():
"""处理维修费用"""
try:
sql = """
SELECT
rp.TASK_ID as task_id,
rp.MA_TYPE_ID as type_id,
rp.MA_ID as ma_id,
rp.REPAIR_NUM as repair_num,
rp.PRICE as costs,
rp.IS_BUCKLE as part_type,
1 as status
FROM
repair_part rp
LEFT JOIN ba_ma_repair bmr on rp.TASK_ID = bmr.ID
"""
df = pd.read_sql(sql, source_engine)
# 转换数值字段
df['repair_num'] = safe_convert_to_int(df['repair_num'])
df['costs'] = safe_convert_to_float(df['costs'])
df['part_type'] = safe_convert_to_int(df['part_type'])
df['status'] = safe_convert_to_int(df['status'])
df.to_sql('repair_cost', target_engine, if_exists='append', index=False)
print(f"成功导入 {len(df)} 条维修费用记录")
return True
except Exception as e:
print(f"处理维修费用时出错: {str(e)}")
return False
if __name__ == "__main__":
# 执行所有转换流程
processes = [
process_tm_task,
process_tm_task_agreement,
process_repair_apply_details,
process_repair_apply_record,
process_repair_cost
]
success = all([p() for p in processes])
if success:
print("所有维修相关表转换完成!")
else:
print("!!! 部分转换失败,请检查错误日志 !!!")