Fix and update bestsellers component

This commit is contained in:
2025-01-18 01:01:37 -05:00
parent 1b4447f886
commit 9003300d0d
2 changed files with 240 additions and 90 deletions

View File

@@ -440,62 +440,194 @@ router.get('/overstock/products', async (req, res) => {
router.get('/best-sellers', async (req, res) => { router.get('/best-sellers', async (req, res) => {
try { try {
const [products] = await executeQuery(` const [products] = await executeQuery(`
WITH product_sales AS (
SELECT SELECT
p.product_id, p.product_id,
p.SKU, p.SKU as sku,
p.title, p.title,
p.brand, -- Current period (last 30 days)
p.vendor, SUM(CASE
pm.total_revenue, WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
pm.daily_sales_avg, THEN o.quantity
pm.number_of_orders, ELSE 0
SUM(o.quantity) as units_sold, END) as units_sold,
GROUP_CONCAT(c.name) as categories SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as revenue,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN (o.price - p.cost_price) * o.quantity
ELSE 0
END) as profit,
-- Previous period (30-60 days ago)
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as previous_revenue
FROM products p FROM products p
JOIN product_metrics pm ON p.product_id = pm.product_id JOIN orders o ON p.product_id = o.product_id
LEFT JOIN orders o ON p.product_id = o.product_id AND o.canceled = false WHERE o.canceled = false
LEFT JOIN product_categories pc ON p.product_id = pc.product_id AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
LEFT JOIN categories c ON pc.category_id = c.id GROUP BY p.product_id, p.SKU, p.title
GROUP BY p.product_id )
ORDER BY pm.total_revenue DESC SELECT
LIMIT 10 product_id,
sku,
title,
units_sold,
revenue,
profit,
CASE
WHEN previous_revenue > 0
THEN ((revenue - previous_revenue) / previous_revenue * 100)
WHEN revenue > 0
THEN 100
ELSE 0
END as growth_rate
FROM product_sales
WHERE units_sold > 0
ORDER BY revenue DESC
LIMIT 50
`); `);
const [vendors] = await executeQuery(` const [brands] = await executeQuery(`
WITH brand_sales AS (
SELECT SELECT
vm.*, p.brand,
COALESCE(SUM(o.quantity), 0) as products_sold -- Current period (last 30 days)
FROM vendor_metrics vm SUM(CASE
LEFT JOIN orders o ON vm.vendor = o.vendor AND o.canceled = false WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
GROUP BY vm.vendor THEN o.quantity
ORDER BY vm.total_revenue DESC ELSE 0
LIMIT 10 END) as units_sold,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as revenue,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN (o.price - p.cost_price) * o.quantity
ELSE 0
END) as profit,
-- Previous period (30-60 days ago)
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as previous_revenue
FROM products p
JOIN orders o ON p.product_id = o.product_id
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
AND p.brand IS NOT NULL
GROUP BY p.brand
)
SELECT
brand,
units_sold,
revenue,
profit,
CASE
WHEN previous_revenue > 0
THEN ((revenue - previous_revenue) / previous_revenue * 100)
WHEN revenue > 0
THEN 100
ELSE 0
END as growth_rate
FROM brand_sales
WHERE units_sold > 0
ORDER BY revenue DESC
LIMIT 50
`); `);
const [categories] = await executeQuery(` const [categories] = await executeQuery(`
WITH category_sales AS (
SELECT SELECT
c.id as category_id,
c.name, c.name,
cm.* -- Current period (last 30 days)
FROM category_metrics cm SUM(CASE
JOIN categories c ON cm.category_id = c.id WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
ORDER BY cm.total_value DESC THEN o.quantity
LIMIT 10 ELSE 0
END) as units_sold,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as revenue,
SUM(CASE
WHEN o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN (o.price - p.cost_price) * o.quantity
ELSE 0
END) as profit,
-- Previous period (30-60 days ago)
SUM(CASE
WHEN o.date BETWEEN DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY) AND DATE_SUB(CURRENT_DATE, INTERVAL 30 DAY)
THEN o.price * o.quantity
ELSE 0
END) as previous_revenue
FROM categories c
JOIN product_categories pc ON c.id = pc.category_id
JOIN products p ON pc.product_id = p.product_id
JOIN orders o ON p.product_id = o.product_id
WHERE o.canceled = false
AND o.date >= DATE_SUB(CURRENT_DATE, INTERVAL 60 DAY)
GROUP BY c.id, c.name
)
SELECT
category_id,
name,
units_sold,
revenue,
profit,
CASE
WHEN previous_revenue > 0
THEN ((revenue - previous_revenue) / previous_revenue * 100)
WHEN revenue > 0
THEN 100
ELSE 0
END as growth_rate
FROM category_sales
WHERE units_sold > 0
ORDER BY revenue DESC
LIMIT 50
`); `);
// Format response with explicit type conversion // Format response with explicit type conversion
const formattedProducts = products.map(p => ({ const formattedProducts = products.map(p => ({
...p, ...p,
total_revenue: parseFloat(p.total_revenue) || 0,
daily_sales_avg: parseFloat(p.daily_sales_avg) || 0,
number_of_orders: parseInt(p.number_of_orders) || 0,
units_sold: parseInt(p.units_sold) || 0, units_sold: parseInt(p.units_sold) || 0,
categories: p.categories ? p.categories.split(',') : [] revenue: parseFloat(p.revenue) || 0,
profit: parseFloat(p.profit) || 0,
growth_rate: parseFloat(p.growth_rate) || 0
}));
const formattedBrands = brands.map(b => ({
brand: b.brand,
units_sold: parseInt(b.units_sold) || 0,
revenue: parseFloat(b.revenue) || 0,
profit: parseFloat(b.profit) || 0,
growth_rate: parseFloat(b.growth_rate) || 0
}));
const formattedCategories = categories.map(c => ({
category_id: c.category_id,
name: c.name,
units_sold: parseInt(c.units_sold) || 0,
revenue: parseFloat(c.revenue) || 0,
profit: parseFloat(c.profit) || 0,
growth_rate: parseFloat(c.growth_rate) || 0
})); }));
res.json({ res.json({
products: formattedProducts, products: formattedProducts,
vendors, brands: formattedBrands,
categories categories: formattedCategories
}); });
} catch (err) { } catch (err) {
console.error('Error fetching best sellers:', err); console.error('Error fetching best sellers:', err);

View File

@@ -13,20 +13,21 @@ interface BestSellerProduct {
units_sold: number units_sold: number
revenue: number revenue: number
profit: number profit: number
growth_rate: number
} }
interface BestSellerVendor { interface BestSellerBrand {
vendor: string brand: string
products_sold: number units_sold: number
revenue: number revenue: number
profit: number profit: number
order_fill_rate: number growth_rate: number
} }
interface BestSellerCategory { interface BestSellerCategory {
category_id: number category_id: number
name: string name: string
products_sold: number units_sold: number
revenue: number revenue: number
profit: number profit: number
growth_rate: number growth_rate: number
@@ -34,7 +35,7 @@ interface BestSellerCategory {
interface BestSellersData { interface BestSellersData {
products: BestSellerProduct[] products: BestSellerProduct[]
vendors: BestSellerVendor[] brands: BestSellerBrand[]
categories: BestSellerCategory[] categories: BestSellerCategory[]
} }
@@ -52,49 +53,58 @@ export function BestSellers() {
return ( return (
<> <>
<Tabs defaultValue="products">
<CardHeader> <CardHeader>
<div className="flex flex-row items-center justify-between"> <div className="flex flex-row items-center justify-between">
<CardTitle className="text-lg font-medium">Best Sellers</CardTitle> <CardTitle className="text-lg font-medium">Best Sellers</CardTitle>
<Tabs defaultValue="products">
<TabsList> <TabsList>
<TabsTrigger value="products">Products</TabsTrigger> <TabsTrigger value="products">Products</TabsTrigger>
<TabsTrigger value="vendors">Vendors</TabsTrigger> <TabsTrigger value="brands">Brands</TabsTrigger>
<TabsTrigger value="categories">Categories</TabsTrigger> <TabsTrigger value="categories">Categories</TabsTrigger>
</TabsList> </TabsList>
</Tabs>
</div> </div>
</CardHeader> </CardHeader>
<CardContent> <CardContent>
<Tabs defaultValue="products">
<TabsContent value="products"> <TabsContent value="products">
<ScrollArea className="h-[400px] w-full"> <ScrollArea className="h-[400px] w-full">
<Table> <Table>
<TableHeader> <TableHeader>
<TableRow> <TableRow>
<TableHead>Product</TableHead> <TableHead className="w-[40%]">Product</TableHead>
<TableHead className="text-right">Units</TableHead> <TableHead className="w-[15%] text-right">Sales</TableHead>
<TableHead className="text-right">Revenue</TableHead> <TableHead className="w-[15%] text-right">Revenue</TableHead>
<TableHead className="text-right">Profit</TableHead> <TableHead className="w-[15%] text-right">Profit</TableHead>
<TableHead className="w-[15%] text-right">Growth</TableHead>
</TableRow> </TableRow>
</TableHeader> </TableHeader>
<TableBody> <TableBody>
{data?.products.map((product) => ( {data?.products.map((product) => (
<TableRow key={product.product_id}> <TableRow key={product.product_id}>
<TableCell> <TableCell className="w-[40%]">
<div> <div>
<p className="font-medium">{product.title}</p> <a
href={`https://backend.acherryontop.com/product/${product.product_id}`}
target="_blank"
rel="noopener noreferrer"
className="font-medium hover:underline"
>
{product.title}
</a>
<p className="text-sm text-muted-foreground">{product.sku}</p> <p className="text-sm text-muted-foreground">{product.sku}</p>
</div> </div>
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{product.units_sold.toLocaleString()} {product.units_sold.toLocaleString()}
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{formatCurrency(product.revenue)} {formatCurrency(product.revenue)}
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{formatCurrency(product.profit)} {formatCurrency(product.profit)}
</TableCell> </TableCell>
<TableCell className="w-[15%] text-right">
{product.growth_rate > 0 ? '+' : ''}{product.growth_rate.toFixed(1)}%
</TableCell>
</TableRow> </TableRow>
))} ))}
</TableBody> </TableBody>
@@ -102,31 +112,35 @@ export function BestSellers() {
</ScrollArea> </ScrollArea>
</TabsContent> </TabsContent>
<TabsContent value="vendors"> <TabsContent value="brands">
<ScrollArea className="h-[400px] w-full"> <ScrollArea className="h-[400px] w-full">
<Table> <Table>
<TableHeader> <TableHeader>
<TableRow> <TableRow>
<TableHead>Vendor</TableHead> <TableHead className="w-[40%]">Brand</TableHead>
<TableHead className="text-right">Products</TableHead> <TableHead className="w-[15%] text-right">Sales</TableHead>
<TableHead className="text-right">Revenue</TableHead> <TableHead className="w-[15%] text-right">Revenue</TableHead>
<TableHead className="text-right">Fill Rate</TableHead> <TableHead className="w-[15%] text-right">Profit</TableHead>
<TableHead className="w-[15%] text-right">Growth</TableHead>
</TableRow> </TableRow>
</TableHeader> </TableHeader>
<TableBody> <TableBody>
{data?.vendors.map((vendor) => ( {data?.brands.map((brand) => (
<TableRow key={vendor.vendor}> <TableRow key={brand.brand}>
<TableCell> <TableCell className="w-[40%]">
<p className="font-medium">{vendor.vendor}</p> <p className="font-medium">{brand.brand}</p>
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{vendor.products_sold.toLocaleString()} {brand.units_sold.toLocaleString()}
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{formatCurrency(vendor.revenue)} {formatCurrency(brand.revenue)}
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{vendor.order_fill_rate.toFixed(1)}% {formatCurrency(brand.profit)}
</TableCell>
<TableCell className="w-[15%] text-right">
{brand.growth_rate > 0 ? '+' : ''}{brand.growth_rate.toFixed(1)}%
</TableCell> </TableCell>
</TableRow> </TableRow>
))} ))}
@@ -140,26 +154,30 @@ export function BestSellers() {
<Table> <Table>
<TableHeader> <TableHeader>
<TableRow> <TableRow>
<TableHead>Category</TableHead> <TableHead className="w-[40%]">Category</TableHead>
<TableHead className="text-right">Products</TableHead> <TableHead className="w-[15%] text-right">Sales</TableHead>
<TableHead className="text-right">Revenue</TableHead> <TableHead className="w-[15%] text-right">Revenue</TableHead>
<TableHead className="text-right">Growth</TableHead> <TableHead className="w-[15%] text-right">Profit</TableHead>
<TableHead className="w-[15%] text-right">Growth</TableHead>
</TableRow> </TableRow>
</TableHeader> </TableHeader>
<TableBody> <TableBody>
{data?.categories.map((category) => ( {data?.categories.map((category) => (
<TableRow key={category.category_id}> <TableRow key={category.category_id}>
<TableCell> <TableCell className="w-[40%]">
<p className="font-medium">{category.name}</p> <p className="font-medium">{category.name}</p>
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{category.products_sold.toLocaleString()} {category.units_sold.toLocaleString()}
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{formatCurrency(category.revenue)} {formatCurrency(category.revenue)}
</TableCell> </TableCell>
<TableCell className="text-right"> <TableCell className="w-[15%] text-right">
{category.growth_rate.toFixed(1)}% {formatCurrency(category.profit)}
</TableCell>
<TableCell className="w-[15%] text-right">
{category.growth_rate > 0 ? '+' : ''}{category.growth_rate.toFixed(1)}%
</TableCell> </TableCell>
</TableRow> </TableRow>
))} ))}
@@ -167,8 +185,8 @@ export function BestSellers() {
</Table> </Table>
</ScrollArea> </ScrollArea>
</TabsContent> </TabsContent>
</Tabs>
</CardContent> </CardContent>
</Tabs>
</> </>
) )
} }