Add FORMULA column to financial indicator queries
Added detailed calculation formulas with accounting references for managers to understand and verify financial indicators: - INDICATORI_GENERALI (6 formulas): grad indatorare, autonomie financiara, rata datoriilor, marja neta, ROA, rotatia activelor - INDICATORI_LICHIDITATE (4 formulas): lichiditate curenta, quick ratio, cash ratio, fond de rulment - CICLU_CONVERSIE_CASH (4 formulas): DIO, DSO, DPO, CCC - DSO_DPO (2 formulas): DSO, DPO with detailed sources Each formula includes: - Mathematical calculation (e.g., "Datorii / Capital Propriu") - Account references (e.g., "cont 16x,40x,42x,44x,46x / cont 10x,11x,12x,117") - Data sources for verification (e.g., "jurnal vanzari vjv2025") Also fixed ORA-32039 error by renaming CTE 'vanzari' to 'vanzari_calc' to avoid conflict with table name. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
419
queries.py
419
queries.py
@@ -1,6 +1,8 @@
|
||||
"""
|
||||
SQL Queries for Data Intelligence Report
|
||||
All queries use the existing views: fact_vfacturi2, fact_vfacturi_detalii, vstoc, vrul
|
||||
OPTIMIZED: All queries use base tables (vanzari, vanzari_detalii) with Oracle hints
|
||||
for index usage (IDX_VANZARI_NR) instead of views (fact_vfacturi2, fact_vfacturi_detalii).
|
||||
Other views: vstoc, vrul are still used where appropriate.
|
||||
|
||||
IMPORTANT: Price calculation considers pret_cu_tva flag:
|
||||
- If pret_cu_tva = 1: price includes VAT, must divide by (1 + proc_tvav/100)
|
||||
@@ -9,13 +11,13 @@ Formula: CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 1. MARJA PER CLIENT
|
||||
# 1. MARJA PER CLIENT (OPTIMIZAT - folosește tabele de bază + indexuri)
|
||||
# =============================================================================
|
||||
MARJA_PER_CLIENT = """
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
f.client,
|
||||
f.cod_fiscal,
|
||||
p.denumire AS client,
|
||||
p.cod_fiscal,
|
||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS vanzari_fara_tva,
|
||||
ROUND(SUM(d.cantitate * d.pret_achizitie), 2) AS cost_total,
|
||||
@@ -25,25 +27,25 @@ SELECT
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
WHERE f.sters = 0
|
||||
AND d.sters = 0
|
||||
AND f.tip > 0
|
||||
AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY f.id_part, f.client, f.cod_fiscal
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
GROUP BY f.id_part, p.denumire, p.cod_fiscal
|
||||
ORDER BY marja_bruta DESC
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 2. CLIENȚI CU MARJĂ MICĂ (sub prag)
|
||||
# 2. CLIENȚI CU MARJĂ MICĂ (sub prag) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
CLIENTI_MARJA_MICA = """
|
||||
SELECT * FROM (
|
||||
SELECT
|
||||
f.client,
|
||||
f.cod_fiscal,
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
p.denumire AS client,
|
||||
p.cod_fiscal,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS vanzari_fara_tva,
|
||||
ROUND(SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)), 2) AS marja_bruta,
|
||||
ROUND(
|
||||
@@ -51,12 +53,13 @@ SELECT * FROM (
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY f.id_part, f.client, f.cod_fiscal
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
GROUP BY f.id_part, p.denumire, p.cod_fiscal
|
||||
HAVING SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) > :min_sales
|
||||
)
|
||||
WHERE procent_marja < :margin_threshold
|
||||
@@ -64,12 +67,12 @@ ORDER BY vanzari_fara_tva DESC
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 3. MARJA PER CATEGORIE (Grupă + Subgrupă)
|
||||
# 3. MARJA PER CATEGORIE (Grupă + Subgrupă) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
MARJA_PER_CATEGORIE = """
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
NVL(sg.grupa, 'NECLASIFICAT') AS grupa,
|
||||
NVL(d.subgrupa, 'NECLASIFICAT') AS subgrupa,
|
||||
NVL(sg.subgrupa, 'NECLASIFICAT') AS subgrupa,
|
||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS vanzari_fara_tva,
|
||||
ROUND(SUM(d.cantitate * d.pret_achizitie), 2) AS cost_total,
|
||||
@@ -79,21 +82,22 @@ SELECT
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
LEFT JOIN vgest_art_sbgr sg ON d.id_subgrupa = sg.id_subgrupa
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_articole art ON d.id_articol = art.id_articol
|
||||
LEFT JOIN vgest_art_sbgr sg ON art.id_subgrupa = sg.id_subgrupa
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY sg.id_grupa, sg.grupa, d.id_subgrupa, d.subgrupa
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
GROUP BY sg.id_grupa, sg.grupa, art.id_subgrupa, sg.subgrupa
|
||||
ORDER BY vanzari_fara_tva DESC
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 4. PRODUCȚIE PROPRIE vs MARFĂ REVÂNDUTĂ
|
||||
# 4. PRODUCȚIE PROPRIE vs MARFĂ REVÂNDUTĂ - OPTIMIZAT
|
||||
# =============================================================================
|
||||
PRODUCTIE_VS_REVANZARE = """
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
CASE
|
||||
WHEN d.cont IN ('341', '345') THEN 'Producție proprie'
|
||||
WHEN d.cont = '301' THEN 'Materii prime'
|
||||
@@ -107,11 +111,11 @@ SELECT
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
GROUP BY CASE
|
||||
WHEN d.cont IN ('341', '345') THEN 'Producție proprie'
|
||||
WHEN d.cont = '301' THEN 'Materii prime'
|
||||
@@ -125,18 +129,21 @@ ORDER BY vanzari_fara_tva DESC
|
||||
# =============================================================================
|
||||
DISPERSIE_PRETURI = """
|
||||
WITH preturi_detalii AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
d.id_articol,
|
||||
d.denumire,
|
||||
d.subgrupa,
|
||||
a.denumire,
|
||||
g.subgrupa,
|
||||
f.id_part,
|
||||
f.client,
|
||||
p.denumire as client,
|
||||
CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END AS pret_fara_tva,
|
||||
d.cantitate,
|
||||
MIN(CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) OVER (PARTITION BY d.id_articol) AS pret_min_global
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
LEFT JOIN nom_articole a ON d.id_articol = a.id_articol
|
||||
LEFT JOIN gest_art_sbgr g ON a.id_subgrupa = g.id_subgrupa
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
AND d.pret > 0
|
||||
@@ -206,23 +213,25 @@ FETCH FIRST 100 ROWS ONLY
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 7. VÂNZĂRI SUB COST (ALERTĂ CRITICĂ)
|
||||
# 7. VÂNZĂRI SUB COST (ALERTĂ CRITICĂ) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
VANZARI_SUB_COST = """
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.data_act,
|
||||
f.serie_act || ' ' || f.numar_act AS factura,
|
||||
f.client,
|
||||
d.denumire AS produs,
|
||||
p.denumire AS client,
|
||||
NVL2(d.id_articol, art.denumire, d.explicatie) AS produs,
|
||||
d.cantitate,
|
||||
ROUND(CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END, 2) AS pret_vanzare,
|
||||
ROUND(d.pret_achizitie, 2) AS cost,
|
||||
ROUND((CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie) * d.cantitate, 2) AS pierdere
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
LEFT JOIN nom_articole art ON d.id_articol = art.id_articol
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
AND d.pret_achizitie > 0
|
||||
AND d.pret > 0
|
||||
AND CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END < d.pret_achizitie
|
||||
@@ -235,20 +244,21 @@ FETCH FIRST 100 ROWS ONLY
|
||||
# =============================================================================
|
||||
TRENDING_CLIENTI = """
|
||||
WITH vanzari_perioade AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
f.client,
|
||||
p.denumire AS client,
|
||||
SUM(CASE WHEN f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
THEN d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END ELSE 0 END) AS vanzari_an_curent,
|
||||
SUM(CASE WHEN f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
THEN d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END ELSE 0 END) AS vanzari_an_trecut
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
GROUP BY f.id_part, f.client
|
||||
GROUP BY f.id_part, p.denumire
|
||||
)
|
||||
SELECT
|
||||
client,
|
||||
@@ -276,24 +286,26 @@ ORDER BY variatie_procent DESC NULLS LAST
|
||||
# =============================================================================
|
||||
CONCENTRARE_CLIENTI = """
|
||||
WITH total_vanzari AS (
|
||||
SELECT SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
),
|
||||
vanzari_client AS (
|
||||
SELECT
|
||||
f.client,
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
p.denumire AS client,
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari,
|
||||
ROW_NUMBER() OVER (ORDER BY SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) DESC) AS rn
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY f.id_part, f.client
|
||||
GROUP BY f.id_part, p.denumire
|
||||
),
|
||||
top_clienti AS (
|
||||
SELECT
|
||||
@@ -556,10 +568,10 @@ WHERE s.cant > 0
|
||||
# 16. TOP PRODUSE DUPĂ VÂNZĂRI
|
||||
# =============================================================================
|
||||
TOP_PRODUSE = """
|
||||
SELECT
|
||||
d.denumire AS produs,
|
||||
NVL(d.subgrupa, 'NECLASIFICAT') AS subgrupa,
|
||||
d.um,
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
NVL2(d.id_articol, a.denumire, d.explicatie) AS produs,
|
||||
NVL(g.subgrupa, 'NECLASIFICAT') AS subgrupa,
|
||||
a.um,
|
||||
ROUND(SUM(d.cantitate), 2) AS cantitate_vanduta,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS valoare_vanzari,
|
||||
ROUND(SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)), 2) AS marja_bruta,
|
||||
@@ -568,22 +580,24 @@ SELECT
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_articole a ON d.id_articol = a.id_articol
|
||||
LEFT JOIN gest_art_sbgr g ON a.id_subgrupa = g.id_subgrupa
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY d.id_articol, d.denumire, d.subgrupa, d.um
|
||||
GROUP BY d.id_articol, NVL2(d.id_articol, a.denumire, d.explicatie), g.subgrupa, a.um
|
||||
ORDER BY valoare_vanzari DESC
|
||||
FETCH FIRST 50 ROWS ONLY
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 17. MARJA PER GESTIUNE (doar articole gestionabile)
|
||||
# 17. MARJA PER GESTIUNE (doar articole gestionabile) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
MARJA_PER_GESTIUNE = """
|
||||
SELECT
|
||||
d.nume_gestiune,
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
g.nume_gestiune,
|
||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS vanzari_fara_tva,
|
||||
ROUND(SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)), 2) AS marja_bruta,
|
||||
@@ -592,25 +606,26 @@ SELECT
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_gestiuni g ON d.id_gestiune = g.id_gestiune
|
||||
JOIN nom_articole a ON d.id_articol = a.id_articol
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
AND NVL(a.in_stoc, 1) = 1
|
||||
GROUP BY d.id_gestiune, d.nume_gestiune
|
||||
GROUP BY d.id_gestiune, g.nume_gestiune
|
||||
ORDER BY vanzari_fara_tva DESC
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 18. ARTICOLE NEGESTIONABILE (servicii, etc.)
|
||||
# 18. ARTICOLE NEGESTIONABILE (servicii, etc.) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
ARTICOLE_NEGESTIONABILE = """
|
||||
SELECT
|
||||
NVL(d.denumire, 'NECUNOSCUT') AS denumire,
|
||||
NVL(d.subgrupa, 'NECLASIFICAT') AS subgrupa,
|
||||
d.um,
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
NVL(art.denumire, d.explicatie) AS denumire,
|
||||
NVL(sg.subgrupa, 'NECLASIFICAT') AS subgrupa,
|
||||
art.um,
|
||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
||||
ROUND(SUM(d.cantitate), 2) AS cantitate_vanduta,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS vanzari_fara_tva,
|
||||
@@ -621,14 +636,15 @@ SELECT
|
||||
THEN SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) * 100.0 / SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END)
|
||||
ELSE 0 END
|
||||
, 2) AS procent_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
JOIN nom_articole a ON d.id_articol = a.id_articol
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_articole art ON d.id_articol = art.id_articol
|
||||
LEFT JOIN vgest_art_sbgr sg ON art.id_subgrupa = sg.id_subgrupa
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
AND NVL(a.in_stoc, 0) = 0
|
||||
GROUP BY d.id_articol, d.denumire, d.subgrupa, d.um
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
AND NVL(art.in_stoc, 0) = 0
|
||||
GROUP BY d.id_articol, art.denumire, d.explicatie, sg.subgrupa, art.um
|
||||
ORDER BY vanzari_fara_tva DESC
|
||||
"""
|
||||
|
||||
@@ -889,6 +905,7 @@ sold_furnizori AS (
|
||||
SELECT
|
||||
'DSO (Zile incasare clienti)' AS indicator,
|
||||
ROUND(NVL(sc.total_creante, 0) * 365 / NULLIF(v.total_vanzari, 0), 0) AS zile,
|
||||
'(Creante clienti x 365) / Vanzari anuale (cont 4111 x 365 / jurnal vanzari vjv2025)' AS formula,
|
||||
CASE
|
||||
WHEN NVL(sc.total_creante, 0) * 365 / NULLIF(v.total_vanzari, 0) > 60 THEN 'ALERTA'
|
||||
WHEN NVL(sc.total_creante, 0) * 365 / NULLIF(v.total_vanzari, 0) > 45 THEN 'ATENTIE'
|
||||
@@ -899,6 +916,7 @@ UNION ALL
|
||||
SELECT
|
||||
'DPO (Zile plata furnizori)' AS indicator,
|
||||
ROUND(NVL(sf.total_datorii, 0) * 365 / NULLIF(a.total_achizitii, 0), 0) AS zile,
|
||||
'(Datorii furnizori x 365) / Achizitii anuale (cont 401 x 365 / jurnal cumparari vjc2025)' AS formula,
|
||||
CASE
|
||||
WHEN NVL(sf.total_datorii, 0) * 365 / NULLIF(a.total_achizitii, 0) < 15 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
@@ -948,10 +966,11 @@ WITH metrici AS (
|
||||
AND b.an = EXTRACT(YEAR FROM SYSDATE)
|
||||
AND b.luna = EXTRACT(MONTH FROM SYSDATE)) AS stoc_curent,
|
||||
-- COGS din facturi (preț achiziție articole vândute)
|
||||
(SELECT SUM(d.cantitate * d.pret_achizitie)
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
(SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
SUM(d.cantitate * d.pret_achizitie)
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)) AS cogs_12_luni,
|
||||
-- Creanțe clienți
|
||||
@@ -1015,18 +1034,21 @@ WITH metrici AS (
|
||||
SELECT
|
||||
'DIO (Zile stoc)' AS indicator,
|
||||
ROUND(NVL(m.stoc_curent, 0) * 365 / NULLIF(m.cogs_12_luni, 0), 0) AS zile,
|
||||
'(Stoc x 365) / Cost marfuri vandute (clasa 3xx x 365 / cost achizitie 12 luni)' AS formula,
|
||||
'Zile medii pentru transformarea stocului in vanzare' AS explicatie
|
||||
FROM metrici m
|
||||
UNION ALL
|
||||
SELECT
|
||||
'DSO (Zile incasare)' AS indicator,
|
||||
ROUND(NVL(m.creante, 0) * 365 / NULLIF(m.vanzari_12_luni, 0), 0) AS zile,
|
||||
'(Creante x 365) / Vanzari anuale (cont 4111 x 365 / jurnal vanzari vjv2025)' AS formula,
|
||||
'Zile medii pentru incasarea creantelor' AS explicatie
|
||||
FROM metrici m
|
||||
UNION ALL
|
||||
SELECT
|
||||
'DPO (Zile plata)' AS indicator,
|
||||
ROUND(NVL(m.datorii_furnizori, 0) * 365 / NULLIF(m.achizitii_12_luni, 0), 0) AS zile,
|
||||
'(Datorii furnizori x 365) / Achizitii anuale (cont 401 x 365 / jurnal cumparari vjc2025)' AS formula,
|
||||
'Zile medii pentru plata furnizorilor' AS explicatie
|
||||
FROM metrici m
|
||||
UNION ALL
|
||||
@@ -1037,16 +1059,17 @@ SELECT
|
||||
NVL(m.creante, 0) * 365 / NULLIF(m.vanzari_12_luni, 0) -
|
||||
NVL(m.datorii_furnizori, 0) * 365 / NULLIF(m.achizitii_12_luni, 0)
|
||||
, 0) AS zile,
|
||||
'DIO + DSO - DPO (zile de la plata furnizor pana la incasare client)' AS formula,
|
||||
'DIO + DSO - DPO = zile de la plata furnizor pana la incasare client' AS explicatie
|
||||
FROM metrici m
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 26. INDICATORI AGREGATI VENITURI (Revenue mix per linie de business)
|
||||
# 26. INDICATORI AGREGATI VENITURI (Revenue mix per linie de business) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
INDICATORI_AGREGATI_VENITURI = """
|
||||
WITH vanzari_detaliate AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
CASE
|
||||
WHEN d.cont IN ('341', '345') THEN 'Productie proprie'
|
||||
WHEN d.cont = '301' THEN 'Materii prime'
|
||||
@@ -1054,11 +1077,11 @@ WITH vanzari_detaliate AS (
|
||||
END AS linie_business,
|
||||
d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END AS vanzare,
|
||||
d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie) AS marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
),
|
||||
total AS (
|
||||
SELECT SUM(vanzare) AS total_vanzari, SUM(marja) AS total_marja
|
||||
@@ -1082,14 +1105,14 @@ ORDER BY vanzari_ron DESC
|
||||
# =============================================================================
|
||||
SEZONALITATE_LUNARA = """
|
||||
WITH vanzari_lunare AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
EXTRACT(MONTH FROM f.data_act) AS nr_luna,
|
||||
TO_CHAR(f.data_act, 'Month', 'NLS_DATE_LANGUAGE=ROMANIAN') AS luna,
|
||||
EXTRACT(YEAR FROM f.data_act) AS an,
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
GROUP BY EXTRACT(MONTH FROM f.data_act), TO_CHAR(f.data_act, 'Month', 'NLS_DATE_LANGUAGE=ROMANIAN'), EXTRACT(YEAR FROM f.data_act)
|
||||
@@ -1129,51 +1152,51 @@ ORDER BY s.nr_luna
|
||||
# =============================================================================
|
||||
PORTOFOLIU_CLIENTI = """
|
||||
WITH clienti_activi_3_luni AS (
|
||||
SELECT COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM fact_vfacturi2 f
|
||||
SELECT /*+ INDEX(f IDX_VANZARI_NR) */ COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM vanzari f
|
||||
WHERE f.sters = 0 AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -3)
|
||||
),
|
||||
clienti_activi_12_luni AS (
|
||||
SELECT COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM fact_vfacturi2 f
|
||||
SELECT /*+ INDEX(f IDX_VANZARI_NR) */ COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM vanzari f
|
||||
WHERE f.sters = 0 AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
),
|
||||
clienti_noi AS (
|
||||
SELECT COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM fact_vfacturi2 f
|
||||
SELECT /*+ INDEX(f IDX_VANZARI_NR) */ COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM vanzari f
|
||||
WHERE f.sters = 0 AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
AND f.id_part NOT IN (
|
||||
SELECT DISTINCT f2.id_part
|
||||
FROM fact_vfacturi2 f2
|
||||
SELECT /*+ INDEX(f2 IDX_VANZARI_NR) */ DISTINCT f2.id_part
|
||||
FROM vanzari f2
|
||||
WHERE f2.sters = 0 AND f2.tip > 0 AND f2.tip NOT IN (7, 8, 9, 24)
|
||||
AND f2.data_act < ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
)
|
||||
),
|
||||
clienti_pierduti AS (
|
||||
SELECT COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM fact_vfacturi2 f
|
||||
SELECT /*+ INDEX(f IDX_VANZARI_NR) */ COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM vanzari f
|
||||
WHERE f.sters = 0 AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -6)
|
||||
AND f.id_part NOT IN (
|
||||
SELECT DISTINCT f2.id_part
|
||||
FROM fact_vfacturi2 f2
|
||||
SELECT /*+ INDEX(f2 IDX_VANZARI_NR) */ DISTINCT f2.id_part
|
||||
FROM vanzari f2
|
||||
WHERE f2.sters = 0 AND f2.tip > 0 AND f2.tip NOT IN (7, 8, 9, 24)
|
||||
AND f2.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -6)
|
||||
)
|
||||
),
|
||||
clienti_inactivi AS (
|
||||
SELECT COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM fact_vfacturi2 f
|
||||
SELECT /*+ INDEX(f IDX_VANZARI_NR) */ COUNT(DISTINCT f.id_part) AS cnt
|
||||
FROM vanzari f
|
||||
WHERE f.sters = 0 AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -6)
|
||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -3)
|
||||
AND f.id_part NOT IN (
|
||||
SELECT DISTINCT f2.id_part
|
||||
FROM fact_vfacturi2 f2
|
||||
SELECT /*+ INDEX(f2 IDX_VANZARI_NR) */ DISTINCT f2.id_part
|
||||
FROM vanzari f2
|
||||
WHERE f2.sters = 0 AND f2.tip > 0 AND f2.tip NOT IN (7, 8, 9, 24)
|
||||
AND f2.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -3)
|
||||
)
|
||||
@@ -1194,24 +1217,25 @@ SELECT 'Clienti inactivi (3-6 luni)' AS indicator, cnt AS valoare, 'Risc de pier
|
||||
# =============================================================================
|
||||
FRECVENTA_CLIENTI = """
|
||||
WITH frecventa_curenta AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
f.client,
|
||||
p.denumire AS client,
|
||||
COUNT(DISTINCT f.id_vanzare) AS comenzi_12_luni,
|
||||
ROUND(COUNT(DISTINCT f.id_vanzare) / 12.0, 2) AS comenzi_pe_luna,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS valoare_12_luni
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
GROUP BY f.id_part, f.client
|
||||
GROUP BY f.id_part, p.denumire
|
||||
),
|
||||
frecventa_anterioara AS (
|
||||
SELECT
|
||||
SELECT /*+ INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
COUNT(DISTINCT f.id_vanzare) AS comenzi_an_anterior
|
||||
FROM fact_vfacturi2 f
|
||||
FROM vanzari f
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
@@ -1240,21 +1264,22 @@ ORDER BY fc.valoare_12_luni DESC
|
||||
# =============================================================================
|
||||
CONCENTRARE_RISC = """
|
||||
WITH total_vanzari AS (
|
||||
SELECT SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
),
|
||||
vanzari_client AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari,
|
||||
ROW_NUMBER() OVER (ORDER BY SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) DESC) AS rn
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY f.id_part
|
||||
@@ -1301,18 +1326,19 @@ GROUP BY tv.total
|
||||
# =============================================================================
|
||||
CLIENTI_RANKING_PROFIT = """
|
||||
WITH vanzari_client AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
f.client,
|
||||
p.denumire AS client,
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari_fara_tva,
|
||||
SUM(d.cantitate * d.pret_achizitie) AS cost_total,
|
||||
SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) AS profit_brut
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY f.id_part, f.client
|
||||
GROUP BY f.id_part, p.denumire
|
||||
)
|
||||
SELECT
|
||||
client,
|
||||
@@ -1328,11 +1354,11 @@ ORDER BY profit_brut DESC
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
# 32. MARJA CLIENT CATEGORIE (Marjă per categorie per client)
|
||||
# 32. MARJA CLIENT CATEGORIE (Marjă per categorie per client) - OPTIMIZAT
|
||||
# =============================================================================
|
||||
MARJA_CLIENT_CATEGORIE = """
|
||||
SELECT
|
||||
f.client,
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
p.denumire AS client,
|
||||
NVL(sg.grupa, 'NECLASIFICAT') AS categoria,
|
||||
ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 2) AS vanzari,
|
||||
ROUND(SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)), 2) AS marja,
|
||||
@@ -1346,15 +1372,17 @@ SELECT
|
||||
NULLIF(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 0) < 15 THEN 'MARJA MICA'
|
||||
ELSE 'OK'
|
||||
END AS status_marja
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
LEFT JOIN vgest_art_sbgr sg ON d.id_subgrupa = sg.id_subgrupa
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_parteneri p ON f.id_part = p.id_part
|
||||
LEFT JOIN nom_articole art ON d.id_articol = art.id_articol
|
||||
LEFT JOIN vgest_art_sbgr sg ON art.id_subgrupa = sg.id_subgrupa
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -:months)
|
||||
GROUP BY f.id_part, f.client, sg.id_grupa, sg.grupa
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE, 'MM'), -:months)
|
||||
GROUP BY f.id_part, p.denumire, sg.id_grupa, sg.grupa
|
||||
HAVING SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) > 1000
|
||||
ORDER BY f.client, vanzari DESC
|
||||
ORDER BY p.denumire, vanzari DESC
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
@@ -1362,27 +1390,28 @@ ORDER BY f.client, vanzari DESC
|
||||
# =============================================================================
|
||||
EVOLUTIE_DISCOUNT = """
|
||||
WITH preturi_vechi AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
d.id_articol,
|
||||
d.denumire,
|
||||
a.denumire,
|
||||
AVG(CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS pret_mediu_vechi
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
LEFT JOIN nom_articole a ON d.id_articol = a.id_articol
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -6)
|
||||
AND d.pret > 0
|
||||
GROUP BY d.id_articol, d.denumire
|
||||
GROUP BY d.id_articol, a.denumire
|
||||
HAVING COUNT(*) >= 5
|
||||
),
|
||||
preturi_noi AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
d.id_articol,
|
||||
AVG(CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS pret_mediu_nou
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -6)
|
||||
AND d.pret > 0
|
||||
@@ -1436,13 +1465,13 @@ activ AS (
|
||||
AND b.luna = EXTRACT(MONTH FROM SYSDATE)
|
||||
),
|
||||
-- Vanzari si profit din ultimele 12 luni
|
||||
vanzari AS (
|
||||
SELECT
|
||||
vanzari_calc AS (
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total_vanzari,
|
||||
SUM(d.cantitate * (CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END - d.pret_achizitie)) AS profit_brut
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
)
|
||||
@@ -1454,6 +1483,7 @@ SELECT
|
||||
WHEN NVL(dt.datorii_totale, 0) / NULLIF(cp.capital_propriu, 0) > 1 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'Datorii / Capital Propriu (cont 16x,40x,42x,44x,46x / cont 10x,11x,12x,117)' AS formula,
|
||||
'< 1 = bine, > 2 = risc' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(dt.datorii_totale, 0) / NULLIF(cp.capital_propriu, 0) > 2 THEN 'Reduceti datoriile sau cresteti capitalul propriu'
|
||||
@@ -1470,6 +1500,7 @@ SELECT
|
||||
WHEN NVL(cp.capital_propriu, 0) / NULLIF(ac.total_activ, 0) < 0.5 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'Capital Propriu / Total Active (cont 10x,11x,12x,117 / Active clasa 1-5)' AS formula,
|
||||
'> 0.5 = bine, < 0.3 = risc' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(cp.capital_propriu, 0) / NULLIF(ac.total_activ, 0) < 0.3 THEN 'Dependenta prea mare de creditori'
|
||||
@@ -1486,6 +1517,7 @@ SELECT
|
||||
WHEN NVL(dt.datorii_totale, 0) / NULLIF(ac.total_activ, 0) > 0.5 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'Datorii / Total Active (cont 16x,40x,42x,44x,46x / Active clasa 1-5)' AS formula,
|
||||
'< 0.5 = bine, > 0.7 = risc' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(dt.datorii_totale, 0) / NULLIF(ac.total_activ, 0) > 0.7 THEN 'Risc de insolventa - reduceti datoriile'
|
||||
@@ -1502,13 +1534,14 @@ SELECT
|
||||
WHEN NVL(v.profit_brut, 0) * 100 / NULLIF(v.total_vanzari, 0) < 5 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'(Profit Brut / Vanzari) x 100 (din facturi ultimele 12 luni)' AS formula,
|
||||
'> 5% = bine, < 3% = risc' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(v.profit_brut, 0) * 100 / NULLIF(v.total_vanzari, 0) < 3 THEN 'Marja periculoasa - revizuiti preturile si costurile'
|
||||
WHEN NVL(v.profit_brut, 0) * 100 / NULLIF(v.total_vanzari, 0) < 5 THEN 'Optimizati costurile sau cresteti preturile'
|
||||
ELSE 'Marja acceptabila'
|
||||
END AS recomandare
|
||||
FROM vanzari v
|
||||
FROM vanzari_calc v
|
||||
UNION ALL
|
||||
SELECT
|
||||
'ROA - Rentabilitatea activelor (%)' AS indicator,
|
||||
@@ -1518,13 +1551,14 @@ SELECT
|
||||
WHEN NVL(v.profit_brut, 0) * 100 / NULLIF(ac.total_activ, 0) < 5 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'(Profit Brut / Total Active) x 100 (facturi 12 luni / balanta)' AS formula,
|
||||
'> 5% = bine, < 2% = slab' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(v.profit_brut, 0) * 100 / NULLIF(ac.total_activ, 0) < 2 THEN 'Activele nu genereaza profit suficient - optimizati utilizarea'
|
||||
WHEN NVL(v.profit_brut, 0) * 100 / NULLIF(ac.total_activ, 0) < 5 THEN 'Cresteti eficienta utilizarii activelor'
|
||||
ELSE 'Activele sunt utilizate eficient'
|
||||
END AS recomandare
|
||||
FROM vanzari v, activ ac
|
||||
FROM vanzari_calc v, activ ac
|
||||
UNION ALL
|
||||
SELECT
|
||||
'Rotatia activelor' AS indicator,
|
||||
@@ -1533,12 +1567,13 @@ SELECT
|
||||
WHEN NVL(v.total_vanzari, 0) / NULLIF(ac.total_activ, 0) < 0.5 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'Vanzari / Total Active (facturi 12 luni / balanta)' AS formula,
|
||||
'> 1 = eficient' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(v.total_vanzari, 0) / NULLIF(ac.total_activ, 0) < 0.5 THEN 'Active subutilizate - cresteti vanzarile'
|
||||
ELSE 'Activele genereaza vanzari eficient'
|
||||
END AS recomandare
|
||||
FROM vanzari v, activ ac
|
||||
FROM vanzari_calc v, activ ac
|
||||
"""
|
||||
|
||||
# =============================================================================
|
||||
@@ -1586,6 +1621,7 @@ SELECT
|
||||
WHEN (NVL(c.cash_total, 0) + NVL(cr.creante_total, 0) + NVL(st.stoc_total, 0)) / NULLIF(dc.datorii_total, 0) < 1.5 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'(Cash + Creante + Stoc) / Datorii curente (cont 512x,531x + 4111 + vstoc / cont 401x,404x,462x)' AS formula,
|
||||
'>= 1.5 ideal, >= 1.0 acceptabil' AS interpretare,
|
||||
CASE
|
||||
WHEN (NVL(c.cash_total, 0) + NVL(cr.creante_total, 0) + NVL(st.stoc_total, 0)) / NULLIF(dc.datorii_total, 0) < 1.0 THEN 'Risc de lichiditate - nu puteti acoperi datoriile curente'
|
||||
@@ -1602,6 +1638,7 @@ SELECT
|
||||
WHEN (NVL(c.cash_total, 0) + NVL(cr.creante_total, 0)) / NULLIF(dc.datorii_total, 0) < 1.0 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'(Cash + Creante) / Datorii curente - fara stocuri (cont 512x,531x + 4111 / cont 401x,404x,462x)' AS formula,
|
||||
'>= 1.0 ideal, >= 0.7 acceptabil' AS interpretare,
|
||||
CASE
|
||||
WHEN (NVL(c.cash_total, 0) + NVL(cr.creante_total, 0)) / NULLIF(dc.datorii_total, 0) < 0.7 THEN 'Dependenta de stocuri pentru plata datoriilor'
|
||||
@@ -1618,6 +1655,7 @@ SELECT
|
||||
WHEN NVL(c.cash_total, 0) / NULLIF(dc.datorii_total, 0) < 0.2 THEN 'ATENTIE'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'Cash / Datorii curente (cont 512x,531x / cont 401x,404x,462x)' AS formula,
|
||||
'>= 0.2 ideal, >= 0.1 minim' AS interpretare,
|
||||
CASE
|
||||
WHEN NVL(c.cash_total, 0) / NULLIF(dc.datorii_total, 0) < 0.1 THEN 'Cash insuficient - risc la plati urgente'
|
||||
@@ -1633,6 +1671,7 @@ SELECT
|
||||
WHEN (NVL(c.cash_total, 0) + NVL(cr.creante_total, 0) + NVL(st.stoc_total, 0)) - NVL(dc.datorii_total, 0) < 0 THEN 'ALERTA'
|
||||
ELSE 'OK'
|
||||
END AS status,
|
||||
'Active curente - Datorii curente (Cash + Creante + Stoc - Datorii furnizori)' AS formula,
|
||||
'Pozitiv = OK, Negativ = probleme' AS interpretare,
|
||||
CASE
|
||||
WHEN (NVL(c.cash_total, 0) + NVL(cr.creante_total, 0) + NVL(st.stoc_total, 0)) - NVL(dc.datorii_total, 0) < 0 THEN 'Fond de rulment negativ - necesita finantare'
|
||||
@@ -1957,10 +1996,11 @@ DSO_DPO_YOY = """
|
||||
WITH
|
||||
-- Metrici curente
|
||||
vanzari_curente AS (
|
||||
SELECT SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total_vanzari
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total_vanzari
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
),
|
||||
@@ -1986,10 +2026,11 @@ sold_furnizori_curent AS (
|
||||
),
|
||||
-- Metrici anterioare (aproximare - vanzari an anterior)
|
||||
vanzari_anterioare AS (
|
||||
SELECT SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total_vanzari
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS total_vanzari
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
@@ -2057,12 +2098,12 @@ CONCENTRARE_RISC_YOY = """
|
||||
WITH
|
||||
-- Single scan for current year: compute total + per-client with ranking
|
||||
vanzari_curent AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
GROUP BY f.id_part
|
||||
@@ -2081,12 +2122,12 @@ metrics_curent AS (
|
||||
),
|
||||
-- Single scan for previous year
|
||||
vanzari_anterior AS (
|
||||
SELECT
|
||||
SELECT /*+ LEADING(f d) USE_NL(d) INDEX(f IDX_VANZARI_NR) */
|
||||
f.id_part,
|
||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari
|
||||
FROM fact_vfacturi2 f
|
||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
||||
WHERE f.sters = 0 AND d.sters = 0
|
||||
FROM vanzari f
|
||||
JOIN vanzari_detalii d ON d.id_vanzare = f.id_vanzare AND d.sters = 0
|
||||
WHERE f.sters = 0
|
||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -24)
|
||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -12)
|
||||
|
||||
Reference in New Issue
Block a user