diff --git a/src/controllers/api/Orders.php b/src/controllers/api/Orders.php index 186d5aa..04e6864 100644 --- a/src/controllers/api/Orders.php +++ b/src/controllers/api/Orders.php @@ -34,19 +34,43 @@ public function getAllOrders(): void /** * Get total revenue for each month. * - * Example: + * Each object includes: + * - The month (first day of the month). + * - The total number of orders for that month. + * - The total revenue for that month. + * - The percentage difference in total orders from the previous month. + * - The percentage difference in total revenue from the previous month. * + * Example response: *
* [ * { - * "date": "2024-06-01", + * "month": "2024-06-01", * "totalOrders": 1, - * "totalRevenue": "3.49" + * "totalRevenue": "3.49", + * "percentageDifferenceOrders": null, + * "percentageDifferenceRevenue": null * }, * { - * "date": "2024-07-01", + * "month": "2024-07-01", * "totalOrders": 9, - * "totalRevenue": "40.91" + * "totalRevenue": "40.91", + * "percentageDifferenceOrders": "800.00", + * "percentageDifferenceRevenue": "1072.21" + * }, + * { + * "month": "2024-08-01", + * "totalOrders": 1, + * "totalRevenue": "7.98", + * "percentageDifferenceOrders": "-88.89", + * "percentageDifferenceRevenue": "-80.49" + * }, + * { + * "month": "2024-10-01", + * "totalOrders": 1, + * "totalRevenue": "7.98", + * "percentageDifferenceOrders": "0.00", + * "percentageDifferenceRevenue": "0.00" * } * ] *@@ -56,18 +80,48 @@ public function getAllOrders(): void public function getSalesOverTime(): void { $query = <<< EOL + WITH monthly_stats AS ( + SELECT + DATE_FORMAT(o.created_date, '%Y-%m-01') AS month, -- Group by month + COUNT(DISTINCT o.order_id) AS totalOrders, -- Count the number of unique orders + SUM(op.quantity * op.unit_price) AS totalRevenue -- Total revenue calculation + FROM + `order` o + JOIN + order_product op ON o.order_id = op.order_id + GROUP BY + DATE_FORMAT(o.created_date, '%Y-%m-01') -- Group by the first day of each month + ), + monthly_diff AS ( + SELECT + month, + totalOrders, + totalRevenue, + LAG(totalOrders) OVER (ORDER BY month) AS previousMonthOrders, -- Get previous month's totalOrders + LAG(totalRevenue) OVER (ORDER BY month) AS previousMonthRevenue -- Get previous month's totalRevenue + FROM + monthly_stats + ) SELECT - DATE_FORMAT(o.created_date, '%Y-%m-01') AS date, -- Group by month - COUNT(DISTINCT o.order_id) AS totalOrders, -- Count the number of unique orders - SUM(op.quantity * op.unit_price) AS totalRevenue -- Total revenue calculation + month, + totalOrders, + totalRevenue, + CASE + WHEN previousMonthOrders IS NOT NULL AND previousMonthOrders != 0 THEN + ROUND(((totalOrders - previousMonthOrders) * 100.0 / previousMonthOrders), 2) + ELSE + NULL -- No previous month data for the first row + END AS percentageDifferenceOrders, + CASE + WHEN previousMonthRevenue IS NOT NULL AND previousMonthRevenue != 0 THEN + ROUND(((totalRevenue - previousMonthRevenue) * 100.0 / previousMonthRevenue), 2) + ELSE + NULL -- No previous month data for the first row + END AS percentageDifferenceRevenue FROM - `order` o - JOIN - order_product op ON o.order_id = op.order_id - GROUP BY - DATE_FORMAT(o.created_date, '%Y-%m-01') -- Group by the first day of each month + monthly_diff ORDER BY - date; -- Order by date + month; -- Order by month EOL; $con = self::connect(); diff --git a/src/controllers/api/Reviews.php b/src/controllers/api/Reviews.php index c93df02..94258d7 100644 --- a/src/controllers/api/Reviews.php +++ b/src/controllers/api/Reviews.php @@ -206,47 +206,68 @@ public function deleteReview(): void } /** - * Gets the number of reviews for each month. - * - *
- * [ - * { - * "date": "2024-04-01", - * "totalReviews": 1, - * "positiveReviews": "0", - * "negativeReviews": "1" - * }, - * { - * "date": "2024-05-01", - * "totalReviews": 9, - * "positiveReviews": "4", - * "negativeReviews": "5" - * }, - * { - * "date": "2024-06-01", - * "totalReviews": 1, - * "positiveReviews": "1", - * "negativeReviews": "0" - * } - * ] - *+ * Gets the number of reviews for each month with percentage difference from last month. + * Example response: + *
+ * [ + * { + * "month": "2024-04-01", + * "totalReviews": 1, + * "percentageDifference": null + * }, + * { + * "month": "2024-05-01", + * "totalReviews": 9, + * "percentageDifference": "800.00" + * }, + * { + * "month": "2024-06-01", + * "totalReviews": 1, + * "percentageDifference": "-88.89" + * }, + * { + * "month": "2024-10-01", + * "totalReviews": 1, + * "percentageDifference": "0.00" + * } + * ] + ** * @return void */ public function getCountOverTime(): void { $query = <<< EOL + WITH monthly_reviews AS ( + SELECT + DATE_FORMAT(created_date, '%Y-%m-01') AS month, -- Extract the first day of the month + COUNT(review_id) AS totalReviews -- Total reviews per month + FROM + review + GROUP BY + DATE_FORMAT(created_date, '%Y-%m') + ), + monthly_diff AS ( + SELECT + month, + totalReviews, + LAG(totalReviews) OVER (ORDER BY month) AS previousMonthReviews -- Get the previous month's reviews + FROM + monthly_reviews + ) SELECT - DATE_FORMAT(created_date, '%Y-%m-01') AS date, -- Group by month - COUNT(*) AS totalReviews, -- Total number of reviews - SUM(IF(rating >= 3, 1, 0)) AS positiveReviews, -- Count of positive reviews (rating 3 and above) - SUM(IF(rating < 3, 1, 0)) AS negativeReviews -- Count of negative reviews (rating below 3) + month, + totalReviews, + CASE + WHEN previousMonthReviews IS NOT NULL AND previousMonthReviews != 0 THEN + ROUND(((totalReviews - previousMonthReviews) * 100.0 / previousMonthReviews), 2) + ELSE + NULL -- No previous month data for the first row + END AS percentageDifference FROM - review - GROUP BY - DATE_FORMAT(created_date, '%Y-%m-01') -- Group by the first day of each month + monthly_diff ORDER BY - date; -- Order by date + month; EOL; $con = self::connect();