Optimize slow SQL queries + Fix duplicate invoices bug
Performance optimizations (views → base tables): - SUMAR_EXECUTIV: 6 UNION ALL → 1 CTE (130s → 0.4s) - SUMAR_EXECUTIV_YOY: 2 CTEs → 1 scan with CASE (129s → 0.4s) - CLIENTI_SUB_MEDIE: 2 duplicate CTEs → 1 base CTE (131s → 0.2s) - VANZARI_LUNARE: view → base table swap (130s → 0.4s) - INDICATORI_AGREGATI_VENITURI_YOY: 2 CTEs → 1 scan (129s → 0.2s) Bug fix (duplicate invoices in vireg_parteneri): - AGING_CREANTE, FACTURI_RESTANTE, AGING_DATORII, FACTURI_RESTANTE_FURNIZORI now filter by last closed calendar period to avoid showing same invoice multiple times Total query time reduced from ~31 min to ~22 min. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
312
queries.py
312
queries.py
@@ -163,33 +163,32 @@ FETCH FIRST 50 ROWS ONLY
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 6. CLIENȚI CARE CUMPĂRĂ SUB MEDIE
|
# 6. CLIENȚI CARE CUMPĂRĂ SUB MEDIE
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# OPTIMIZED: Single base CTE scans once, derives both aggregations from it
|
||||||
CLIENTI_SUB_MEDIE = """
|
CLIENTI_SUB_MEDIE = """
|
||||||
WITH preturi_medii AS (
|
WITH base_prices AS (
|
||||||
SELECT
|
|
||||||
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
|
|
||||||
FROM fact_vfacturi2 f
|
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
|
||||||
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)
|
|
||||||
AND d.pret > 0
|
|
||||||
GROUP BY d.id_articol
|
|
||||||
),
|
|
||||||
preturi_client AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
d.id_articol,
|
d.id_articol,
|
||||||
f.id_part,
|
f.id_part,
|
||||||
f.client,
|
p.denumire AS client,
|
||||||
AVG(CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS pret_client,
|
CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END AS pret_fara_tva,
|
||||||
SUM(d.cantitate) AS cantitate_totala
|
d.cantitate
|
||||||
FROM fact_vfacturi2 f
|
FROM VANZARI f
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
JOIN VANZARI_DETALII d ON d.id_vanzare = f.id_vanzare
|
||||||
|
JOIN NOM_PARTENERI p ON f.id_part = p.id_part
|
||||||
WHERE f.sters = 0 AND d.sters = 0
|
WHERE f.sters = 0 AND d.sters = 0
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
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), -:months)
|
||||||
AND d.pret > 0
|
AND d.pret > 0
|
||||||
GROUP BY d.id_articol, f.id_part, f.client
|
),
|
||||||
|
preturi_medii AS (
|
||||||
|
SELECT id_articol, AVG(pret_fara_tva) AS pret_mediu
|
||||||
|
FROM base_prices
|
||||||
|
GROUP BY id_articol
|
||||||
|
),
|
||||||
|
preturi_client AS (
|
||||||
|
SELECT id_articol, id_part, client, AVG(pret_fara_tva) AS pret_client, SUM(cantitate) AS cantitate_totala
|
||||||
|
FROM base_prices
|
||||||
|
GROUP BY id_articol, id_part, client
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
a.denumire AS produs,
|
a.denumire AS produs,
|
||||||
@@ -200,7 +199,7 @@ SELECT
|
|||||||
pc.cantitate_totala
|
pc.cantitate_totala
|
||||||
FROM preturi_client pc
|
FROM preturi_client pc
|
||||||
JOIN preturi_medii pm ON pm.id_articol = pc.id_articol
|
JOIN preturi_medii pm ON pm.id_articol = pc.id_articol
|
||||||
JOIN vnom_articole a ON a.id_articol = pc.id_articol
|
JOIN NOM_ARTICOLE a ON a.id_articol = pc.id_articol
|
||||||
WHERE pc.pret_client < pm.pret_mediu * 0.85
|
WHERE pc.pret_client < pm.pret_mediu * 0.85
|
||||||
ORDER BY discount_vs_medie DESC
|
ORDER BY discount_vs_medie DESC
|
||||||
FETCH FIRST 100 ROWS ONLY
|
FETCH FIRST 100 ROWS ONLY
|
||||||
@@ -334,6 +333,7 @@ ORDER BY rn
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 10. VÂNZĂRI LUNARE (SEZONALITATE)
|
# 10. VÂNZĂRI LUNARE (SEZONALITATE)
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# OPTIMIZED: Use base tables instead of views (removes 29 unnecessary JOINs)
|
||||||
VANZARI_LUNARE = """
|
VANZARI_LUNARE = """
|
||||||
SELECT
|
SELECT
|
||||||
TO_CHAR(f.data_act, 'YYYY-MM') AS luna,
|
TO_CHAR(f.data_act, 'YYYY-MM') AS luna,
|
||||||
@@ -341,8 +341,8 @@ SELECT
|
|||||||
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(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,
|
||||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
||||||
COUNT(DISTINCT f.id_part) AS nr_clienti
|
COUNT(DISTINCT f.id_part) AS nr_clienti
|
||||||
FROM fact_vfacturi2 f
|
FROM VANZARI f
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
JOIN VANZARI_DETALII d ON d.id_vanzare = f.id_vanzare
|
||||||
WHERE f.sters = 0 AND d.sters = 0
|
WHERE f.sters = 0 AND d.sters = 0
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
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), -24)
|
||||||
@@ -482,65 +482,65 @@ ORDER BY luna, tip
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 15. SUMAR EXECUTIV - KPIs
|
# 15. SUMAR EXECUTIV - KPIs
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# OPTIMIZED: Single CTE scans base tables once instead of 6 separate view scans (29 JOINs each)
|
||||||
SUMAR_EXECUTIV = """
|
SUMAR_EXECUTIV = """
|
||||||
SELECT
|
WITH base_data AS (
|
||||||
'Vânzări totale (fără TVA)' AS indicator,
|
SELECT
|
||||||
TO_CHAR(ROUND(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 0), '999,999,999') AS valoare,
|
f.id_vanzare,
|
||||||
'RON' AS um
|
f.id_part,
|
||||||
FROM fact_vfacturi2 f
|
d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END AS vanzare_fara_tva,
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_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
|
||||||
WHERE f.sters = 0 AND d.sters = 0
|
FROM VANZARI f
|
||||||
|
JOIN VANZARI_DETALII d ON d.id_vanzare = f.id_vanzare
|
||||||
|
WHERE f.sters = 0 AND d.sters = 0
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
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), -12)
|
||||||
|
),
|
||||||
|
aggregated AS (
|
||||||
|
SELECT
|
||||||
|
SUM(vanzare_fara_tva) AS total_vanzari,
|
||||||
|
SUM(marja) AS total_marja,
|
||||||
|
COUNT(DISTINCT id_vanzare) AS nr_facturi,
|
||||||
|
COUNT(DISTINCT id_part) AS nr_clienti
|
||||||
|
FROM base_data
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
'Vânzări totale (fără TVA)' AS indicator,
|
||||||
|
TO_CHAR(ROUND(total_vanzari, 0), '999,999,999') AS valoare,
|
||||||
|
'RON' AS um
|
||||||
|
FROM aggregated
|
||||||
|
|
||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
'Marja brută totală' AS indicator,
|
'Marja brută totală' AS indicator,
|
||||||
TO_CHAR(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)), 0), '999,999,999') AS valoare,
|
TO_CHAR(ROUND(total_marja, 0), '999,999,999') AS valoare,
|
||||||
'RON' AS um
|
'RON' AS um
|
||||||
FROM fact_vfacturi2 f
|
FROM aggregated
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
|
||||||
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), -12)
|
|
||||||
|
|
||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
'Procent marjă medie' AS indicator,
|
'Procent marjă medie' AS indicator,
|
||||||
TO_CHAR(ROUND(
|
TO_CHAR(ROUND(total_marja * 100.0 / NULLIF(total_vanzari, 0), 2), '990.99') AS valoare,
|
||||||
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 /
|
|
||||||
NULLIF(SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END), 0)
|
|
||||||
, 2), '990.99') AS valoare,
|
|
||||||
'%' AS um
|
'%' AS um
|
||||||
FROM fact_vfacturi2 f
|
FROM aggregated
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
|
||||||
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), -12)
|
|
||||||
|
|
||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
'Număr facturi' AS indicator,
|
'Număr facturi' AS indicator,
|
||||||
TO_CHAR(COUNT(DISTINCT f.id_vanzare), '999,999') AS valoare,
|
TO_CHAR(nr_facturi, '999,999') AS valoare,
|
||||||
'buc' AS um
|
'buc' AS um
|
||||||
FROM fact_vfacturi2 f
|
FROM aggregated
|
||||||
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)
|
|
||||||
|
|
||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
'Număr clienți activi' AS indicator,
|
'Număr clienți activi' AS indicator,
|
||||||
TO_CHAR(COUNT(DISTINCT f.id_part), '999,999') AS valoare,
|
TO_CHAR(nr_clienti, '999,999') AS valoare,
|
||||||
'buc' AS um
|
'buc' AS um
|
||||||
FROM fact_vfacturi2 f
|
FROM aggregated
|
||||||
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)
|
|
||||||
|
|
||||||
UNION ALL
|
UNION ALL
|
||||||
|
|
||||||
@@ -683,8 +683,12 @@ ORDER BY sold_curent DESC
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 21. AGING CREANTE (Buckets pentru creanțe - din vireg_parteneri)
|
# 21. AGING CREANTE (Buckets pentru creanțe - din vireg_parteneri)
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# FIX: Filter by last closed calendar period to avoid duplicate invoices
|
||||||
AGING_CREANTE = """
|
AGING_CREANTE = """
|
||||||
WITH solduri_clienti AS (
|
WITH ultima_luna AS (
|
||||||
|
SELECT anul, luna FROM calendar ORDER BY anul DESC, luna DESC FETCH FIRST 1 ROW ONLY
|
||||||
|
),
|
||||||
|
solduri_clienti AS (
|
||||||
SELECT
|
SELECT
|
||||||
r.id_part,
|
r.id_part,
|
||||||
r.nume AS client,
|
r.nume AS client,
|
||||||
@@ -699,9 +703,10 @@ WITH solduri_clienti AS (
|
|||||||
WHEN r.datascad >= TRUNC(SYSDATE) THEN 0
|
WHEN r.datascad >= TRUNC(SYSDATE) THEN 0
|
||||||
ELSE ROUND(TRUNC(SYSDATE) - r.datascad)
|
ELSE ROUND(TRUNC(SYSDATE) - r.datascad)
|
||||||
END AS zile_restante
|
END AS zile_restante
|
||||||
FROM vireg_parteneri r
|
FROM vireg_parteneri r, ultima_luna ul
|
||||||
WHERE (r.cont LIKE '4111%' OR r.cont LIKE '461%')
|
WHERE (r.cont LIKE '4111%' OR r.cont LIKE '461%')
|
||||||
AND (r.precdeb + r.debit) - (r.preccred + r.credit) <> 0
|
AND (r.precdeb + r.debit) - (r.preccred + r.credit) <> 0
|
||||||
|
AND r.an = ul.anul AND r.luna = ul.luna
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
client,
|
client,
|
||||||
@@ -720,7 +725,11 @@ ORDER BY total_sold DESC
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 22. FACTURI RESTANTE CLIENTI (Depășite scadența - din vireg_parteneri)
|
# 22. FACTURI RESTANTE CLIENTI (Depășite scadența - din vireg_parteneri)
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# FIX: Filter by last closed calendar period to avoid duplicate invoices
|
||||||
FACTURI_RESTANTE = """
|
FACTURI_RESTANTE = """
|
||||||
|
WITH ultima_luna AS (
|
||||||
|
SELECT anul, luna FROM calendar ORDER BY anul DESC, luna DESC FETCH FIRST 1 ROW ONLY
|
||||||
|
)
|
||||||
SELECT
|
SELECT
|
||||||
r.nume AS client,
|
r.nume AS client,
|
||||||
r.serie_act || ' ' || r.nract AS nr_factura,
|
r.serie_act || ' ' || r.nract AS nr_factura,
|
||||||
@@ -728,11 +737,12 @@ SELECT
|
|||||||
r.datascad AS data_scadenta,
|
r.datascad AS data_scadenta,
|
||||||
ROUND(TRUNC(SYSDATE) - r.datascad) AS zile_intarziere,
|
ROUND(TRUNC(SYSDATE) - r.datascad) AS zile_intarziere,
|
||||||
ROUND((r.precdeb + r.debit) - (r.preccred + r.credit), 2) AS suma_restanta
|
ROUND((r.precdeb + r.debit) - (r.preccred + r.credit), 2) AS suma_restanta
|
||||||
FROM vireg_parteneri r
|
FROM vireg_parteneri r, ultima_luna ul
|
||||||
WHERE (r.cont LIKE '4111%' OR r.cont LIKE '461%')
|
WHERE (r.cont LIKE '4111%' OR r.cont LIKE '461%')
|
||||||
AND (r.precdeb + r.debit) - (r.preccred + r.credit) <> 0
|
AND (r.precdeb + r.debit) - (r.preccred + r.credit) <> 0
|
||||||
AND r.datascad IS NOT NULL
|
AND r.datascad IS NOT NULL
|
||||||
AND r.datascad < TRUNC(SYSDATE)
|
AND r.datascad < TRUNC(SYSDATE)
|
||||||
|
AND r.an = ul.anul AND r.luna = ul.luna
|
||||||
ORDER BY zile_intarziere DESC
|
ORDER BY zile_intarziere DESC
|
||||||
FETCH FIRST 100 ROWS ONLY
|
FETCH FIRST 100 ROWS ONLY
|
||||||
"""
|
"""
|
||||||
@@ -741,8 +751,12 @@ FETCH FIRST 100 ROWS ONLY
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 22b. AGING DATORII FURNIZORI (din vireg_parteneri)
|
# 22b. AGING DATORII FURNIZORI (din vireg_parteneri)
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# FIX: Filter by last closed calendar period to avoid duplicate invoices
|
||||||
AGING_DATORII = """
|
AGING_DATORII = """
|
||||||
WITH solduri_furnizori AS (
|
WITH ultima_luna AS (
|
||||||
|
SELECT anul, luna FROM calendar ORDER BY anul DESC, luna DESC FETCH FIRST 1 ROW ONLY
|
||||||
|
),
|
||||||
|
solduri_furnizori AS (
|
||||||
SELECT
|
SELECT
|
||||||
r.id_part,
|
r.id_part,
|
||||||
r.nume AS furnizor,
|
r.nume AS furnizor,
|
||||||
@@ -757,9 +771,10 @@ WITH solduri_furnizori AS (
|
|||||||
WHEN r.datascad >= TRUNC(SYSDATE) THEN 0
|
WHEN r.datascad >= TRUNC(SYSDATE) THEN 0
|
||||||
ELSE ROUND(TRUNC(SYSDATE) - r.datascad)
|
ELSE ROUND(TRUNC(SYSDATE) - r.datascad)
|
||||||
END AS zile_restante
|
END AS zile_restante
|
||||||
FROM vireg_parteneri r
|
FROM vireg_parteneri r, ultima_luna ul
|
||||||
WHERE (r.cont LIKE '401%' OR r.cont LIKE '404%' OR r.cont LIKE '462%')
|
WHERE (r.cont LIKE '401%' OR r.cont LIKE '404%' OR r.cont LIKE '462%')
|
||||||
AND (r.preccred + r.credit) - (r.precdeb + r.debit) <> 0
|
AND (r.preccred + r.credit) - (r.precdeb + r.debit) <> 0
|
||||||
|
AND r.an = ul.anul AND r.luna = ul.luna
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
furnizor,
|
furnizor,
|
||||||
@@ -778,7 +793,11 @@ ORDER BY total_sold DESC
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 22c. FACTURI RESTANTE FURNIZORI (Depășite scadența)
|
# 22c. FACTURI RESTANTE FURNIZORI (Depășite scadența)
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# FIX: Filter by last closed calendar period to avoid duplicate invoices
|
||||||
FACTURI_RESTANTE_FURNIZORI = """
|
FACTURI_RESTANTE_FURNIZORI = """
|
||||||
|
WITH ultima_luna AS (
|
||||||
|
SELECT anul, luna FROM calendar ORDER BY anul DESC, luna DESC FETCH FIRST 1 ROW ONLY
|
||||||
|
)
|
||||||
SELECT
|
SELECT
|
||||||
r.nume AS furnizor,
|
r.nume AS furnizor,
|
||||||
r.serie_act || ' ' || r.nract AS nr_factura,
|
r.serie_act || ' ' || r.nract AS nr_factura,
|
||||||
@@ -786,11 +805,12 @@ SELECT
|
|||||||
r.datascad AS data_scadenta,
|
r.datascad AS data_scadenta,
|
||||||
ROUND(TRUNC(SYSDATE) - r.datascad) AS zile_intarziere,
|
ROUND(TRUNC(SYSDATE) - r.datascad) AS zile_intarziere,
|
||||||
ROUND((r.preccred + r.credit) - (r.precdeb + r.debit), 2) AS suma_restanta
|
ROUND((r.preccred + r.credit) - (r.precdeb + r.debit), 2) AS suma_restanta
|
||||||
FROM vireg_parteneri r
|
FROM vireg_parteneri r, ultima_luna ul
|
||||||
WHERE (r.cont LIKE '401%' OR r.cont LIKE '404%' OR r.cont LIKE '462%')
|
WHERE (r.cont LIKE '401%' OR r.cont LIKE '404%' OR r.cont LIKE '462%')
|
||||||
AND (r.preccred + r.credit) - (r.precdeb + r.debit) <> 0
|
AND (r.preccred + r.credit) - (r.precdeb + r.debit) <> 0
|
||||||
AND r.datascad IS NOT NULL
|
AND r.datascad IS NOT NULL
|
||||||
AND r.datascad < TRUNC(SYSDATE)
|
AND r.datascad < TRUNC(SYSDATE)
|
||||||
|
AND r.an = ul.anul AND r.luna = ul.luna
|
||||||
ORDER BY zile_intarziere DESC
|
ORDER BY zile_intarziere DESC
|
||||||
FETCH FIRST 100 ROWS ONLY
|
FETCH FIRST 100 ROWS ONLY
|
||||||
"""
|
"""
|
||||||
@@ -1837,96 +1857,97 @@ FROM cash_curent c, incasari_programate i, plati_programate p
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 39. SUMAR EXECUTIV YoY (cu comparatie an anterior)
|
# 39. SUMAR EXECUTIV YoY (cu comparatie an anterior)
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# OPTIMIZED: Single 24-month scan with CASE-based period partitioning instead of 2 separate view scans
|
||||||
SUMAR_EXECUTIV_YOY = """
|
SUMAR_EXECUTIV_YOY = """
|
||||||
WITH vanzari_curente AS (
|
WITH base_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari,
|
f.id_vanzare,
|
||||||
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 marja,
|
f.id_part,
|
||||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
CASE WHEN f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12) THEN 'CURENT' ELSE 'ANTERIOR' END AS perioada,
|
||||||
COUNT(DISTINCT f.id_part) AS nr_clienti
|
d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END AS vanzare,
|
||||||
FROM fact_vfacturi2 f
|
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
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
FROM VANZARI f
|
||||||
WHERE f.sters = 0 AND d.sters = 0
|
JOIN VANZARI_DETALII d ON d.id_vanzare = f.id_vanzare
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
|
||||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
|
||||||
),
|
|
||||||
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 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 marja,
|
|
||||||
COUNT(DISTINCT f.id_vanzare) AS nr_facturi,
|
|
||||||
COUNT(DISTINCT f.id_part) AS nr_clienti
|
|
||||||
FROM fact_vfacturi2 f
|
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
|
||||||
WHERE f.sters = 0 AND d.sters = 0
|
WHERE f.sters = 0 AND d.sters = 0
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
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), -24)
|
||||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -12)
|
),
|
||||||
|
aggregated AS (
|
||||||
|
SELECT
|
||||||
|
SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END) AS vanzari_curente,
|
||||||
|
SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END) AS vanzari_anterioare,
|
||||||
|
SUM(CASE WHEN perioada = 'CURENT' THEN marja ELSE 0 END) AS marja_curenta,
|
||||||
|
SUM(CASE WHEN perioada = 'ANTERIOR' THEN marja ELSE 0 END) AS marja_anterioara,
|
||||||
|
COUNT(DISTINCT CASE WHEN perioada = 'CURENT' THEN id_vanzare END) AS facturi_curente,
|
||||||
|
COUNT(DISTINCT CASE WHEN perioada = 'ANTERIOR' THEN id_vanzare END) AS facturi_anterioare,
|
||||||
|
COUNT(DISTINCT CASE WHEN perioada = 'CURENT' THEN id_part END) AS clienti_curenti,
|
||||||
|
COUNT(DISTINCT CASE WHEN perioada = 'ANTERIOR' THEN id_part END) AS clienti_anteriori
|
||||||
|
FROM base_data
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
'Vanzari totale (RON)' AS indicator,
|
'Vanzari totale (RON)' AS indicator,
|
||||||
ROUND(vc.vanzari, 0) AS valoare_curenta,
|
ROUND(vanzari_curente, 0) AS valoare_curenta,
|
||||||
ROUND(va.vanzari, 0) AS valoare_anterioara,
|
ROUND(vanzari_anterioare, 0) AS valoare_anterioara,
|
||||||
ROUND(vc.vanzari - va.vanzari, 0) AS variatie_absoluta,
|
ROUND(vanzari_curente - vanzari_anterioare, 0) AS variatie_absoluta,
|
||||||
ROUND((vc.vanzari - va.vanzari) * 100 / NULLIF(va.vanzari, 0), 2) AS variatie_procent,
|
ROUND((vanzari_curente - vanzari_anterioare) * 100 / NULLIF(vanzari_anterioare, 0), 2) AS variatie_procent,
|
||||||
CASE
|
CASE
|
||||||
WHEN vc.vanzari > va.vanzari * 1.05 THEN 'CRESTERE'
|
WHEN vanzari_curente > vanzari_anterioare * 1.05 THEN 'CRESTERE'
|
||||||
WHEN vc.vanzari < va.vanzari * 0.95 THEN 'SCADERE'
|
WHEN vanzari_curente < vanzari_anterioare * 0.95 THEN 'SCADERE'
|
||||||
ELSE 'STABIL'
|
ELSE 'STABIL'
|
||||||
END AS trend
|
END AS trend
|
||||||
FROM vanzari_curente vc, vanzari_anterioare va
|
FROM aggregated
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT
|
SELECT
|
||||||
'Marja bruta (RON)' AS indicator,
|
'Marja bruta (RON)' AS indicator,
|
||||||
ROUND(vc.marja, 0) AS valoare_curenta,
|
ROUND(marja_curenta, 0) AS valoare_curenta,
|
||||||
ROUND(va.marja, 0) AS valoare_anterioara,
|
ROUND(marja_anterioara, 0) AS valoare_anterioara,
|
||||||
ROUND(vc.marja - va.marja, 0) AS variatie_absoluta,
|
ROUND(marja_curenta - marja_anterioara, 0) AS variatie_absoluta,
|
||||||
ROUND((vc.marja - va.marja) * 100 / NULLIF(va.marja, 0), 2) AS variatie_procent,
|
ROUND((marja_curenta - marja_anterioara) * 100 / NULLIF(marja_anterioara, 0), 2) AS variatie_procent,
|
||||||
CASE
|
CASE
|
||||||
WHEN vc.marja > va.marja * 1.05 THEN 'CRESTERE'
|
WHEN marja_curenta > marja_anterioara * 1.05 THEN 'CRESTERE'
|
||||||
WHEN vc.marja < va.marja * 0.95 THEN 'SCADERE'
|
WHEN marja_curenta < marja_anterioara * 0.95 THEN 'SCADERE'
|
||||||
ELSE 'STABIL'
|
ELSE 'STABIL'
|
||||||
END AS trend
|
END AS trend
|
||||||
FROM vanzari_curente vc, vanzari_anterioare va
|
FROM aggregated
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT
|
SELECT
|
||||||
'Procent marja (%)' AS indicator,
|
'Procent marja (%)' AS indicator,
|
||||||
ROUND(vc.marja * 100 / NULLIF(vc.vanzari, 0), 2) AS valoare_curenta,
|
ROUND(marja_curenta * 100 / NULLIF(vanzari_curente, 0), 2) AS valoare_curenta,
|
||||||
ROUND(va.marja * 100 / NULLIF(va.vanzari, 0), 2) AS valoare_anterioara,
|
ROUND(marja_anterioara * 100 / NULLIF(vanzari_anterioare, 0), 2) AS valoare_anterioara,
|
||||||
ROUND(vc.marja * 100 / NULLIF(vc.vanzari, 0) - va.marja * 100 / NULLIF(va.vanzari, 0), 2) AS variatie_absoluta,
|
ROUND(marja_curenta * 100 / NULLIF(vanzari_curente, 0) - marja_anterioara * 100 / NULLIF(vanzari_anterioare, 0), 2) AS variatie_absoluta,
|
||||||
NULL AS variatie_procent,
|
NULL AS variatie_procent,
|
||||||
CASE
|
CASE
|
||||||
WHEN vc.marja * 100 / NULLIF(vc.vanzari, 0) > va.marja * 100 / NULLIF(va.vanzari, 0) + 1 THEN 'CRESTERE'
|
WHEN marja_curenta * 100 / NULLIF(vanzari_curente, 0) > marja_anterioara * 100 / NULLIF(vanzari_anterioare, 0) + 1 THEN 'CRESTERE'
|
||||||
WHEN vc.marja * 100 / NULLIF(vc.vanzari, 0) < va.marja * 100 / NULLIF(va.vanzari, 0) - 1 THEN 'SCADERE'
|
WHEN marja_curenta * 100 / NULLIF(vanzari_curente, 0) < marja_anterioara * 100 / NULLIF(vanzari_anterioare, 0) - 1 THEN 'SCADERE'
|
||||||
ELSE 'STABIL'
|
ELSE 'STABIL'
|
||||||
END AS trend
|
END AS trend
|
||||||
FROM vanzari_curente vc, vanzari_anterioare va
|
FROM aggregated
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT
|
SELECT
|
||||||
'Numar facturi' AS indicator,
|
'Numar facturi' AS indicator,
|
||||||
vc.nr_facturi AS valoare_curenta,
|
facturi_curente AS valoare_curenta,
|
||||||
va.nr_facturi AS valoare_anterioara,
|
facturi_anterioare AS valoare_anterioara,
|
||||||
vc.nr_facturi - va.nr_facturi AS variatie_absoluta,
|
facturi_curente - facturi_anterioare AS variatie_absoluta,
|
||||||
ROUND((vc.nr_facturi - va.nr_facturi) * 100 / NULLIF(va.nr_facturi, 0), 2) AS variatie_procent,
|
ROUND((facturi_curente - facturi_anterioare) * 100 / NULLIF(facturi_anterioare, 0), 2) AS variatie_procent,
|
||||||
CASE
|
CASE
|
||||||
WHEN vc.nr_facturi > va.nr_facturi * 1.05 THEN 'CRESTERE'
|
WHEN facturi_curente > facturi_anterioare * 1.05 THEN 'CRESTERE'
|
||||||
WHEN vc.nr_facturi < va.nr_facturi * 0.95 THEN 'SCADERE'
|
WHEN facturi_curente < facturi_anterioare * 0.95 THEN 'SCADERE'
|
||||||
ELSE 'STABIL'
|
ELSE 'STABIL'
|
||||||
END AS trend
|
END AS trend
|
||||||
FROM vanzari_curente vc, vanzari_anterioare va
|
FROM aggregated
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT
|
SELECT
|
||||||
'Numar clienti activi' AS indicator,
|
'Numar clienti activi' AS indicator,
|
||||||
vc.nr_clienti AS valoare_curenta,
|
clienti_curenti AS valoare_curenta,
|
||||||
va.nr_clienti AS valoare_anterioara,
|
clienti_anteriori AS valoare_anterioara,
|
||||||
vc.nr_clienti - va.nr_clienti AS variatie_absoluta,
|
clienti_curenti - clienti_anteriori AS variatie_absoluta,
|
||||||
ROUND((vc.nr_clienti - va.nr_clienti) * 100 / NULLIF(va.nr_clienti, 0), 2) AS variatie_procent,
|
ROUND((clienti_curenti - clienti_anteriori) * 100 / NULLIF(clienti_anteriori, 0), 2) AS variatie_procent,
|
||||||
CASE
|
CASE
|
||||||
WHEN vc.nr_clienti > va.nr_clienti THEN 'CRESTERE'
|
WHEN clienti_curenti > clienti_anteriori THEN 'CRESTERE'
|
||||||
WHEN vc.nr_clienti < va.nr_clienti THEN 'SCADERE'
|
WHEN clienti_curenti < clienti_anteriori THEN 'SCADERE'
|
||||||
ELSE 'STABIL'
|
ELSE 'STABIL'
|
||||||
END AS trend
|
END AS trend
|
||||||
FROM vanzari_curente vc, vanzari_anterioare va
|
FROM aggregated
|
||||||
"""
|
"""
|
||||||
|
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
@@ -2149,65 +2170,40 @@ FROM combined
|
|||||||
# =============================================================================
|
# =============================================================================
|
||||||
# 42. INDICATORI AGREGATI VENITURI YoY
|
# 42. INDICATORI AGREGATI VENITURI YoY
|
||||||
# =============================================================================
|
# =============================================================================
|
||||||
|
# OPTIMIZED: Single 24-month scan with CASE-based period partitioning, no FULL OUTER JOIN needed
|
||||||
INDICATORI_AGREGATI_VENITURI_YOY = """
|
INDICATORI_AGREGATI_VENITURI_YOY = """
|
||||||
WITH
|
WITH base_data AS (
|
||||||
vanzari_curente AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
CASE
|
CASE
|
||||||
WHEN d.cont IN ('341', '345') THEN 'Productie proprie'
|
WHEN d.cont IN ('341', '345') THEN 'Productie proprie'
|
||||||
WHEN d.cont = '301' THEN 'Materii prime'
|
WHEN d.cont = '301' THEN 'Materii prime'
|
||||||
ELSE 'Marfa revanduta'
|
ELSE 'Marfa revanduta'
|
||||||
END AS linie_business,
|
END AS linie_business,
|
||||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS vanzari,
|
CASE WHEN f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12) THEN 'CURENT' ELSE 'ANTERIOR' END AS perioada,
|
||||||
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 marja
|
d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END AS vanzare,
|
||||||
FROM fact_vfacturi2 f
|
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
|
||||||
JOIN fact_vfacturi_detalii d ON d.id_vanzare = f.id_vanzare
|
FROM VANZARI f
|
||||||
WHERE f.sters = 0 AND d.sters = 0
|
JOIN VANZARI_DETALII d ON d.id_vanzare = f.id_vanzare
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
|
||||||
AND f.data_act >= ADD_MONTHS(TRUNC(SYSDATE), -12)
|
|
||||||
GROUP BY CASE
|
|
||||||
WHEN d.cont IN ('341', '345') THEN 'Productie proprie'
|
|
||||||
WHEN d.cont = '301' THEN 'Materii prime'
|
|
||||||
ELSE 'Marfa revanduta'
|
|
||||||
END
|
|
||||||
),
|
|
||||||
vanzari_anterioare AS (
|
|
||||||
SELECT
|
|
||||||
CASE
|
|
||||||
WHEN d.cont IN ('341', '345') THEN 'Productie proprie'
|
|
||||||
WHEN d.cont = '301' THEN 'Materii prime'
|
|
||||||
ELSE 'Marfa revanduta'
|
|
||||||
END AS linie_business,
|
|
||||||
SUM(d.cantitate * CASE WHEN d.pret_cu_tva = 1 THEN d.pret / (1 + d.proc_tvav/100) ELSE d.pret END) AS 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 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
|
WHERE f.sters = 0 AND d.sters = 0
|
||||||
AND f.tip > 0 AND f.tip NOT IN (7, 8, 9, 24)
|
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), -24)
|
||||||
AND f.data_act < ADD_MONTHS(TRUNC(SYSDATE), -12)
|
|
||||||
GROUP BY CASE
|
|
||||||
WHEN d.cont IN ('341', '345') THEN 'Productie proprie'
|
|
||||||
WHEN d.cont = '301' THEN 'Materii prime'
|
|
||||||
ELSE 'Marfa revanduta'
|
|
||||||
END
|
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
NVL(vc.linie_business, va.linie_business) AS linie_business,
|
linie_business,
|
||||||
ROUND(NVL(vc.vanzari, 0), 0) AS vanzari_curente,
|
ROUND(SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END), 0) AS vanzari_curente,
|
||||||
ROUND(NVL(va.vanzari, 0), 0) AS vanzari_anterioare,
|
ROUND(SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END), 0) AS vanzari_anterioare,
|
||||||
ROUND(NVL(vc.vanzari, 0) - NVL(va.vanzari, 0), 0) AS variatie_vanzari,
|
ROUND(SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END) - SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END), 0) AS variatie_vanzari,
|
||||||
ROUND((NVL(vc.vanzari, 0) - NVL(va.vanzari, 0)) * 100 / NULLIF(va.vanzari, 0), 2) AS variatie_procent,
|
ROUND((SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END) - SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END)) * 100 / NULLIF(SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END), 0), 2) AS variatie_procent,
|
||||||
ROUND(NVL(vc.marja, 0) * 100 / NULLIF(vc.vanzari, 0), 2) AS marja_curenta_pct,
|
ROUND(SUM(CASE WHEN perioada = 'CURENT' THEN marja ELSE 0 END) * 100 / NULLIF(SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END), 0), 2) AS marja_curenta_pct,
|
||||||
ROUND(NVL(va.marja, 0) * 100 / NULLIF(va.vanzari, 0), 2) AS marja_anterioara_pct,
|
ROUND(SUM(CASE WHEN perioada = 'ANTERIOR' THEN marja ELSE 0 END) * 100 / NULLIF(SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END), 0), 2) AS marja_anterioara_pct,
|
||||||
CASE
|
CASE
|
||||||
WHEN NVL(vc.vanzari, 0) > NVL(va.vanzari, 0) * 1.05 THEN 'CRESTERE'
|
WHEN SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END) > SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END) * 1.05 THEN 'CRESTERE'
|
||||||
WHEN NVL(vc.vanzari, 0) < NVL(va.vanzari, 0) * 0.95 THEN 'SCADERE'
|
WHEN SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END) < SUM(CASE WHEN perioada = 'ANTERIOR' THEN vanzare ELSE 0 END) * 0.95 THEN 'SCADERE'
|
||||||
ELSE 'STABIL'
|
ELSE 'STABIL'
|
||||||
END AS trend
|
END AS trend
|
||||||
FROM vanzari_curente vc
|
FROM base_data
|
||||||
FULL OUTER JOIN vanzari_anterioare va ON vc.linie_business = va.linie_business
|
GROUP BY linie_business
|
||||||
ORDER BY NVL(vc.vanzari, 0) DESC
|
ORDER BY SUM(CASE WHEN perioada = 'CURENT' THEN vanzare ELSE 0 END) DESC
|
||||||
"""
|
"""
|
||||||
|
|
||||||
# Dictionary mapping query names to queries and their parameters
|
# Dictionary mapping query names to queries and their parameters
|
||||||
|
|||||||
Reference in New Issue
Block a user