261 lines
8.1 KiB
JavaScript
261 lines
8.1 KiB
JavaScript
const express = require('express');
|
|
const router = express.Router();
|
|
|
|
// Get all orders with pagination, filtering, and sorting
|
|
router.get('/', async (req, res) => {
|
|
const pool = req.app.locals.pool;
|
|
try {
|
|
const page = parseInt(req.query.page) || 1;
|
|
const limit = parseInt(req.query.limit) || 50;
|
|
const offset = (page - 1) * limit;
|
|
const search = req.query.search || '';
|
|
const status = req.query.status || 'all';
|
|
const fromDate = req.query.fromDate ? new Date(req.query.fromDate) : null;
|
|
const toDate = req.query.toDate ? new Date(req.query.toDate) : null;
|
|
const minAmount = parseFloat(req.query.minAmount) || 0;
|
|
const maxAmount = req.query.maxAmount ? parseFloat(req.query.maxAmount) : null;
|
|
const sortColumn = req.query.sortColumn || 'date';
|
|
const sortDirection = req.query.sortDirection === 'desc' ? 'DESC' : 'ASC';
|
|
|
|
// Build the WHERE clause
|
|
const conditions = ['o1.canceled = false'];
|
|
const params = [];
|
|
let paramCounter = 1;
|
|
|
|
if (search) {
|
|
conditions.push(`(o1.order_number ILIKE $${paramCounter} OR o1.customer ILIKE $${paramCounter})`);
|
|
params.push(`%${search}%`);
|
|
paramCounter++;
|
|
}
|
|
|
|
if (status !== 'all') {
|
|
conditions.push(`o1.status = $${paramCounter}`);
|
|
params.push(status);
|
|
paramCounter++;
|
|
}
|
|
|
|
if (fromDate) {
|
|
conditions.push(`DATE(o1.date) >= DATE($${paramCounter})`);
|
|
params.push(fromDate.toISOString());
|
|
paramCounter++;
|
|
}
|
|
|
|
if (toDate) {
|
|
conditions.push(`DATE(o1.date) <= DATE($${paramCounter})`);
|
|
params.push(toDate.toISOString());
|
|
paramCounter++;
|
|
}
|
|
|
|
if (minAmount > 0) {
|
|
conditions.push(`total_amount >= $${paramCounter}`);
|
|
params.push(minAmount);
|
|
paramCounter++;
|
|
}
|
|
|
|
if (maxAmount) {
|
|
conditions.push(`total_amount <= $${paramCounter}`);
|
|
params.push(maxAmount);
|
|
paramCounter++;
|
|
}
|
|
|
|
// Get total count for pagination
|
|
const { rows: [countResult] } = await pool.query(`
|
|
SELECT COUNT(DISTINCT o1.order_number) as total
|
|
FROM orders o1
|
|
LEFT JOIN (
|
|
SELECT order_number, SUM(price * quantity) as total_amount
|
|
FROM orders
|
|
GROUP BY order_number
|
|
) totals ON o1.order_number = totals.order_number
|
|
WHERE ${conditions.join(' AND ')}
|
|
`, params);
|
|
|
|
const total = countResult.total;
|
|
|
|
// Get paginated results
|
|
const query = `
|
|
SELECT
|
|
o1.order_number,
|
|
o1.customer,
|
|
o1.date,
|
|
o1.status,
|
|
o1.payment_method,
|
|
o1.shipping_method,
|
|
COUNT(o2.pid) as items_count,
|
|
ROUND(SUM(o2.price * o2.quantity)::numeric, 3) as total_amount
|
|
FROM orders o1
|
|
JOIN orders o2 ON o1.order_number = o2.order_number
|
|
WHERE ${conditions.join(' AND ')}
|
|
GROUP BY
|
|
o1.order_number,
|
|
o1.customer,
|
|
o1.date,
|
|
o1.status,
|
|
o1.payment_method,
|
|
o1.shipping_method
|
|
ORDER BY ${
|
|
sortColumn === 'items_count' || sortColumn === 'total_amount'
|
|
? `${sortColumn} ${sortDirection}`
|
|
: `o1.${sortColumn} ${sortDirection}`
|
|
}
|
|
LIMIT $${paramCounter} OFFSET $${paramCounter + 1}
|
|
`;
|
|
|
|
params.push(limit, offset);
|
|
const { rows } = await pool.query(query, params);
|
|
|
|
// Get order statistics
|
|
const { rows: [orderStats] } = await pool.query(`
|
|
WITH CurrentStats AS (
|
|
SELECT
|
|
COUNT(DISTINCT order_number) as total_orders,
|
|
ROUND(SUM(price * quantity)::numeric, 3) as total_revenue
|
|
FROM orders
|
|
WHERE canceled = false
|
|
AND DATE(date) >= CURRENT_DATE - INTERVAL '30 days'
|
|
),
|
|
PreviousStats AS (
|
|
SELECT
|
|
COUNT(DISTINCT order_number) as prev_orders,
|
|
ROUND(SUM(price * quantity)::numeric, 3) as prev_revenue
|
|
FROM orders
|
|
WHERE canceled = false
|
|
AND DATE(date) BETWEEN CURRENT_DATE - INTERVAL '60 days' AND CURRENT_DATE - INTERVAL '30 days'
|
|
),
|
|
OrderValues AS (
|
|
SELECT
|
|
order_number,
|
|
ROUND(SUM(price * quantity)::numeric, 3) as order_value
|
|
FROM orders
|
|
WHERE canceled = false
|
|
AND DATE(date) >= CURRENT_DATE - INTERVAL '30 days'
|
|
GROUP BY order_number
|
|
)
|
|
SELECT
|
|
cs.total_orders,
|
|
cs.total_revenue,
|
|
CASE
|
|
WHEN ps.prev_orders > 0
|
|
THEN ROUND(((cs.total_orders - ps.prev_orders)::numeric / ps.prev_orders * 100), 1)
|
|
ELSE 0
|
|
END as order_growth,
|
|
CASE
|
|
WHEN ps.prev_revenue > 0
|
|
THEN ROUND(((cs.total_revenue - ps.prev_revenue)::numeric / ps.prev_revenue * 100), 1)
|
|
ELSE 0
|
|
END as revenue_growth,
|
|
CASE
|
|
WHEN cs.total_orders > 0
|
|
THEN ROUND((cs.total_revenue::numeric / cs.total_orders), 3)
|
|
ELSE 0
|
|
END as average_order_value,
|
|
CASE
|
|
WHEN ps.prev_orders > 0
|
|
THEN ROUND((ps.prev_revenue::numeric / ps.prev_orders), 3)
|
|
ELSE 0
|
|
END as prev_average_order_value
|
|
FROM CurrentStats cs
|
|
CROSS JOIN PreviousStats ps
|
|
`);
|
|
|
|
res.json({
|
|
orders: rows.map(row => ({
|
|
...row,
|
|
total_amount: parseFloat(row.total_amount) || 0,
|
|
items_count: parseInt(row.items_count) || 0,
|
|
date: row.date
|
|
})),
|
|
pagination: {
|
|
total,
|
|
pages: Math.ceil(total / limit),
|
|
currentPage: page,
|
|
limit
|
|
},
|
|
stats: {
|
|
totalOrders: parseInt(orderStats.total_orders) || 0,
|
|
totalRevenue: parseFloat(orderStats.total_revenue) || 0,
|
|
orderGrowth: parseFloat(orderStats.order_growth) || 0,
|
|
revenueGrowth: parseFloat(orderStats.revenue_growth) || 0,
|
|
averageOrderValue: parseFloat(orderStats.average_order_value) || 0,
|
|
aovGrowth: orderStats.prev_average_order_value > 0
|
|
? ((orderStats.average_order_value - orderStats.prev_average_order_value) / orderStats.prev_average_order_value * 100)
|
|
: 0,
|
|
conversionRate: 2.5, // Placeholder - would need actual visitor data
|
|
conversionGrowth: 0.5 // Placeholder - would need actual visitor data
|
|
}
|
|
});
|
|
} catch (error) {
|
|
console.error('Error fetching orders:', error);
|
|
res.status(500).json({ error: 'Failed to fetch orders' });
|
|
}
|
|
});
|
|
|
|
// Get a single order with its items
|
|
router.get('/:orderNumber', async (req, res) => {
|
|
const pool = req.app.locals.pool;
|
|
try {
|
|
// Get order details
|
|
const { rows: orderRows } = await pool.query(`
|
|
SELECT DISTINCT
|
|
o1.order_number,
|
|
o1.customer,
|
|
o1.date,
|
|
o1.status,
|
|
o1.payment_method,
|
|
o1.shipping_method,
|
|
o1.shipping_address,
|
|
o1.billing_address,
|
|
COUNT(o2.pid) as items_count,
|
|
ROUND(SUM(o2.price * o2.quantity)::numeric, 3) as total_amount
|
|
FROM orders o1
|
|
JOIN orders o2 ON o1.order_number = o2.order_number
|
|
WHERE o1.order_number = $1 AND o1.canceled = false
|
|
GROUP BY
|
|
o1.order_number,
|
|
o1.customer,
|
|
o1.date,
|
|
o1.status,
|
|
o1.payment_method,
|
|
o1.shipping_method,
|
|
o1.shipping_address,
|
|
o1.billing_address
|
|
`, [req.params.orderNumber]);
|
|
|
|
if (orderRows.length === 0) {
|
|
return res.status(404).json({ error: 'Order not found' });
|
|
}
|
|
|
|
// Get order items
|
|
const { rows: itemRows } = await pool.query(`
|
|
SELECT
|
|
o.pid,
|
|
p.title,
|
|
p.SKU,
|
|
o.quantity,
|
|
o.price,
|
|
ROUND((o.price * o.quantity)::numeric, 3) as total
|
|
FROM orders o
|
|
JOIN products p ON o.pid = p.pid
|
|
WHERE o.order_number = $1 AND o.canceled = false
|
|
`, [req.params.orderNumber]);
|
|
|
|
const order = {
|
|
...orderRows[0],
|
|
total_amount: parseFloat(orderRows[0].total_amount) || 0,
|
|
items_count: parseInt(orderRows[0].items_count) || 0,
|
|
items: itemRows.map(item => ({
|
|
...item,
|
|
price: parseFloat(item.price) || 0,
|
|
total: parseFloat(item.total) || 0,
|
|
quantity: parseInt(item.quantity) || 0
|
|
}))
|
|
};
|
|
|
|
res.json(order);
|
|
} catch (error) {
|
|
console.error('Error fetching order:', error);
|
|
res.status(500).json({ error: 'Failed to fetch order' });
|
|
}
|
|
});
|
|
|
|
module.exports = router;
|