From efc38970ff8e540052424d419bf71e01b41557bb Mon Sep 17 00:00:00 2001 From: MinaR Date: Fri, 21 Jun 2024 11:57:36 +0200 Subject: [PATCH] varie migration --- .../ems/migration/_base/BaseMigration.java | 9 ++ .../model/Migration_20240620132505.java | 45 +++++++ .../model/Migration_20240620142950.java | 68 ++++++++++ .../model/Migration_20240621105122.java | 67 ++++++++++ .../model/Migration_20240621111156.java | 117 ++++++++++++++++++ 5 files changed, 306 insertions(+) create mode 100644 ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621105122.java create mode 100644 ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621111156.java diff --git a/ems-core/src/main/java/it/integry/ems/migration/_base/BaseMigration.java b/ems-core/src/main/java/it/integry/ems/migration/_base/BaseMigration.java index 25d108e3a6..4dc4422cba 100644 --- a/ems-core/src/main/java/it/integry/ems/migration/_base/BaseMigration.java +++ b/ems-core/src/main/java/it/integry/ems/migration/_base/BaseMigration.java @@ -102,6 +102,10 @@ public abstract class BaseMigration implements MigrationModelInterface { alterObject(SqlObjectTypeEnum.FUNCTION, objectName, createFunctionSql); } + protected void dropFunction(String objectName) throws SQLException, IOException { + dropObject(SqlObjectTypeEnum.FUNCTION, objectName); + } + protected void createOrUpdateView(String objectName, String createViewSql) throws SQLException, IOException { alterObject(SqlObjectTypeEnum.VIEW, objectName, createViewSql); } @@ -120,6 +124,11 @@ public abstract class BaseMigration implements MigrationModelInterface { sql); } + private void dropObject(SqlObjectTypeEnum sqlObject, String objectName) throws SQLException, IOException { + executeStatement("IF EXISTS (SELECT * FROM SYSOBJECTS WHERE id = object_id('" + objectName + "'))\r\n" + + "\tDROP " + sqlObject.toString() + " " + objectName); + } + protected boolean existsColumn(String tableName, String columnName) throws SQLException, IOException { String schema = null; diff --git a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620132505.java b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620132505.java index 85bc794abb..5919bfe950 100644 --- a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620132505.java +++ b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620132505.java @@ -11,6 +11,51 @@ public class Migration_20240620132505 extends BaseMigration implements Migration return; + createOrUpdateView("olvw_caratteristiche_lotto", "CREATE view [dbo].[olvw_caratteristiche_lotto] as \n" + + "\n" + + "\n" + + "SELECT\n" + + " * \n" + + "FROM\n" + + " (\n" + + " SELECT\n" + + " mtb_partita_mag_carat.cod_mart,\n" + + " mtb_partita_mag_carat.partita_mag,\n" + + " mtb_partita_mag_carat.carat,\n" + + " mtb_partita_mag_carat.val_carat\n" + + " from\n" + + " mtb_partita_mag_carat\n" + + " )\n" + + " as caratteristiche PIVOT ( min(val_carat) FOR carat IN \n" + + " (\n" + + " [Anno],\n" + + " [Numero Certificato],\n" + + " [Data Certificato],\n" + + " [Temperatura estrazione],\n" + + " [% Resa],\n" + + " [Orario Accettazione],\n" + + " [Conto Terzi],\n" + + " [Varieta]\n" + + " )\n" + + ") AS PivotTable\n" + + "/*\n" + + "--Ho dovuto disattivare tutti i controlli perchè bloccavano le moliture\n" + + "SELECT distinct\n" + + " mtb_partita_mag_carat.cod_mart,\n" + + " mtb_partita_mag_carat.partita_mag,\n" + + " '' as Anno,\n" + + " '' as [Numero Certificato],\n" + + " '' as [Data Certificato],\n" + + " '' as [Temperatura estrazione],\n" + + " '' as [ % Resa],\n" + + " '' as [Orario Accettazione],\n" + + " '' as [Conto Terzi],\n" + + " '' as [Varieta]\n" + + " \n" + + " from\n" + + " mtb_partita_mag_carat\n" + + " */"); + createOrUpdateFunction("f_lol_getOperazione", "CREATE FUNCTION [dbo].[f_lol_getOperazione] ( @codDtip varchar(5), @nazione varchar(3), @codMartIniz varchar(15), @partitaMagIniz varchar(20), @codMartFine varchar(15), @partitaMagFine varchar(20), @omaggio bit, @tipoMiscela varchar(1) )\n" + "RETURNS varchar(max)\n" + "AS\n" + diff --git a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620142950.java b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620142950.java index 1cd72d7723..34271f290c 100644 --- a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620142950.java +++ b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240620142950.java @@ -10,6 +10,74 @@ public class Migration_20240620142950 extends BaseMigration implements Migration if (isHistoryDB()) return; + createOrUpdateFunction("getCompatibiltaCaratteristiche", "CREATE FUNCTION [dbo].[getCompatibiltaCaratteristiche] \n" + + "(\n" + + " @codMart1 varchar(15), @partitaMag1 varchar(20), @codMart2 varchar(15), @partitaMag2 varchar(20), @checkVarieta varchar(1)\n" + + ")\n" + + "RETURNS TABLE as\n" + + "return \n" + + "( \n" + + " with art_carat as (\n" + + " SELECT IsNull(art1.carat, art2.carat) as carat,\n" + + " art1.val_carat as val_carat1,\n" + + " art2.val_carat as val_carat2,\n" + + " case when IsNull(art1.val_carat, '') = IsNull(art2.val_carat, '') THEN 1 ELSE 0 END as compatibilita\n" + + " from (\n" + + " select carat, \n" + + " case when carat in ('Biologico', 'Conto terzi', 'Estratto a freddo', 'In conversione', 'Non etichettato', 'Prima spremitura a freddo') and val_carat IS null THEN 'N' ELSE val_carat END as val_carat \n" + + " from mtb_aart_carat where cod_mart = @codMart1 \n" + + " UNION \n" + + " SELECT carat, \n" + + " case when carat in ('Biologico', 'Conto terzi', 'Estratto a freddo', 'In conversione', 'Non etichettato', 'Prima spremitura a freddo') and val_carat IS null THEN 'N' ELSE val_carat END as val_carat \n" + + " FROM mtb_partita_mag_carat WHERE cod_mart = @codMart1 AND partita_mag = @partitaMag1 and\n" + + " ((@checkVarieta = 'S') OR (@checkVarieta = 'N' AND carat <> 'Varieta'))\n" + + " ) art1 full outer join\n" + + " (\n" + + " select carat, \n" + + " case when carat in ('Biologico', 'Conto terzi', 'Estratto a freddo', 'In conversione', 'Non etichettato', 'Prima spremitura a freddo') and val_carat IS null THEN 'N' ELSE val_carat END as val_carat \n" + + " from mtb_aart_carat where cod_mart = @codMart2\n" + + " UNION \n" + + " SELECT carat, \n" + + " case when carat in ('Biologico', 'Conto terzi', 'Estratto a freddo', 'In conversione', 'Non etichettato', 'Prima spremitura a freddo') and val_carat IS null THEN 'N' ELSE val_carat END as val_carat \n" + + " FROM mtb_partita_mag_carat WHERE cod_mart = @codMart2 AND partita_mag = @partitaMag2 and \n" + + " ((@checkVarieta = 'S') OR (@checkVarieta = 'N' AND carat <> 'Varieta'))\n" + + " ) art2 on\n" + + " art1.carat = art2.carat \n" + + " )\n" + + " ,\n" + + " risultato_tb as (\n" + + " select art_carat.carat,\n" + + " art_carat.val_carat1,\n" + + " art_carat.val_carat2,\n" + + " case when art_carat.compatibilita = 0 AND id_carat is null THEN 0 ELSE 1 END as compatibilita,\n" + + " case when art_carat.compatibilita = 1 THEN ISNull(art_carat.val_carat1, art_carat.val_carat2) ELSE mtb_aart_carat_mix.risultato END as risultato\n" + + " from art_carat \n" + + " left outer join mtb_aart_carat_mix\n" + + " on art_carat.carat = mtb_aart_carat_mix.carat AND\n" + + " IsNull(art_carat.val_carat1, '') = IsNull(mtb_aart_carat_mix.val_carat1, '') AND\n" + + " IsnUll(art_carat.val_carat2, '') = IsNull(mtb_aart_carat_mix.val_carat2, '')\n" + + " ) ,\n" + + " tab as ( \n" + + "\n" + + " SELECT *, 0 AS ERROR, null as error_message FROM risultato_tb WHERE not existS(SELECT carat from risultato_tb where compatibilita = 0 )\n" + + " UNION ALL \n" + + "\n" + + " SELECT null, null, null, null, null, 1 AS ERROR,\n" + + " \n" + + " 'Articoli con carattaretistiche non compatibili. [' +\n" + + " (SELECT STUFF((\n" + + " SELECT ', ' + carat FROM risultato_tb WHERE existS(SELECT carat from risultato_tb where compatibilita = 0) AND compatibilita = 0\n" + + " FOR XML PATH('')\n" + + " ), 1, 1, '' )) + ']'\n" + + " /*** ATTENZIONE Ho dovuto disattivare il messaggio perchè bloccava le operazioni di molitura nache su oli compatibili*/\n" + + " --'' \n" + + " as error_message WHERE existS(SELECT carat from risultato_tb where compatibilita = 0)\n" + + " \n" + + " )\n" + + " \n" + + " select * from tab\n" + + " )"); + createOrUpdateFunction("lol_chkPostureSian", "CREATE FUNCTION [dbo].[lol_chkPostureSian] \n" + "(\n" + diff --git a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621105122.java b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621105122.java new file mode 100644 index 0000000000..aebce44578 --- /dev/null +++ b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621105122.java @@ -0,0 +1,67 @@ +package it.integry.ems.migration.model; + +import it.integry.ems.migration._base.BaseMigration; +import it.integry.ems.migration._base.MigrationModelInterface; + +public class Migration_20240621105122 extends BaseMigration implements MigrationModelInterface { + + @Override + public void up() throws Exception { + if (isHistoryDB()) + return; + + + dropFunction("getListinoVenditaRange"); + + + createOrUpdateFunction("getListinoVenditaPedane", "CREATE FUNCTION [dbo].[getListinoVenditaPedane](@datavalidita DATETIME, @codvlis VARCHAR(5), @codmart VARCHAR(15), @pedane INT)\n" + + " RETURNS TABLE AS\n" + + " RETURN\n" + + " WITH trasp AS (SELECT mtb_lisv_data_spese.cod_vlis,\n" + + " mtb_lisv_data_spese.versione,\n" + + " mtb_lisv_data_spese.cod_spes,\n" + + " mtb_lisv_data_spese.perc_ricarico,\n" + + " mtb_lisv_data_spese.val_ricarico,\n" + + " mtb_lisv_data_spese.perc_sconto,\n" + + " mtb_lisv_data_spese.da,\n" + + " mtb_lisv_data_spese.a\n" + + " FROM (SELECT cod_vlis,\n" + + " MAX(CASE\n" + + " WHEN vtb_list_data.versione IS NULL THEN NULL\n" + + " ELSE CONVERT(VARCHAR(10), vtb_list_data.data_iniz, 111) + ' ' +\n" + + " REPLICATE('0', 5 - LEN(vtb_list_data.versione)) +\n" + + " CONVERT(VARCHAR(5), vtb_list_data.versione) END) AS max_lisv\n" + + " FROM vtb_list_data\n" + + " WHERE vtb_list_data.data_iniz <= ISNULL(@datavalidita, CAST(GETDATE() AS DATE))\n" + + " GROUP BY cod_vlis) t\n" + + " INNER JOIN vtb_list_data ON t.cod_vlis = vtb_list_data.cod_vlis AND\n" + + " CONVERT(INT, RIGHT(t.max_lisv, 5)) = vtb_list_data.versione\n" + + " INNER JOIN mtb_lisv_data_spese\n" + + " ON vtb_list_data.cod_vlis = mtb_lisv_data_spese.cod_vlis AND\n" + + " vtb_list_data.versione = mtb_lisv_data_spese.versione)\n" + + "\n" + + " SELECT list.*,\n" + + " trasp.cod_spes,\n" + + " trasp.perc_ricarico,\n" + + " trasp.val_ricarico,\n" + + " trasp.perc_sconto,\n" + + " trasp.da,\n" + + " trasp.a,\n" + + " (list.prz_vend +\n" + + " IIF(list.flag_add_trasp = 1,\n" + + " ((ISNULL(val_ricarico, 0)) * list.add_val_spese) /\n" + + " IIF(ISNULL(list.colli_pedana, 1) = 0, 1, list.colli_pedana), 0)) +\n" + + " ((ISNULL(perc_ricarico, 0) * list.add_ric_spese * list.prz_vend) / 100) *\n" + + " (1 - (ISNULL(perc_sconto, 0) * list.add_sco_spese) / 100) prz_vend_trasp\n" + + " FROM getlistinovendita(@datavalidita, @codvlis, @codmart) list\n" + + " LEFT OUTER JOIN trasp ON list.cod_vlis = trasp.cod_vlis AND\n" + + " (@pedane IS NULL OR @pedane BETWEEN da AND a OR\n" + + " (@pedane IS NOT NULL AND da = 0 AND a = 0))"); + } + + @Override + public void down() throws Exception { + + } + +} diff --git a/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621111156.java b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621111156.java new file mode 100644 index 0000000000..9219d8ae62 --- /dev/null +++ b/ems-core/src/main/java/it/integry/ems/migration/model/Migration_20240621111156.java @@ -0,0 +1,117 @@ +package it.integry.ems.migration.model; + +import it.integry.ems.migration._base.BaseMigration; +import it.integry.ems.migration._base.MigrationModelInterface; + +public class Migration_20240621111156 extends BaseMigration implements MigrationModelInterface { + + @Override + public void up() throws Exception { + if (isHistoryDB()) + return; + + + createOrUpdateView("dbo.cvw_gg_dilazione_media", "CREATE VIEW [dbo].[cvw_gg_dilazione_media] AS\n" + + "SELECT\n" + + " ctb_scad.tipo_anag,\n" + + " ctb_scad.cod_anag,\n" + + " ctb_scad.anno_part,\n" + + " ctb_scad.data_doc,\n" + + " ctb_scad.num_doc,\n" + + " ctb_scad.ser_doc,\n" + + " ctb_scad.id_riga,\n" + + " sum(\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " ) AS imp_scad,\n" + + " Sum(\n" + + " (\n" + + " CASE\n" + + " WHEN ctb_scad.data_pag <= '2000/01/01' THEN (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " ELSE 0\n" + + " END\n" + + " )\n" + + " ) AS imp_pagato,\n" + + " Sum(\n" + + " (\n" + + " CASE\n" + + " WHEN ctb_scad.data_pag > '2000/01/01' THEN (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " ELSE (\n" + + " CASE\n" + + " WHEN ctb_scad.data_pag IS NULL THEN (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " ELSE 0\n" + + " END\n" + + " )\n" + + " END\n" + + " )\n" + + " ) AS imp_scoperto,\n" + + " Round(\n" + + " CASE\n" + + " WHEN sum(\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " ) <> 0 THEN sum(\n" + + " dateDiff(DAY, ctb_part.data_doc, ctb_scad.data_scad) * (\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " )\n" + + " ) / sum(\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " )\n" + + " ELSE 0\n" + + " END,\n" + + " 0\n" + + " ) AS gg_cred_conc,\n" + + " Round(\n" + + " CASE\n" + + " WHEN sum(\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " ) <> 0 THEN sum(\n" + + " dateDiff(\n" + + " DAY,\n" + + " ctb_part.data_doc,\n" + + " isnull(ctb_scad.data_pag, '2000/01/01')\n" + + " ) * (\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " )\n" + + " ) / sum(\n" + + " (ctb_part.tipo_partita * ctb_scad.imp_dare) + ((ctb_part.tipo_partita - 1) * ctb_scad.imp_avere) / ctb_part.cambio_divi_cont\n" + + " )\n" + + " ELSE 0\n" + + " END,\n" + + " 0\n" + + " ) AS gg_medi_cred, \n" + + " convert (numeric(20,5),0) as gg_medi_eff_ad_oggi\n" + + "FROM\n" + + " ctb_part,\n" + + " ctb_scad\n" + + "WHERE\n" + + " (ctb_part.tipo_anag = ctb_scad.tipo_anag)\n" + + " AND (ctb_part.cod_anag = ctb_scad.cod_anag)\n" + + " AND (ctb_part.anno_part = ctb_scad.anno_part)\n" + + " AND (ctb_part.ser_doc = ctb_scad.ser_doc)\n" + + " AND (ctb_part.num_doc = ctb_scad.num_doc)\n" + + " AND (ctb_part.data_doc = ctb_scad.data_doc)\n" + + " AND (\n" + + " (\n" + + " ctb_part.tipo_partita = 1\n" + + " AND ctb_scad.imp_dare <> 0\n" + + " )\n" + + " OR (\n" + + " ctb_part.tipo_partita = 0\n" + + " AND ctb_scad.imp_avere <> 0\n" + + " )\n" + + " )\n" + + "GROUP BY\n" + + " ctb_scad.tipo_anag,\n" + + " ctb_scad.cod_anag,\n" + + " ctb_scad.anno_part,\n" + + " ctb_scad.data_doc,\n" + + " ctb_scad.num_doc,\n" + + " ctb_scad.ser_doc,\n" + + " ctb_scad.id_riga"); + } + + @Override + public void down() throws Exception { + + } + +}