Added few new queries for dashboard

This commit is contained in:
Aswin B. S 2025-07-21 12:10:30 +05:30
parent 1e02eea2f0
commit 21d078ed37
5 changed files with 358 additions and 7 deletions

66
package-lock.json generated
View File

@ -12,7 +12,9 @@
"@aws-sdk/client-athena": "^3.699.0",
"@aws-sdk/client-s3": "^3.701.0",
"@aws-sdk/credential-providers": "^3.699.0",
"@fastify/cors": "^11.0.1",
"awsmetrics": "file:",
"cors": "^2.8.5",
"dotenv": "^16.4.5",
"fastify": "^5.3.0",
"fastify-plugin": "^5.0.1",
@ -1041,6 +1043,26 @@
"fast-uri": "^3.0.0"
}
},
"node_modules/@fastify/cors": {
"version": "11.0.1",
"resolved": "https://registry.npmjs.org/@fastify/cors/-/cors-11.0.1.tgz",
"integrity": "sha512-dmZaE7M1f4SM8ZZuk5RhSsDJ+ezTgI7v3HHRj8Ow9CneczsPLZV6+2j2uwdaSLn8zhTv6QV0F4ZRcqdalGx1pQ==",
"funding": [
{
"type": "github",
"url": "https://github.com/sponsors/fastify"
},
{
"type": "opencollective",
"url": "https://opencollective.com/fastify"
}
],
"license": "MIT",
"dependencies": {
"fastify-plugin": "^5.0.0",
"toad-cache": "^3.7.0"
}
},
"node_modules/@fastify/error": {
"version": "4.0.0",
"resolved": "https://registry.npmjs.org/@fastify/error/-/error-4.0.0.tgz",
@ -1966,9 +1988,10 @@
"integrity": "sha512-AlcaJBi/pqqJBIQ8U9Mcpc9i8Aqxn88Skv5d+xBX006BY5u8N3mGLHa5Lgppa7L/HfwgwLgZ6NYs+Ag6uUmJRA=="
},
"node_modules/brace-expansion": {
"version": "1.1.11",
"resolved": "https://registry.npmjs.org/brace-expansion/-/brace-expansion-1.1.11.tgz",
"integrity": "sha512-iCuPHDFgrHX7H2vEI/5xpz07zSHB00TpugqhmYtVmMO6518mCuRMoOYFldEBl0g187ufozdaHgWKcYFb61qGiA==",
"version": "1.1.12",
"resolved": "https://registry.npmjs.org/brace-expansion/-/brace-expansion-1.1.12.tgz",
"integrity": "sha512-9T9UjW3r0UW5c1Q7GTwllptXwhvYmEzFhzMfZ9H7FQWt+uZePjZPjBP/W1ZEyZ1twGWom5/56TF4lPcqjnDHcg==",
"license": "MIT",
"optional": true,
"dependencies": {
"balanced-match": "^1.0.0",
@ -2073,6 +2096,19 @@
"node": ">=18"
}
},
"node_modules/cors": {
"version": "2.8.5",
"resolved": "https://registry.npmjs.org/cors/-/cors-2.8.5.tgz",
"integrity": "sha512-KIHbLJqu73RGr/hnbrO9uBeixNGuvSQjul/jdFvS/KFSIH1hWVd1ng7zOHx+YrEfInLG7q4n6GHQ9cDtxv/P6g==",
"license": "MIT",
"dependencies": {
"object-assign": "^4",
"vary": "^1"
},
"engines": {
"node": ">= 0.10"
}
},
"node_modules/debug": {
"version": "4.4.0",
"resolved": "https://registry.npmjs.org/debug/-/debug-4.4.0.tgz",
@ -2904,6 +2940,15 @@
"node": "^12.13.0 || ^14.15.0 || >=16.0.0"
}
},
"node_modules/object-assign": {
"version": "4.1.1",
"resolved": "https://registry.npmjs.org/object-assign/-/object-assign-4.1.1.tgz",
"integrity": "sha512-rJgTQnkUnH1sFw8yT6VSU3zD3sWmu6sZhIseY8VX+GRu3P6F7Fu+JNDoXfklElbLJSnc3FUQHVe4cU5hj+BcUg==",
"license": "MIT",
"engines": {
"node": ">=0.10.0"
}
},
"node_modules/on-exit-leak-free": {
"version": "2.1.2",
"resolved": "https://registry.npmjs.org/on-exit-leak-free/-/on-exit-leak-free-2.1.2.tgz",
@ -3505,9 +3550,9 @@
}
},
"node_modules/tar-fs": {
"version": "2.1.2",
"resolved": "https://registry.npmjs.org/tar-fs/-/tar-fs-2.1.2.tgz",
"integrity": "sha512-EsaAXwxmx8UB7FRKqeozqEPop69DXcmYwTQwXvyAPF352HJsPdkVhvTaDPYqfNgruveJIJy3TA2l+2zj8LJIJA==",
"version": "2.1.3",
"resolved": "https://registry.npmjs.org/tar-fs/-/tar-fs-2.1.3.tgz",
"integrity": "sha512-090nwYJDmlhwFwEW3QQl+vaNnxsO2yVsd45eTKRBzSzu+hlb1w2K9inVq5b0ngXuLVqQ4ApvsUHHnu/zQNkWAg==",
"license": "MIT",
"dependencies": {
"chownr": "^1.1.1",
@ -3629,6 +3674,15 @@
"node": ">= 0.10"
}
},
"node_modules/vary": {
"version": "1.1.2",
"resolved": "https://registry.npmjs.org/vary/-/vary-1.1.2.tgz",
"integrity": "sha512-BNGbWLfd0eUPabhkXUVm0j8uuvREyTh5ovRa/dyow/BqAbZJyC+5fU+IzQOzmAKzYqYRAISoRhdQr3eIZ/PXqg==",
"license": "MIT",
"engines": {
"node": ">= 0.8"
}
},
"node_modules/which": {
"version": "2.0.2",
"resolved": "https://registry.npmjs.org/which/-/which-2.0.2.tgz",

View File

@ -12,7 +12,9 @@
"@aws-sdk/client-athena": "^3.699.0",
"@aws-sdk/client-s3": "^3.701.0",
"@aws-sdk/credential-providers": "^3.699.0",
"@fastify/cors": "^11.0.1",
"awsmetrics": "file:",
"cors": "^2.8.5",
"dotenv": "^16.4.5",
"fastify": "^5.3.0",
"fastify-plugin": "^5.0.1",

187
queries/dashboard.js Normal file
View File

@ -0,0 +1,187 @@
export const currentMonthSummary = `
SELECT
SUM(line_item_blended_cost) as totalBlendedCost,
SUM(line_item_unblended_cost) as totalUnblendedCost,
COUNT(DISTINCT line_item_usage_account_id) as accountCount,
COUNT(DISTINCT line_item_product_code) as serviceCount,
COUNT(DISTINCT bill_invoice_id) as invoiceCount,
CONCAT(year, '-', LPAD(month, 2, '0')) as month
FROM ${process.env.ATHENA_CU_TABLE}
WHERE year = CAST(YEAR(CURRENT_DATE) AS VARCHAR)
AND month = CAST(MONTH(CURRENT_DATE) AS VARCHAR)
AND line_item_blended_cost > 0
GROUP BY year, month
`;
export const previousMonthSummary = `
SELECT
SUM(line_item_blended_cost) as totalBlendedCost,
CONCAT(year, '-', LPAD(month, 2, '0')) as month
FROM ${process.env.ATHENA_CU_TABLE}
WHERE year = CAST(YEAR(DATE_ADD('month', -1, CURRENT_DATE)) AS VARCHAR)
AND month = CAST(MONTH(DATE_ADD('month', -1, CURRENT_DATE)) AS VARCHAR)
AND line_item_blended_cost > 0
GROUP BY year, month
`;
export const serviceBreakdown = `
SELECT
line_item_product_code as productCode,
SUM(line_item_blended_cost) as totalCost,
COUNT(DISTINCT line_item_resource_id) as resourceCount,
COUNT(DISTINCT line_item_usage_account_id) as accountCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE year = CAST(YEAR(DATE_ADD('month', -1, CURRENT_DATE)) AS VARCHAR)
AND month = CAST(MONTH(DATE_ADD('month', -1, CURRENT_DATE)) AS VARCHAR)
AND line_item_blended_cost > 0
GROUP BY line_item_product_code
ORDER BY totalCost DESC
LIMIT 10
`;
export const topAccounts = `
SELECT
line_item_usage_account_id as accountId,
SUM(line_item_blended_cost) as totalCost,
COUNT(DISTINCT line_item_product_code) as serviceCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE year = CAST(YEAR(DATE_ADD('month', -1, CURRENT_DATE)) AS VARCHAR)
AND month = CAST(MONTH(DATE_ADD('month', -1, CURRENT_DATE)) AS VARCHAR)
AND line_item_blended_cost > 0
GROUP BY line_item_usage_account_id
ORDER BY totalCost DESC
LIMIT 10
`;
export const dailyTrends = `
SELECT
line_item_usage_start_date as date,
SUM(line_item_blended_cost) as blendedCost,
SUM(line_item_unblended_cost) as unblendedCost
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_start_date >= date_add('day', -30, current_date)
AND line_item_blended_cost > 0
GROUP BY line_item_usage_start_date
ORDER BY date DESC
LIMIT 31
`;
export const todaySpending = `
SELECT
SUM(line_item_blended_cost) as todaysCost,
COUNT(DISTINCT line_item_product_code) as servicesUsed
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_start_date = CURRENT_DATE
AND line_item_blended_cost > 0`;
// This week vs last week
export const weeklyComparison = `
SELECT
CASE
WHEN line_item_usage_start_date >= date_add('day', -7, current_date) THEN 'this_week'
WHEN line_item_usage_start_date >= date_add('day', -14, current_date) THEN 'last_week'
END as week_period,
SUM(line_item_blended_cost) as totalCost
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_start_date >= date_add('day', -14, current_date)
GROUP BY CASE
WHEN line_item_usage_start_date >= date_add('day', -7, current_date) THEN 'this_week'
WHEN line_item_usage_start_date >= date_add('day', -14, current_date) THEN 'last_week'
END
`;
// Service drill-down queries
export const serviceAccountBreakdown = `
SELECT
line_item_usage_account_id as accountId,
SUM(line_item_blended_cost) as totalCost,
COUNT(DISTINCT line_item_resource_id) as resourceCount,
COUNT(DISTINCT line_item_usage_start_date) as daysActive
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_product_code = '%serviceCode%'
AND line_item_usage_start_date >= date_add('day', -%days%, current_date)
AND line_item_blended_cost > 0
GROUP BY line_item_usage_account_id
ORDER BY totalCost DESC
`;
export const serviceTrends = `
SELECT
line_item_usage_start_date as date,
SUM(line_item_blended_cost) as dailyCost,
COUNT(DISTINCT line_item_usage_account_id) as accountCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_product_code = '%serviceCode%'
AND line_item_usage_start_date >= date_add('day', -%days%, current_date)
AND line_item_blended_cost > 0
GROUP BY line_item_usage_start_date
ORDER BY date DESC
`;
// Account drill-down queries
export const accountServiceBreakdown = `
SELECT
line_item_product_code as productCode,
SUM(line_item_blended_cost) as totalCost,
COUNT(DISTINCT line_item_resource_id) as resourceCount,
COUNT(DISTINCT line_item_usage_start_date) as daysActive
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_account_id = '%accountId%'
AND line_item_usage_start_date >= date_add('day', -%days%, current_date)
AND line_item_blended_cost > 0
GROUP BY line_item_product_code
ORDER BY totalCost DESC
`;
export const accountTrends = `
SELECT
line_item_usage_start_date as date,
SUM(line_item_blended_cost) as dailyCost,
COUNT(DISTINCT line_item_product_code) as serviceCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_account_id = '%accountId%'
AND line_item_usage_start_date >= date_add('day', -%days%, current_date)
AND line_item_blended_cost > 0
GROUP BY line_item_usage_start_date
ORDER BY date DESC
`;
// Flexible date range queries
export const trendsWithDateRange = (startDate, endDate) => `
SELECT
line_item_usage_start_date as date,
SUM(line_item_blended_cost) as blendedCost,
SUM(line_item_unblended_cost) as unblendedCost,
COUNT(DISTINCT line_item_product_code) as serviceCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_start_date >= date('${startDate}')
AND line_item_usage_start_date <= date('${endDate}')
GROUP BY line_item_usage_start_date
ORDER BY date DESC
`;
export const servicesWithDateRange = (startDate, endDate) => `
SELECT
line_item_product_code as productCode,
SUM(line_item_blended_cost) as totalCost,
COUNT(DISTINCT line_item_usage_account_id) as accountCount,
COUNT(DISTINCT line_item_resource_id) as resourceCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_start_date >= date('${startDate}')
AND line_item_usage_start_date <= date('${endDate}')
GROUP BY line_item_product_code
ORDER BY totalCost DESC
`;
export const accountsWithDateRange = (startDate, endDate) => `
SELECT
line_item_usage_account_id as accountId,
SUM(line_item_blended_cost) as totalCost,
COUNT(DISTINCT line_item_product_code) as serviceCount,
COUNT(DISTINCT line_item_resource_id) as resourceCount
FROM ${process.env.ATHENA_CU_TABLE}
WHERE line_item_usage_start_date >= date('${startDate}')
AND line_item_usage_start_date <= date('${endDate}')
GROUP BY line_item_usage_account_id
ORDER BY totalCost DESC
`;

110
server.js
View File

@ -1,11 +1,16 @@
import Fastify from "fastify";
import sequelizePlugin from "./plugins/sequelize.js";
import dotenv from "dotenv";
import cors from "@fastify/cors";
import { executeQueryAsync, retrieveResultsAsync } from "./services/athena.js";
dotenv.config();
import * as queries from "./queries.js";
import * as queries from "./queries/queries.js";
import * as dashboardQueries from "./queries/dashboard.js";
const server = Fastify({ logger: true });
await server.register(cors, {
origin: "*",
});
server.register(sequelizePlugin);
server.get("/", async (request, reply) => {
@ -220,6 +225,109 @@ server.get("/invoices/:invoiceId/accounts/:accountId/products/:productCode/usage
return results;
});
server.get("/dashboard/summary", async (request, reply) => {
const [currentQueryId, previousQueryId] = await Promise.all([
executeQueryAsync(dashboardQueries.currentMonthSummary),
executeQueryAsync(dashboardQueries.previousMonthSummary)
]);
const [currentResults, previousResults] = await Promise.all([
retrieveResultsAsync(currentQueryId),
retrieveResultsAsync(previousQueryId)
]);
return {
current: currentResults[0] || {},
previous: previousResults[0] || {}
};
});
server.get("/dashboard/services", async (request, reply) => {
const queryExecutionId = await executeQueryAsync(dashboardQueries.serviceBreakdown);
const results = await retrieveResultsAsync(queryExecutionId);
return results;
});
server.get("/dashboard/trends", async (request, reply) => {
const queryExecutionId = await executeQueryAsync(dashboardQueries.dailyTrends);
const results = await retrieveResultsAsync(queryExecutionId);
return results;
});
server.get("/dashboard/accounts", async (request, reply) => {
const queryExecutionId = await executeQueryAsync(dashboardQueries.topAccounts);
const results = await retrieveResultsAsync(queryExecutionId);
return results;
});
server.get("/dashboard/today", async (request, reply) => {
const queryExecutionId = await executeQueryAsync(dashboardQueries.todaySpending);
const results = await retrieveResultsAsync(queryExecutionId);
return results[0] || {};
});
server.get("/dashboard/weekly", async (request, reply) => {
const queryExecutionId = await executeQueryAsync(dashboardQueries.weeklyComparison);
const results = await retrieveResultsAsync(queryExecutionId);
return results;
});
server.get("/dashboard/services/:serviceCode/accounts", async (request, reply) => {
const { days = 30 } = request.query;
const query = dashboardQueries.serviceAccountBreakdown
.replace('%serviceCode%', request.params.serviceCode)
.replace('%days%', days);
const queryExecutionId = await executeQueryAsync(query);
const results = await retrieveResultsAsync(queryExecutionId);
return {
serviceCode: request.params.serviceCode,
accounts: results,
totalCost: results.reduce((sum, account) => sum + parseFloat(account.totalCost || 0), 0).toFixed(2)
};
});
server.get("/dashboard/services/:serviceCode/trends", async (request, reply) => {
const { days = 30 } = request.query;
const query = dashboardQueries.serviceTrends
.replace('%serviceCode%', request.params.serviceCode)
.replace('%days%', days);
const queryExecutionId = await executeQueryAsync(query);
const results = await retrieveResultsAsync(queryExecutionId);
return {
serviceCode: request.params.serviceCode,
trends: results,
totalCost: results.reduce((sum, day) => sum + parseFloat(day.dailyCost || 0), 0).toFixed(2)
};
});
// Account drill-down routes
server.get("/dashboard/accounts/:accountId/services", async (request, reply) => {
const { days = 30 } = request.query;
const query = dashboardQueries.accountServiceBreakdown
.replace('%accountId%', request.params.accountId)
.replace('%days%', days);
const queryExecutionId = await executeQueryAsync(query);
const results = await retrieveResultsAsync(queryExecutionId);
return {
accountId: request.params.accountId,
services: results,
totalCost: results.reduce((sum, service) => sum + parseFloat(service.totalCost || 0), 0).toFixed(2)
};
});
server.get("/dashboard/accounts/:accountId/trends", async (request, reply) => {
const { days = 30 } = request.query;
const query = dashboardQueries.accountTrends
.replace('%accountId%', request.params.accountId)
.replace('%days%', days);
const queryExecutionId = await executeQueryAsync(query);
const results = await retrieveResultsAsync(queryExecutionId);
return {
accountId: request.params.accountId,
trends: results,
totalCost: results.reduce((sum, day) => sum + parseFloat(day.dailyCost || 0), 0).toFixed(2)
};
});
try {
await server.listen({ port: 3000 })
} catch (err) {