repair: change readers to users
This commit is contained in:
@@ -4,53 +4,102 @@ const { setResponsePaging } = require('../helpers/utils');
|
||||
class HistoryValueController {
|
||||
|
||||
static async getAllHistoryAlarm(req, res) {
|
||||
const queryParams = req.query;
|
||||
try {
|
||||
const queryParams = req.query;
|
||||
|
||||
const results = await HistoryValue.getAllHistoryAlarm(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
const results = await HistoryValue.getAllHistoryAlarm(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
|
||||
res.status(response.statusCode).json(response);
|
||||
res.status(response.statusCode).json(response);
|
||||
} catch (error) {
|
||||
const statusCode = error.statusCode || 500;
|
||||
res.status(statusCode).json({
|
||||
success: false,
|
||||
statusCode,
|
||||
message: error.message || 'Internal server error'
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
static async getAllHistoryEvent(req, res) {
|
||||
const queryParams = req.query;
|
||||
try {
|
||||
const queryParams = req.query;
|
||||
|
||||
const results = await HistoryValue.getAllHistoryEvent(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
const results = await HistoryValue.getAllHistoryEvent(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
|
||||
res.status(response.statusCode).json(response);
|
||||
res.status(response.statusCode).json(response);
|
||||
} catch (error) {
|
||||
const statusCode = error.statusCode || 500;
|
||||
res.status(statusCode).json({
|
||||
success: false,
|
||||
statusCode,
|
||||
message: error.message || 'Internal server error'
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
static async getHistoryValueReport(req, res) {
|
||||
const queryParams = req.query;
|
||||
try {
|
||||
const queryParams = req.query;
|
||||
|
||||
const results = await HistoryValue.getHistoryValueReport(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
const results = await HistoryValue.getHistoryValueReport(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
|
||||
res.status(response.statusCode).json(response);
|
||||
res.status(response.statusCode).json(response);
|
||||
} catch (error) {
|
||||
const statusCode = error.statusCode || 500;
|
||||
res.status(statusCode).json({
|
||||
success: false,
|
||||
statusCode,
|
||||
message: error.message || 'Internal server error'
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
static async getHistoryValueReportPivot(req, res) {
|
||||
const queryParams = req.query;
|
||||
try {
|
||||
const queryParams = req.query;
|
||||
|
||||
const results = await HistoryValue.getHistoryValueReportPivot(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
const results = await HistoryValue.getHistoryValueReportPivot(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
|
||||
response.columns = results.column
|
||||
if (results.column) {
|
||||
response.columns = results.column;
|
||||
}
|
||||
|
||||
res.status(response.statusCode).json(response);
|
||||
res.status(response.statusCode).json(response);
|
||||
} catch (error) {
|
||||
const statusCode = error.statusCode || 500;
|
||||
res.status(statusCode).json({
|
||||
success: false,
|
||||
statusCode,
|
||||
message: error.message || 'Internal server error'
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
static async getHistoryValueTrendingPivot(req, res) {
|
||||
const queryParams = req.query;
|
||||
try {
|
||||
const queryParams = req.query;
|
||||
|
||||
const results = await HistoryValue.getHistoryValueTrendingPivot(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
const results = await HistoryValue.getHistoryValueTrendingPivot(queryParams);
|
||||
const response = await setResponsePaging(queryParams, results, 'Data found');
|
||||
|
||||
response.columns = results.column
|
||||
if (results.column) {
|
||||
response.columns = results.column;
|
||||
}
|
||||
|
||||
res.status(response.statusCode).json(response);
|
||||
res.status(response.statusCode).json(response);
|
||||
} catch (error) {
|
||||
const statusCode = error.statusCode || 500;
|
||||
res.status(statusCode).json({
|
||||
success: false,
|
||||
statusCode,
|
||||
message: error.message || 'Internal server error'
|
||||
});
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
module.exports = HistoryValueController;
|
||||
module.exports = HistoryValueController;
|
||||
@@ -115,160 +115,321 @@ const getHistoryEventDb = async (searchParams = {}) => {
|
||||
};
|
||||
|
||||
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;
|
||||
try {
|
||||
if (!tableName || !/^[a-zA-Z0-9_]+$/.test(tableName)) {
|
||||
throw new Error('Invalid table name format');
|
||||
}
|
||||
|
||||
const queryText = `
|
||||
SELECT TABLE_NAME, TABLE_SCHEMA, TABLE_TYPE
|
||||
FROM INFORMATION_SCHEMA.TABLES
|
||||
WHERE TABLE_NAME = $1
|
||||
`;
|
||||
|
||||
const result = await pool.query(queryText, [tableName]);
|
||||
return result.recordset;
|
||||
} catch (error) {
|
||||
console.error('Error in checkTableNamedDb:', error);
|
||||
throw error;
|
||||
}
|
||||
};
|
||||
|
||||
const getHistoryValueReportDb = async (tableName, searchParams = {}) => {
|
||||
let queryParams = [];
|
||||
try {
|
||||
if (!tableName || !/^[a-zA-Z0-9_]+$/.test(tableName)) {
|
||||
throw new Error('Invalid table name format');
|
||||
}
|
||||
|
||||
if (searchParams.limit) {
|
||||
const page = Number(searchParams.page ?? 1) - 1;
|
||||
queryParams = [Number(searchParams.limit ?? 10), page];
|
||||
}
|
||||
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
|
||||
);
|
||||
const { whereOrConditions, whereParamOr } = pool.buildStringOrIlike(
|
||||
["b.tag_name", "CAST(a.tagnum AS VARCHAR)"],
|
||||
searchParams.criteria,
|
||||
queryParams
|
||||
);
|
||||
|
||||
if (whereParamOr) queryParams = whereParamOr;
|
||||
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
|
||||
);
|
||||
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;
|
||||
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 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 result = await pool.query(queryText, queryParams);
|
||||
|
||||
const total =
|
||||
result?.recordset?.length > 0
|
||||
const total = result.recordset?.length > 0
|
||||
? parseInt(result.recordset[0].total_data, 10)
|
||||
: 0;
|
||||
|
||||
return { data: result.recordset, total };
|
||||
return { data: result.recordset, total };
|
||||
} catch (error) {
|
||||
console.error('Error in getHistoryValueReportDb:', error);
|
||||
throw error;
|
||||
}
|
||||
};
|
||||
|
||||
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);
|
||||
try {
|
||||
if (!tableName || !/^[a-zA-Z0-9_]+$/.test(tableName)) {
|
||||
throw new Error('Invalid table name format');
|
||||
}
|
||||
|
||||
// --- Normalisasi tanggal
|
||||
if (from.length === 10) from += ' 00:00:00';
|
||||
if (to.length === 10) to += ' 23:59:59';
|
||||
let from = searchParams.from || '';
|
||||
let to = searchParams.to || '';
|
||||
const interval = Math.max(1, Math.min(1440, Number(searchParams.interval ?? 10)));
|
||||
|
||||
// --- 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 (from.length === 10 && /^\d{4}-\d{2}-\d{2}$/.test(from)) {
|
||||
from += ' 00:00:00';
|
||||
}
|
||||
if (to.length === 10 && /^\d{4}-\d{2}-\d{2}$/.test(to)) {
|
||||
to += ' 23:59:59';
|
||||
}
|
||||
|
||||
if (tags.recordset.length === 0) {
|
||||
return { data: [], total: 0 };
|
||||
console.log('Table:', tableName);
|
||||
console.log('From:', from, '| To:', to, '| Interval:', interval);
|
||||
console.log('Filters:', searchParams);
|
||||
|
||||
const dateRegex = /^\d{4}-\d{2}-\d{2} \d{2}:\d{2}:\d{2}$/;
|
||||
if (!dateRegex.test(from) || !dateRegex.test(to)) {
|
||||
throw new Error('Invalid date format. Expected: YYYY-MM-DD or YYYY-MM-DD HH:MM:SS');
|
||||
}
|
||||
|
||||
const fromDate = new Date(from);
|
||||
const toDate = new Date(to);
|
||||
const daysDiff = (toDate - fromDate) / (1000 * 60 * 60 * 24);
|
||||
|
||||
if (daysDiff > 365) {
|
||||
throw new Error('Date range cannot exceed 1 year');
|
||||
}
|
||||
if (daysDiff < 0) {
|
||||
throw new Error('From date must be before to date');
|
||||
}
|
||||
|
||||
let tagQueryParams = [];
|
||||
let tagWhereConditions = [];
|
||||
|
||||
if (searchParams.plant_sub_section_id) {
|
||||
tagWhereConditions.push(`plant_sub_section_id = $${tagQueryParams.length + 1}`);
|
||||
tagQueryParams.push(searchParams.plant_sub_section_id);
|
||||
}
|
||||
|
||||
if (searchParams.plant_section_id) {
|
||||
tagWhereConditions.push(`plant_section_id = $${tagQueryParams.length + 1}`);
|
||||
tagQueryParams.push(searchParams.plant_section_id);
|
||||
}
|
||||
|
||||
if (searchParams.name) {
|
||||
const nameFilter = `(tag_name LIKE $${tagQueryParams.length + 1} OR CAST(tag_number AS VARCHAR) LIKE $${tagQueryParams.length + 2})`;
|
||||
tagWhereConditions.push(nameFilter);
|
||||
tagQueryParams.push(`%${searchParams.name}%`, `%${searchParams.name}%`);
|
||||
}
|
||||
|
||||
if (searchParams.criteria) {
|
||||
const criteriaFilter = `(tag_name LIKE $${tagQueryParams.length + 1} OR CAST(tag_number AS VARCHAR) LIKE $${tagQueryParams.length + 2})`;
|
||||
tagWhereConditions.push(criteriaFilter);
|
||||
tagQueryParams.push(`%${searchParams.criteria}%`, `%${searchParams.criteria}%`);
|
||||
}
|
||||
|
||||
const tagWhereClause = tagWhereConditions.length > 0
|
||||
? ` AND ${tagWhereConditions.join(" AND ")}`
|
||||
: '';
|
||||
|
||||
const tagsQuery = `
|
||||
SELECT tag_name, tag_number
|
||||
FROM m_tags
|
||||
WHERE is_report = 1 AND deleted_at IS NULL
|
||||
${tagWhereClause}
|
||||
ORDER BY tag_name
|
||||
`;
|
||||
|
||||
console.log('Tags Query:', tagsQuery);
|
||||
console.log('Tags Query Params:', tagQueryParams);
|
||||
|
||||
const tagsResult = await pool.query(tagsQuery, tagQueryParams);
|
||||
|
||||
console.log('Tags found:', tagsResult.recordset.length);
|
||||
|
||||
if (tagsResult.recordset.length === 0) {
|
||||
return { data: [], column: '' };
|
||||
}
|
||||
|
||||
const tagNames = tagsResult.recordset.map(r => `[${r.tag_name}]`).join(', ');
|
||||
const tagNamesColumn = tagsResult.recordset.map(r => r.tag_name).join(', ');
|
||||
const tagNumbers = tagsResult.recordset.map(r => r.tag_number);
|
||||
|
||||
console.log('Filtered tag numbers:', tagNumbers);
|
||||
console.log('Filtered tag names:', tagNamesColumn);
|
||||
|
||||
const tagNumbersFilter = tagNumbers.length > 0
|
||||
? ` AND a.tagnum IN (${tagNumbers.join(',')})`
|
||||
: '';
|
||||
|
||||
const queryText = `
|
||||
DECLARE
|
||||
@fromParam DATETIME = $1,
|
||||
@toParam DATETIME = $2,
|
||||
@intervalParam INT = $3;
|
||||
|
||||
SELECT TOP 10
|
||||
'DEBUG_AVERAGING' as info,
|
||||
b.tag_name,
|
||||
DATEADD(MINUTE,
|
||||
(DATEDIFF(MINUTE, @fromParam, CAST(a.datetime AS DATETIME)) / @intervalParam) * @intervalParam,
|
||||
@fromParam
|
||||
) AS waktu_group,
|
||||
COUNT(*) as data_points,
|
||||
AVG(CAST(a.val AS FLOAT)) as avg_val,
|
||||
MIN(CAST(a.val AS FLOAT)) as min_val,
|
||||
MAX(CAST(a.val AS FLOAT)) as max_val
|
||||
FROM ${tableName} a
|
||||
INNER JOIN m_tags b ON a.tagnum = b.tag_number
|
||||
AND b.deleted_at IS NULL
|
||||
AND b.is_report = 1
|
||||
WHERE CAST(a.datetime AS DATETIME) BETWEEN @fromParam AND @toParam
|
||||
AND a.val IS NOT NULL
|
||||
${tagNumbersFilter}
|
||||
GROUP BY
|
||||
b.tag_name,
|
||||
DATEADD(MINUTE,
|
||||
(DATEDIFF(MINUTE, @fromParam, CAST(a.datetime AS DATETIME)) / @intervalParam) * @intervalParam,
|
||||
@fromParam
|
||||
)
|
||||
ORDER BY b.tag_name, waktu_group;
|
||||
|
||||
;WITH TimeSeries AS (
|
||||
SELECT @fromParam AS waktu
|
||||
UNION ALL
|
||||
SELECT DATEADD(MINUTE, @intervalParam, waktu)
|
||||
FROM TimeSeries
|
||||
WHERE DATEADD(MINUTE, @intervalParam, waktu) <= @toParam
|
||||
),
|
||||
CleanData AS (
|
||||
SELECT
|
||||
CAST(a.datetime AS DATETIME) as datetime_clean,
|
||||
a.tagnum,
|
||||
CAST(a.val AS FLOAT) as val,
|
||||
b.tag_name
|
||||
FROM ${tableName} a
|
||||
INNER JOIN m_tags b ON a.tagnum = b.tag_number
|
||||
AND b.deleted_at IS NULL
|
||||
AND b.is_report = 1
|
||||
WHERE ISDATE(a.datetime) = 1
|
||||
AND a.val IS NOT NULL
|
||||
AND CAST(a.datetime AS DATETIME) BETWEEN @fromParam AND @toParam
|
||||
${tagNumbersFilter}
|
||||
),
|
||||
Averaged AS (
|
||||
SELECT
|
||||
DATEADD(MINUTE,
|
||||
(DATEDIFF(MINUTE, @fromParam, datetime_clean) / @intervalParam) * @intervalParam,
|
||||
@fromParam
|
||||
) AS waktu_group,
|
||||
tag_name,
|
||||
AVG(val) AS avg_val
|
||||
FROM CleanData
|
||||
GROUP BY
|
||||
DATEADD(MINUTE,
|
||||
(DATEDIFF(MINUTE, @fromParam, datetime_clean) / @intervalParam) * @intervalParam,
|
||||
@fromParam
|
||||
),
|
||||
tag_name
|
||||
),
|
||||
Pivoted AS (
|
||||
SELECT
|
||||
waktu_group,
|
||||
${tagNames}
|
||||
FROM Averaged
|
||||
PIVOT (
|
||||
MAX(avg_val)
|
||||
FOR tag_name IN (${tagNames})
|
||||
) AS p
|
||||
)
|
||||
SELECT
|
||||
CONVERT(VARCHAR(19), 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, [from, to, interval]);
|
||||
|
||||
if (result.recordsets && result.recordsets.length >= 2) {
|
||||
console.log('Sample averaging data:');
|
||||
result.recordsets[0].slice(0, 10).forEach(row => {
|
||||
console.log(`${row.tag_name} @ ${row.waktu_group}: avg=${row.avg_val}, min=${row.min_val}, max=${row.max_val}, points=${row.data_points}`);
|
||||
});
|
||||
|
||||
console.log('\nPivot result sample:');
|
||||
if (result.recordsets[1] && result.recordsets[1].length > 0) {
|
||||
result.recordsets[1].slice(0, 5).forEach(row => {
|
||||
console.log(JSON.stringify(row, null, 2));
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
const rows = result.recordsets?.[1] || result.recordset;
|
||||
|
||||
if (!rows || rows.length === 0) {
|
||||
console.log('No pivot data');
|
||||
return { data: [], column: tagNamesColumn };
|
||||
}
|
||||
|
||||
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 && row[tag] !== undefined ? Number(row[tag]) : null
|
||||
}))
|
||||
}));
|
||||
|
||||
nivoData.forEach(series => {
|
||||
const nonNull = series.data.filter(d => d.y !== null && d.y !== 0);
|
||||
const sampleVals = nonNull.slice(0, 3).map(d => d.y);
|
||||
console.log(`${series.id}: ${nonNull.length} non-zero values, sample: [${sampleVals.join(', ')}]`);
|
||||
});
|
||||
|
||||
return { data: nivoData, column: tagNamesColumn };
|
||||
} catch (error) {
|
||||
console.error('Error in getHistoryValueReportPivotDb:', error);
|
||||
throw error;
|
||||
}
|
||||
|
||||
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 = {}) => {
|
||||
@@ -282,18 +443,55 @@ const getHistoryValueTrendingPivotDb = async (tableName, searchParams = {}) => {
|
||||
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
|
||||
let tagQueryParams = [];
|
||||
let tagWhereConditions = [];
|
||||
|
||||
if (searchParams.plant_sub_section_id) {
|
||||
tagWhereConditions.push(`plant_sub_section_id = $${tagQueryParams.length + 1}`);
|
||||
tagQueryParams.push(searchParams.plant_sub_section_id);
|
||||
}
|
||||
|
||||
if (searchParams.plant_section_id) {
|
||||
tagWhereConditions.push(`plant_section_id = $${tagQueryParams.length + 1}`);
|
||||
tagQueryParams.push(searchParams.plant_section_id);
|
||||
}
|
||||
|
||||
if (searchParams.name) {
|
||||
const nameFilter = `(tag_name LIKE $${tagQueryParams.length + 1} OR CAST(tag_number AS VARCHAR) LIKE $${tagQueryParams.length + 2})`;
|
||||
tagWhereConditions.push(nameFilter);
|
||||
tagQueryParams.push(`%${searchParams.name}%`, `%${searchParams.name}%`);
|
||||
}
|
||||
|
||||
if (searchParams.criteria) {
|
||||
const criteriaFilter = `(tag_name LIKE $${tagQueryParams.length + 1} OR CAST(tag_number AS VARCHAR) LIKE $${tagQueryParams.length + 2})`;
|
||||
tagWhereConditions.push(criteriaFilter);
|
||||
tagQueryParams.push(`%${searchParams.criteria}%`, `%${searchParams.criteria}%`);
|
||||
}
|
||||
|
||||
const tagWhereClause = tagWhereConditions.length > 0
|
||||
? ` AND ${tagWhereConditions.join(" AND ")}`
|
||||
: '';
|
||||
|
||||
const tagsQuery = `
|
||||
SELECT tag_name, tag_number
|
||||
FROM m_tags
|
||||
WHERE is_report = 1 AND deleted_at IS NULL
|
||||
`);
|
||||
${tagWhereClause}
|
||||
ORDER BY tag_name
|
||||
`;
|
||||
|
||||
const tags = await pool.query(tagsQuery, tagQueryParams);
|
||||
|
||||
if (tags.recordset.length === 0) {
|
||||
return { data: [] };
|
||||
}
|
||||
|
||||
const tagNames = tags.recordset.map(r => `[${r.tag_name}]`).join(', ');
|
||||
const tagNumbers = tags.recordset.map(r => r.tag_number);
|
||||
|
||||
const tagNumbersFilter = tagNumbers.length > 0
|
||||
? ` AND a.tagnum IN (${tagNumbers.join(',')})`
|
||||
: '';
|
||||
|
||||
const queryText = `
|
||||
DECLARE
|
||||
@@ -316,6 +514,7 @@ const getHistoryValueTrendingPivotDb = async (tableName, searchParams = {}) => {
|
||||
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
|
||||
${tagNumbersFilter}
|
||||
GROUP BY
|
||||
DATEADD(MINUTE, DATEDIFF(MINUTE, 0, CAST(a.datetime AS DATETIME)) / @intervalParam * @intervalParam, 0),
|
||||
b.tag_name
|
||||
@@ -349,7 +548,7 @@ const getHistoryValueTrendingPivotDb = async (tableName, searchParams = {}) => {
|
||||
const tagList = Object.keys(rows[0]).filter(k => k !== timeKey);
|
||||
|
||||
const nivoData = tagList.map(tag => ({
|
||||
name: tag,
|
||||
id: tag,
|
||||
data: rows.map(row => ({
|
||||
x: row[timeKey],
|
||||
y: row[tag] !== null ? Number(row[tag]) : null
|
||||
@@ -359,7 +558,6 @@ const getHistoryValueTrendingPivotDb = async (tableName, searchParams = {}) => {
|
||||
return { data: nivoData };
|
||||
};
|
||||
|
||||
|
||||
module.exports = {
|
||||
getHistoryAlarmDb,
|
||||
getHistoryEventDb,
|
||||
@@ -367,4 +565,4 @@ module.exports = {
|
||||
getHistoryValueReportDb,
|
||||
getHistoryValueReportPivotDb,
|
||||
getHistoryValueTrendingPivotDb
|
||||
};
|
||||
};
|
||||
@@ -1,4 +1,11 @@
|
||||
const { getHistoryAlarmDb, getHistoryEventDb, checkTableNamedDb, getHistoryValueReportDb, getHistoryValueReportPivotDb, getHistoryValueTrendingPivotDb } = require('../db/history_value.db');
|
||||
const {
|
||||
getHistoryAlarmDb,
|
||||
getHistoryEventDb,
|
||||
checkTableNamedDb,
|
||||
getHistoryValueReportDb,
|
||||
getHistoryValueReportPivotDb,
|
||||
getHistoryValueTrendingPivotDb
|
||||
} = require('../db/history_value.db');
|
||||
const { getSubSectionByIdDb } = require('../db/plant_sub_section.db');
|
||||
const { ErrorHandler } = require('../helpers/error');
|
||||
|
||||
@@ -7,94 +14,128 @@ class HistoryValue {
|
||||
static async getAllHistoryAlarm(param) {
|
||||
try {
|
||||
const results = await getHistoryAlarmDb(param);
|
||||
|
||||
results.data.map(element => {
|
||||
});
|
||||
|
||||
return results
|
||||
return results;
|
||||
} catch (error) {
|
||||
throw new ErrorHandler(error.statusCode, error.message);
|
||||
throw new ErrorHandler(error.statusCode || 500, error.message || 'Error fetching alarm history');
|
||||
}
|
||||
}
|
||||
|
||||
static async getAllHistoryEvent(param) {
|
||||
try {
|
||||
const results = await getHistoryEventDb(param);
|
||||
|
||||
results.data.map(element => {
|
||||
});
|
||||
|
||||
return results
|
||||
return results;
|
||||
} catch (error) {
|
||||
throw new ErrorHandler(error.statusCode, error.message);
|
||||
throw new ErrorHandler(error.statusCode || 500, error.message || 'Error fetching event history');
|
||||
}
|
||||
}
|
||||
|
||||
static async getHistoryValueReport(param) {
|
||||
try {
|
||||
if (!param.plant_sub_section_id) {
|
||||
throw new ErrorHandler(400, 'plant_sub_section_id is required');
|
||||
}
|
||||
|
||||
const plantSubSection = await getSubSectionByIdDb(param.plant_sub_section_id);
|
||||
|
||||
if (plantSubSection.length < 1) throw new ErrorHandler(404, 'Plant sub section not found');
|
||||
if (!plantSubSection || plantSubSection.length < 1) {
|
||||
throw new ErrorHandler(404, 'Plant sub section not found');
|
||||
}
|
||||
|
||||
const tabelExist = await checkTableNamedDb(plantSubSection[0]?.table_name_value);
|
||||
const tableNameValue = plantSubSection[0]?.table_name_value;
|
||||
|
||||
if (!tableNameValue) {
|
||||
throw new ErrorHandler(404, 'Table name not configured for this sub section');
|
||||
}
|
||||
|
||||
if (tabelExist.length < 1) throw new ErrorHandler(404, 'Value not found');
|
||||
const tableExist = await checkTableNamedDb(tableNameValue);
|
||||
|
||||
const results = await getHistoryValueReportDb(tabelExist[0]?.TABLE_NAME, param);
|
||||
if (!tableExist || tableExist.length < 1) {
|
||||
throw new ErrorHandler(404, `Value table '${tableNameValue}' not found`);
|
||||
}
|
||||
|
||||
results.data.map(element => {
|
||||
});
|
||||
|
||||
return results
|
||||
const results = await getHistoryValueReportDb(tableExist[0].TABLE_NAME, param);
|
||||
return results;
|
||||
} catch (error) {
|
||||
throw new ErrorHandler(error.statusCode, error.message);
|
||||
throw new ErrorHandler(
|
||||
error.statusCode || 500,
|
||||
error.message || 'Error fetching history value report'
|
||||
);
|
||||
}
|
||||
}
|
||||
|
||||
static async getHistoryValueReportPivot(param) {
|
||||
try {
|
||||
if (!param.plant_sub_section_id) {
|
||||
throw new ErrorHandler(400, 'plant_sub_section_id is required');
|
||||
}
|
||||
if (!param.from || !param.to) {
|
||||
throw new ErrorHandler(400, 'from and to date parameters are required');
|
||||
}
|
||||
|
||||
const plantSubSection = await getSubSectionByIdDb(param.plant_sub_section_id);
|
||||
|
||||
if (plantSubSection.length < 1) throw new ErrorHandler(404, 'Plant sub section not found');
|
||||
if (!plantSubSection || plantSubSection.length < 1) {
|
||||
throw new ErrorHandler(404, 'Plant sub section not found');
|
||||
}
|
||||
|
||||
const tabelExist = await checkTableNamedDb(plantSubSection[0]?.table_name_value);
|
||||
const tableNameValue = plantSubSection[0]?.table_name_value;
|
||||
|
||||
if (!tableNameValue) {
|
||||
throw new ErrorHandler(404, 'Table name not configured for this sub section');
|
||||
}
|
||||
|
||||
if (tabelExist.length < 1) throw new ErrorHandler(404, 'Value not found');
|
||||
const tableExist = await checkTableNamedDb(tableNameValue);
|
||||
|
||||
const results = await getHistoryValueReportPivotDb(tabelExist[0]?.TABLE_NAME, param);
|
||||
if (!tableExist || tableExist.length < 1) {
|
||||
throw new ErrorHandler(404, `Value table '${tableNameValue}' not found`);
|
||||
}
|
||||
|
||||
results.data.map(element => {
|
||||
});
|
||||
|
||||
return results
|
||||
const results = await getHistoryValueReportPivotDb(tableExist[0].TABLE_NAME, param);
|
||||
return results;
|
||||
} catch (error) {
|
||||
throw new ErrorHandler(error.statusCode, error.message);
|
||||
throw new ErrorHandler(
|
||||
error.statusCode || 500,
|
||||
error.message || 'Error fetching history value report pivot'
|
||||
);
|
||||
}
|
||||
}
|
||||
|
||||
static async getHistoryValueTrendingPivot(param) {
|
||||
try {
|
||||
if (!param.plant_sub_section_id) {
|
||||
throw new ErrorHandler(400, 'plant_sub_section_id is required');
|
||||
}
|
||||
if (!param.from || !param.to) {
|
||||
throw new ErrorHandler(400, 'from and to date parameters are required');
|
||||
}
|
||||
|
||||
const plantSubSection = await getSubSectionByIdDb(param.plant_sub_section_id);
|
||||
|
||||
if (plantSubSection.length < 1) throw new ErrorHandler(404, 'Plant sub section not found');
|
||||
if (!plantSubSection || plantSubSection.length < 1) {
|
||||
throw new ErrorHandler(404, 'Plant sub section not found');
|
||||
}
|
||||
|
||||
const tabelExist = await checkTableNamedDb(plantSubSection[0]?.table_name_value);
|
||||
const tableNameValue = plantSubSection[0]?.table_name_value;
|
||||
|
||||
if (!tableNameValue) {
|
||||
throw new ErrorHandler(404, 'Table name not configured for this sub section');
|
||||
}
|
||||
|
||||
if (tabelExist.length < 1) throw new ErrorHandler(404, 'Value not found');
|
||||
const tableExist = await checkTableNamedDb(tableNameValue);
|
||||
|
||||
const results = await getHistoryValueTrendingPivotDb(tabelExist[0]?.TABLE_NAME, param);
|
||||
if (!tableExist || tableExist.length < 1) {
|
||||
throw new ErrorHandler(404, `Value table '${tableNameValue}' not found`);
|
||||
}
|
||||
|
||||
results.data.map(element => {
|
||||
});
|
||||
|
||||
return results
|
||||
const results = await getHistoryValueTrendingPivotDb(tableExist[0].TABLE_NAME, param);
|
||||
return results;
|
||||
} catch (error) {
|
||||
throw new ErrorHandler(error.statusCode, error.message);
|
||||
throw new ErrorHandler(
|
||||
error.statusCode || 500,
|
||||
error.message || 'Error fetching history value trending pivot'
|
||||
);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
module.exports = HistoryValue;
|
||||
module.exports = HistoryValue;
|
||||
Reference in New Issue
Block a user