= Напредни извештаи од базата (SQL, складирани процедури и релациона алгебра) = --- == 2. Месечен тренд на продажба (Monthly Sales Growth Trend) == Ги споредува приходите од тековниот месец со претходниот за да го пресмета процентот на раст или пад на бизнисот. {{{#!sql WITH MonthlySales AS ( SELECT DATE_TRUNC('month', date_time) AS sales_month, SUM(total_amount) AS revenue FROM sale GROUP BY 1 ) SELECT sales_month, revenue AS current_month_revenue, LAG(revenue) OVER (ORDER BY sales_month) AS previous_month_revenue, ROUND(((revenue - LAG(revenue) OVER (ORDER BY sales_month)) / NULLIF(LAG(revenue) OVER (ORDER BY sales_month), 0)) * 100, 2) AS growth_percentage FROM MonthlySales; }}} '''Релациона алгебра:''' {{{ MonthlySales ← γ DATE_TRUNC('month', date_time) → sales_month; SUM(total_amount) → revenue (sale) Result ← π sales_month, revenue → current_month_revenue, LAG(revenue) → previous_month_revenue, ROUND(((revenue - LAG(revenue)) / NULLIF(LAG(revenue), 0)) × 100, 2) → growth_percentage (τ sales_month ASC (MonthlySales)) }}} ---- == 3. Состојба на залихи и критични точки (Inventory Health & Reorder Levels) == Ги идентификува производите што се под минимумот во магацините и дава аларм за итна набавка. {{{#!sql SELECT p.name AS product_name, w.name AS warehouse_location, ws.quantity_on_hand, p.reorder_level, CASE WHEN ws.quantity_on_hand <= p.reorder_level THEN 'CRITICAL: REORDER' WHEN ws.quantity_on_hand <= p.reorder_level * 1.5 THEN 'WARNING: LOW' ELSE 'HEALTHY' END AS stock_status FROM product p JOIN warehouse_stock ws ON p.product_id = ws.product_id JOIN warehouse w ON ws.warehouse_id = w.warehouse_id; }}} '''Релациона алгебра:''' {{{ Temp1 ← product ⨝ product_id=product_id warehouse_stock Temp2 ← Temp1 ⨝ warehouse_id=warehouse_id warehouse Result ← π product.name → product_name, warehouse.name → warehouse_location, quantity_on_hand, reorder_level, CASE(quantity_on_hand ≤ reorder_level → 'CRITICAL: REORDER', quantity_on_hand ≤ reorder_level × 1.5 → 'WARNING: LOW', ELSE → 'HEALTHY') → stock_status (Temp2) }}} ---- == 6. Искористеност на капацитетот на магацините == Пресметува колкав процент од физичкиот простор во секој магацин е моментално пополнет. {{{#!sql SELECT w.name AS warehouse_name, w.capacity AS total_unit_capacity, SUM(ws.quantity_on_hand) AS units_in_stock, ROUND((SUM(ws.quantity_on_hand)::NUMERIC / w.capacity) * 100, 2) AS occupancy_percentage FROM warehouse w LEFT JOIN warehouse_stock ws ON w.warehouse_id = ws.warehouse_id GROUP BY w.warehouse_id, w.name, w.capacity; }}} '''Релациона алгебра:''' {{{ Temp1 ← warehouse ⟕ warehouse_id=warehouse_id warehouse_stock Result ← γ warehouse_id, name → warehouse_name, capacity → total_unit_capacity; SUM(quantity_on_hand) → units_in_stock, ROUND((SUM(quantity_on_hand) / capacity) × 100, 2) → occupancy_percentage (Temp1) }}} ---- == 7. Анализа на застојни производи == Ги прикажува производите што не се продале во последните 90 дена и само зафаќаат простор и капитал. {{{#!sql SELECT p.name AS product_name, p.sku, ws.quantity_on_hand, COALESCE(MAX(s.date_time)::TEXT, 'NO SALES RECORDED') AS last_sold_date FROM product p JOIN warehouse_stock ws ON p.product_id = ws.product_id LEFT JOIN sale_item si ON p.product_id = si.product_id LEFT JOIN sale s ON si.sale_id = s.sale_id GROUP BY p.product_id, p.name, p.sku, ws.quantity_on_hand HAVING MAX(s.date_time) < CURRENT_DATE - INTERVAL '90 days' OR MAX(s.date_time) IS NULL; }}} '''Релациона алгебра:''' {{{ Temp1 ← product ⨝ product_id=product_id warehouse_stock Temp2 ← Temp1 ⟕ product_id=product_id sale_item Temp3 ← Temp2 ⟕ sale_id=sale_id sale Temp4 ← γ product_id, name, sku, quantity_on_hand; MAX(date_time) → last_sold_date (Temp3) Result ← π name → product_name, sku, quantity_on_hand, COALESCE(last_sold_date::TEXT, 'NO SALES RECORDED') → last_sold_date (σ last_sold_date < CURRENT_DATE - 90 ∨ last_sold_date IS NULL (Temp4)) }}} ---- '''Релациона алгебра:''' {{{ Temp1 ← ρ si1 (sale_item) Temp2 ← ρ si2 (sale_item) Temp3 ← σ si1.sale_id = si2.sale_id ∧ si1.product_id < si2.product_id (Temp1 × Temp2) Temp4 ← Temp3 ⨝ si1.product_id = p1.product_id (ρ p1 (product)) Temp5 ← Temp4 ⨝ si2.product_id = p2.product_id (ρ p2 (product)) Temp6 ← γ p1.name → product_a, p2.name → product_b; COUNT(*) → pair_occurrence_count (Temp5) Result ← δ 10 (τ pair_occurrence_count DESC (Temp6)) }}} ---- '''Релациона алгебра:''' {{{ LatestCost(product_id) ← π product_id, unit_cost (δ 1 (τ po_id DESC (purchase_order_item))) Temp1 ← warehouse ⨝ warehouse_id=warehouse_id warehouse_stock Temp2 ← Temp1 ⨝ product_id=product_id LatestCost Result ← γ warehouse.name → warehouse_location; SUM(quantity_on_hand × unit_cost) → total_inventory_valuation_mkd (Temp2) }}} ---- '''Символи и операции:''' * π - проекција (SELECT) * σ - селекција (WHERE) * ⨝ - природен спој (JOIN) * ⟕ - left outer join (LEFT JOIN) * × - Декартов производ (CROSS JOIN) * γ - групирање (GROUP BY) * τ - сортирање (ORDER BY) * δ - лимит (LIMIT) * ρ - преименување (AS / alias) * ∧ - логичко И (AND) * ∨ - логичко ИЛИ (OR)