From 6b5274f2c3669b4af1289a6bd556b338f74d32e6 Mon Sep 17 00:00:00 2001 From: MinaR Date: Wed, 19 Jun 2024 10:20:24 +0200 Subject: [PATCH] aggironamento su MRP_UpdateQtaImpProx --- .../model/Migration_20240619102012.java | 196 ++++++++++++++++++ 1 file changed, 196 insertions(+) create mode 100644 ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240619102012.java diff --git a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240619102012.java b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240619102012.java new file mode 100644 index 0000000000..7205d83444 --- /dev/null +++ b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240619102012.java @@ -0,0 +1,196 @@ +package it.integry.ems.migration.model; + +import it.integry.ems.migration._base.BaseMigration; +import it.integry.ems.migration._base.MigrationModelInterface; + +public class Migration_20240619102012 extends BaseMigration implements MigrationModelInterface { + + @Override + public void up() throws Exception { + if (isHistoryDB()) + return; + + + createOrUpdateProcedure("MRP_UpdateQtaImpProx", "CREATE Procedure [dbo].[MRP_UpdateQtaImpProx](@elencoArticoli varchar(max) = null)\n" + + "AS \n" + + "--DECLARE @elencoarticoli VARCHAR(MAX) = NULL\n" + + "SET NOCOUNT ON;\n" + + "DECLARE @tableart TABLE\n" + + " (\n" + + " cod_mart VARCHAR(15)\n" + + " );\n" + + "\n" + + "IF @elencoarticoli IS NOT NULL AND @elencoarticoli <> ''\n" + + " BEGIN\n" + + " INSERT INTO @tableart\n" + + " SELECT *\n" + + " FROM dbo.parsestringintoarray(@elencoarticoli, '|')\n" + + " END\n" + + "ELSE\n" + + " BEGIN\n" + + " INSERT INTO @tableart\n" + + " SELECT mtb_aart.cod_mart\n" + + " FROM mtb_aart\n" + + " INNER JOIN jtb_cicl ON mtb_aart.cod_mart = jtb_cicl.cod_mart\n" + + " WHERE mtb_aart.flag_stato = 'A'\n" + + " END;\n" + + "\n" + + "WITH imp_ordini AS (SELECT mtb_part.cod_mart,\n" + + " mtb_aart.unt_mis,\n" + + " CASE\n" + + " WHEN SUM(mtb_part.qta_imp_cli) > SUM(mtb_part.qta_esistente + mtb_part.qta_ord_for) THEN\n" + + " SUM(mtb_part.qta_imp_cli - (mtb_part.qta_esistente + mtb_part.qta_ord_for))\n" + + " ELSE 0 END AS qtadaprodurre,\n" + + " CASE\n" + + " WHEN SUM(mtb_part.qta_imp_cli) > SUM(mtb_part.qta_esistente + mtb_part.qta_ord_for) THEN\n" + + " SUM(mtb_part.qta_imp_cli - (mtb_part.qta_esistente + mtb_part.qta_ord_for)) /\n" + + " mtb_aart.qta_cnf\n" + + " ELSE 0 END AS numdaprodurre,\n" + + " SUM((mtb_part.qta_esistente + mtb_part.qta_ord_for) - mtb_part.qta_imp_cli) AS qta_disp\n" + + " \n" + + " FROM mtb_part\n" + + " INNER JOIN jtb_cicl ON mtb_part.cod_mart = jtb_cicl.cod_prod\n" + + " INNER JOIN mtb_aart ON mtb_part.cod_mart = mtb_aart.cod_mart\n" + + " INNER JOIN @tableart a ON mtb_aart.cod_mart = a.cod_mart\n" + + " WHERE mtb_aart.flag_stato = 'A'\n" + + " GROUP BY mtb_part.cod_mart, mtb_aart.unt_mis, mtb_aart.qta_cnf\n" + + " HAVING SUM(mtb_part.qta_esistente + mtb_part.qta_ord_for) <> SUM(mtb_part.qta_imp_cli) \n" + + " \n" + + " \n" + + " )\n" + + " , imp_contratti AS (SELECT c.cod_mart,\n" + + " ISNULL(SUM((qta_vend_contratto - qta_ord - qta_doc) /\n" + + " CASE WHEN c.rap_conv = 0 THEN 1 ELSE c.rap_conv END), 0) AS qtacontratto\n" + + " FROM vvw_contratti_vendita c\n" + + " INNER JOIN @tableart a ON c.cod_mart = a.cod_mart\n" + + " WHERE c.data_fine >= CAST(GETDATE() AS DATE)\n" + + " GROUP BY c.cod_mart\n" + + " HAVING ISNULL(SUM(qta_residua), 0) > 0)\n" + + " , imp_budget AS (SELECT b.cod_mart,\n" + + " SUM(qta_saldo) AS qta_bdg\n" + + " FROM ovw_budget_ordv b\n" + + " INNER JOIN @tableart a ON b.cod_mart = a.cod_mart\n" + + " WHERE CAST(GETDATE() AS DATE) BETWEEN b.data_iniz AND b.data_fine\n" + + " AND qta_saldo <> 0\n" + + " GROUP BY b.cod_mart)\n" + + " , tmp_impegni\n" + + " AS (SELECT ISNULL(ISNULL(imp_ordini.cod_mart, imp_contratti.cod_mart), imp_budget.cod_mart) AS cod_mart,\n" + + " SUM(ISNULL(imp_ordini.qtadaprodurre, 0)) AS qtadaprodurre,\n" + + " SUM(ISNULL(imp_ordini.numdaprodurre, 0)) AS numdaprodurre,\n" + + " SUM(ISNULL(imp_contratti.qtacontratto -\n" + + " ISNULL(CASE WHEN imp_ordini.qta_disp > 0 THEN imp_ordini.qta_disp ELSE 0 END, 0),\n" + + " 0)) AS qtacontratto,\n" + + " SUM(ISNULL(imp_budget.qta_bdg, 0)) AS qtabudget\n" + + " \n" + + " FROM imp_ordini\n" + + " FULL OUTER JOIN imp_contratti ON imp_ordini.cod_mart = imp_contratti.cod_mart\n" + + " FULL OUTER JOIN imp_budget ON imp_ordini.cod_mart = imp_budget.cod_mart\n" + + " \n" + + " GROUP BY ISNULL(ISNULL(imp_ordini.cod_mart, imp_contratti.cod_mart), imp_budget.cod_mart)\n" + + " HAVING SUM(ISNULL(imp_ordini.qtadaprodurre, 0)) <> 0\n" + + " OR SUM(ISNULL(imp_contratti.qtacontratto -\n" + + " ISNULL(CASE WHEN imp_ordini.qta_disp > 0 THEN imp_ordini.qta_disp ELSE 0 END, 0), 0)) <> 0\n" + + " OR SUM(ISNULL(imp_budget.qta_bdg, 0)) <> 0)\n" + + "\n" + + "SELECT materiali.cod_mart,\n" + + " materiali.cod_prod,\n" + + " jtb_fasi.cod_mdep_lav AS cod_mdep,\n" + + " SUM(qtadaprodurre * ((materiali.qta_prod * materiali.rap_conv) /\n" + + " (jtb_cicl.qta_prod * jtb_cicl.rap_conv_prod))) AS impegnatoprox,\n" + + " SUM(qtacontratto * ((materiali.qta_prod * materiali.rap_conv) /\n" + + " (jtb_cicl.qta_prod * jtb_cicl.rap_conv_prod))) AS impproxcontratto,\n" + + " SUM(qtabudget * ((materiali.qta_prod * materiali.rap_conv) /\n" + + " (jtb_cicl.qta_prod * jtb_cicl.rap_conv_prod))) AS impproxbudget,\n" + + " max(case when ord.gestione = 'L' THEN max_data_cons else null end ) as data_imp_prox,\n" + + " max(case when ord.gestione = 'A' THEN max_data_cons else null end ) as data_imp_prox_contr\n" + + "INTO #tmp\n" + + "FROM tmp_impegni\n" + + " INNER JOIN\n" + + " (SELECT cod_mart, descrizione_estesa, unt_mis_prod AS unt_doc, rap_conv_prod AS rap_conv, qta_prod, cod_prod\n" + + " FROM [dbo].getmaterialidistinta(NULL)\n" + + " WHERE cod_parent IS NOT NULL) materiali ON materiali.cod_prod = tmp_impegni.cod_mart\n" + + " INNER JOIN jtb_cicl ON materiali.cod_prod = jtb_cicl.cod_prod\n" + + " INNER JOIN jtb_fasi ON jtb_cicl.cod_jfas = jtb_fasi.cod_jfas \n" + + " LEFT OUTER JOIN (select cod_mart, dtb_ordt.gestione, MAX(dtb_ordr.data_cons) as max_data_cons\n" + + " from dtb_ordt inner join dtb_ordr on dtb_ordt.gestione = dtb_ordr.gestione\n" + + " and dtb_ordt.data_ord = dtb_ordr.data_ord\n" + + " and dtb_ordt.num_ord = dtb_ordr.num_ord\n" + + " where dtb_ordt.gestione <> 'V' AND \n" + + " dtb_ordt.flag_annulla = 'N' and\n" + + " dtb_ordt.flag_budget = 0 and\n" + + " dtb_ordt.flag_sospeso = 'N' and\n" + + " dtb_ordt.flag_evaso_forzato = 'N' and \n" + + " dtb_ordr.flag_evaso = 'I' \n" + + " group by cod_mart, dtb_ordt.gestione\n" + + " ) ORD ON materiali.cod_mart = ORD.cod_mart\n" + + "GROUP BY materiali.cod_prod,\n" + + " materiali.cod_mart,\n" + + " jtb_fasi.cod_mdep_lav\n" + + " \n" + + "SELECT cod_mart,\n" + + " cod_mdep,\n" + + " SUM(impegnatoprox) AS impegnatoprox,\n" + + " SUM(impproxcontratto) AS impproxcontratto,\n" + + " SUM(impproxbudget) AS impproxbudget,\n" + + " IIF( data_imp_prox is null or data_imp_prox < Cast(getdate() as date), Cast(getdate() as date), data_imp_prox) as data_imp_prox,\n" + + " IIF( data_imp_prox_contr is null or data_imp_prox_contr < Cast(getdate() as date), Cast(getdate() as date), data_imp_prox_contr) as data_imp_prox_contr \n" + + "INTO #tmpsum\n" + + "FROM #tmp\n" + + "WHERE cod_mdep IS NOT NULL\n" + + "GROUP BY cod_mart, cod_mdep,\n" + + " data_imp_prox,\n" + + " data_imp_prox_contr\n" + + "\n" + + "INSERT INTO mtb_part (cod_mart, cod_mdep, scorta_min, qta_esistente, qta_imp_cli, qta_imp_lav, qta_ord_for)\n" + + "SELECT cod_mart, cod_mdep, 0, 0, 0, 0, 0\n" + + "FROM #tmpsum t\n" + + "WHERE NOT EXISTS(SELECT * FROM mtb_part WHERE mtb_part.cod_mart = t.cod_mart AND mtb_part.cod_mdep = t.cod_mdep)\n" + + "\n" + + "IF @elencoarticoli IS NULL OR @elencoarticoli = ''\n" + + " UPDATE mtb_part SET qta_imp_prox = 0, qta_imp_prox_contr = 0, qta_imp_prox_bdg = 0, data_imp_prox = null, data_imp_prox_contr = null\n" + + "ELSE\n" + + " UPDATE mtb_part\n" + + " SET qta_imp_prox = 0,\n" + + " qta_imp_prox_contr = 0,\n" + + " qta_imp_prox_bdg = 0,\n" + + " data_imp_prox = null, \n" + + " data_imp_prox_contr = null \n" + + " WHERE cod_mart IN (SELECT cod_mart FROM #tmpsum)\n" + + "\n" + + "UPDATE mtb_part\n" + + "SET qta_imp_prox = q.impegnatoprox,\n" + + " qta_imp_prox_contr = q.impproxcontratto,\n" + + " qta_imp_prox_bdg = q.impproxbudget,\n" + + " data_imp_prox = DateAdd(day, 1, q.data_imp_prox), \n" + + " data_imp_prox_contr = DateAdd(day, 1, q.data_imp_prox_contr )\n" + + "FROM mtb_part\n" + + " INNER JOIN #tmpsum q ON mtb_part.cod_mdep = q.cod_mdep AND mtb_part.cod_mart = q.cod_mart\n" + + "\n" + + "IF EXISTS(SELECT *\n" + + " FROM #tmp\n" + + " WHERE cod_mdep IS NULL)\n" + + " BEGIN\n" + + "\n" + + "\n" + + " DECLARE @message VARCHAR(MAX), @email VARCHAR(MAX)\n" + + "\n" + + " SELECT @email = e_mail FROM stb_email WHERE flag_default = 'S';\n" + + "\n" + + " SET @message = 'Verificare i seguenti articoli: la fase non ha il deposito agganciato.' + CHAR(10) + CHAR(13)\n" + + " SELECT @message = @message +\n" + + " STUFF((SELECT ',' + cod_prod\n" + + " FROM #tmp\n" + + " WHERE cod_mdep IS NULL\n" + + " FOR XML PATH('')), 1, 1, '')\n" + + "\n" + + " EXECUTE [dbo].[sp_sendEmail] @email, 'helpdesk@integry.it', 'Errore Impegni Prossimi', @message\n" + + "\n" + + " END"); + } + + @Override + public void down() throws Exception { + + } + +}