const { columns } = require("mssql"); const pool = require("../config"); const getHistoryAlarmDb = async (searchParams = {}) => { let queryParams = []; if (searchParams.limit) { const page = Number(searchParams.page ?? 1) - 1; queryParams = [Number(searchParams.limit ?? 10), page]; } const { whereOrConditions, whereParamOr } = pool.buildStringOrIlike( [ "b.tag_name", "a.tagnum" ], searchParams.criteria, queryParams ); if (whereParamOr) queryParams = whereParamOr; const { whereConditions, whereParamAnd } = pool.buildFilterQuery( [ { column: "b.tag_name", param: searchParams.name, type: "string" }, { column: "b.tag_number", param: searchParams.name, type: "number" }, ], queryParams ); if (whereParamAnd) queryParams = whereParamAnd; const queryText = ` SELECT COUNT(*) OVER() AS total_data, a.*, b.tag_name, b.tag_number, b.lim_low_crash, b.lim_low, b.lim_high, b.lim_high_crash, c.status_color FROM alarm_history a LEFT JOIN m_tags b ON a.tagnum = b.tag_number AND b.deleted_at IS NULL LEFT JOIN m_status c ON a.status = c.status_number AND c.deleted_at IS NULL WHERE a.datetime IS NOT NULL ${whereConditions.length > 0 ? ` AND ${whereConditions.join(" AND ")}` : ""} ${whereOrConditions ? ` ${whereOrConditions}` : ""} ORDER BY a.datetime DESC ${searchParams.limit ? `OFFSET $2 * $1 ROWS FETCH NEXT $1 ROWS ONLY` : ''} `; const result = await pool.query(queryText, queryParams); const total = result?.recordset?.length > 0 ? parseInt(result.recordset[0].total_data, 10) : 0; return { data: result.recordset, total }; }; const getHistoryEventDb = async (searchParams = {}) => { let queryParams = []; if (searchParams.limit) { const page = Number(searchParams.page ?? 1) - 1; queryParams = [Number(searchParams.limit ?? 10), page]; } const { whereOrConditions, whereParamOr } = pool.buildStringOrIlike( [ "b.tag_name", "a.tagnum" ], searchParams.criteria, queryParams ); if (whereParamOr) queryParams = whereParamOr; const { whereConditions, whereParamAnd } = pool.buildFilterQuery( [ { column: "b.tag_name", param: searchParams.name, type: "string" }, { column: "b.tag_number", param: searchParams.name, type: "number" }, ], queryParams ); if (whereParamAnd) queryParams = whereParamAnd; const queryText = ` SELECT COUNT(*) OVER() AS total_data, a.*, c.status_color FROM event_alarm a LEFT JOIN m_status c ON a.status = c.status_number AND c.deleted_at IS NULL WHERE a.datetime IS NOT NULL ${whereConditions.length > 0 ? ` AND ${whereConditions.join(" AND ")}` : ""} ${whereOrConditions ? ` ${whereOrConditions}` : ""} ORDER BY a.datetime DESC ${searchParams.limit ? `OFFSET $2 * $1 ROWS FETCH NEXT $1 ROWS ONLY` : ''} `; const result = await pool.query(queryText, queryParams); const total = result?.recordset?.length > 0 ? parseInt(result.recordset[0].total_data, 10) : 0; return { data: result.recordset, total }; }; const checkTableNamedDb = async (tableName) => { const queryText = ` SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = $1;`; const result = await pool.query(queryText, [tableName]); return result.recordset; }; const getHistoryValueReportDb = async (tableName, searchParams = {}) => { let queryParams = []; if (searchParams.limit) { const page = Number(searchParams.page ?? 1) - 1; queryParams = [Number(searchParams.limit ?? 10), page]; } const { whereOrConditions, whereParamOr } = pool.buildStringOrIlike( [ "b.tag_name", "a.tagnum" ], searchParams.criteria, queryParams ); if (whereParamOr) queryParams = whereParamOr; const { whereConditions, whereParamAnd } = pool.buildFilterQuery( [ { column: "b.tag_name", param: searchParams.name, type: "string" }, { column: "b.tag_number", param: searchParams.name, type: "number" }, { column: "a.datetime", param: [searchParams.from, searchParams.to], type: "between" }, ], queryParams ); if (whereParamAnd) queryParams = whereParamAnd; const queryText = ` SELECT COUNT(*) OVER() AS total_data, a.*, b.tag_name, b.tag_number, b.lim_low_crash, b.lim_low, b.lim_high, b.lim_high_crash, c.status_color FROM ${tableName} a LEFT JOIN m_tags b ON a.tagnum = b.tag_number AND b.deleted_at IS NULL LEFT JOIN m_status c ON a.status = c.status_number AND c.deleted_at IS NULL WHERE a.datetime IS NOT NULL AND b.is_report = 1 ${whereConditions.length > 0 ? ` AND ${whereConditions.join(" AND ")}` : ""} ${whereOrConditions ? ` ${whereOrConditions}` : ""} ORDER BY a.datetime DESC ${searchParams.limit ? `OFFSET $2 * $1 ROWS FETCH NEXT $1 ROWS ONLY` : ''} `; const result = await pool.query(queryText, queryParams); const total = result?.recordset?.length > 0 ? parseInt(result.recordset[0].total_data, 10) : 0; return { data: result.recordset, total }; }; const getHistoryValueReportPivotDb = async (tableName, searchParams = {}) => { let from = searchParams.from; let to = searchParams.to; const interval = Number(searchParams.interval ?? 10); // menit const limit = Number(searchParams.limit ?? 10); const page = Number(searchParams.page ?? 1); // --- Normalisasi tanggal if (from.length === 10) from += ' 00:00:00'; if (to.length === 10) to += ' 23:59:59'; // --- Ambil semua tag yang di-report const tags = await pool.query(` SELECT tag_name FROM m_tags WHERE is_report = 1 AND deleted_at IS NULL `); if (tags.recordset.length === 0) { return { data: [], total: 0 }; } const tagNames = tags.recordset.map(r => `[${r.tag_name}]`).join(', '); const tagNamesColumn = tags.recordset.map(r => `${r.tag_name}`).join(', '); // --- Query utama const queryText = ` DECLARE @fromParam DATETIME = '${from}', @toParam DATETIME = '${to}', @intervalParam INT = ${interval}; ;WITH TimeSeries AS ( SELECT @fromParam AS waktu UNION ALL SELECT DATEADD(MINUTE, @intervalParam, waktu) FROM TimeSeries WHERE DATEADD(MINUTE, @intervalParam, waktu) <= @toParam ), Averaged AS ( SELECT DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CAST(a.datetime AS DATETIME)) / @intervalParam * @intervalParam, 0) AS waktu_group, b.tag_name, ROUND(AVG(a.val), 4) AS avg_val FROM ${tableName} a LEFT JOIN m_tags b ON a.tagnum = b.tag_number AND b.deleted_at IS NULL WHERE a.datetime BETWEEN @fromParam AND @toParam GROUP BY DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CAST(a.datetime AS DATETIME)) / @intervalParam * @intervalParam, 0), b.tag_name ), Pivoted AS ( SELECT waktu_group, ${tagNames} FROM Averaged PIVOT ( MAX(avg_val) FOR tag_name IN (${tagNames}) ) AS p ), FinalResult AS ( SELECT CONVERT(VARCHAR(16), ts.waktu, 120) AS datetime, ${tagNames} FROM TimeSeries ts LEFT JOIN Pivoted p ON ts.waktu = p.waktu_group ) SELECT COUNT(*) OVER() AS total_data, * FROM FinalResult ORDER BY datetime ${searchParams.limit ? `OFFSET ${(page - 1) * limit} ROWS FETCH NEXT ${limit} ROWS ONLY` : ''} OPTION (MAXRECURSION 0); `; const result = await pool.query(queryText); const total = result?.recordset?.length > 0 ? parseInt(result.recordset[0].total_data, 10) : 0; return { data: result.recordset, column: tagNamesColumn, total }; }; const getHistoryValueTrendingPivotDb = async (tableName, searchParams = {}) => { let from = searchParams.from; let to = searchParams.to; // pastikan interval berupa number dan ada nilai default const interval = Number(searchParams.interval) > 0 ? Number(searchParams.interval) : 10; // --- Normalisasi tanggal (kalau cuma tanggal tanpa jam) if (from.length === 10) from += ' 00:00:00'; if (to.length === 10) to += ' 23:59:59'; // --- Ambil semua tag yang di-report const tags = await pool.query(` SELECT tag_name FROM m_tags WHERE is_report = 1 AND deleted_at IS NULL `); if (tags.recordset.length === 0) { return { data: [] }; } const tagNames = tags.recordset.map(r => `[${r.tag_name}]`).join(', '); const queryText = ` DECLARE @fromParam DATETIME = '${from}', @toParam DATETIME = '${to}', @intervalParam INT = ${interval}; ;WITH TimeSeries AS ( SELECT @fromParam AS waktu UNION ALL SELECT DATEADD(MINUTE, @intervalParam, waktu) FROM TimeSeries WHERE DATEADD(MINUTE, @intervalParam, waktu) <= @toParam ), Averaged AS ( SELECT DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CAST(a.datetime AS DATETIME)) / @intervalParam * @intervalParam, 0) AS waktu_group, b.tag_name, ROUND(AVG(a.val), 4) AS avg_val FROM ${tableName} a LEFT JOIN m_tags b ON a.tagnum = b.tag_number AND b.deleted_at IS NULL WHERE a.datetime BETWEEN @fromParam AND @toParam GROUP BY DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CAST(a.datetime AS DATETIME)) / @intervalParam * @intervalParam, 0), b.tag_name ), Pivoted AS ( SELECT waktu_group, ${tagNames} FROM Averaged PIVOT ( MAX(avg_val) FOR tag_name IN (${tagNames}) ) AS p ) SELECT CONVERT(VARCHAR(16), ts.waktu, 120) AS waktu, ${tagNames} FROM TimeSeries ts LEFT JOIN Pivoted p ON ts.waktu = p.waktu_group ORDER BY ts.waktu OPTION (MAXRECURSION 0); `; const result = await pool.query(queryText); const rows = result.recordset; if (!rows || rows.length === 0) return { data: [] }; // --- Bentuk data untuk Nivo Chart const timeKey = 'waktu'; const tagList = Object.keys(rows[0]).filter(k => k !== timeKey); const nivoData = tagList.map(tag => ({ id: tag, data: rows.map(row => ({ x: row[timeKey], y: row[tag] !== null ? Number(row[tag]) : null })) })); return { data: nivoData }; }; module.exports = { getHistoryAlarmDb, getHistoryEventDb, checkTableNamedDb, getHistoryValueReportDb, getHistoryValueReportPivotDb, getHistoryValueTrendingPivotDb };