getMateriali
All checks were successful
IntegryManagementSystem_Multi/pipeline/head This commit looks good
All checks were successful
IntegryManagementSystem_Multi/pipeline/head This commit looks good
This commit is contained in:
@@ -0,0 +1,313 @@
|
||||
package it.integry.ems.migration.model;
|
||||
|
||||
import it.integry.ems.migration._base.BaseMigration;
|
||||
import it.integry.ems.migration._base.MigrationModelInterface;
|
||||
|
||||
public class Migration_20250625120735 extends BaseMigration implements MigrationModelInterface {
|
||||
|
||||
@Override
|
||||
public void up() throws Exception {
|
||||
if (isHistoryDB())
|
||||
return;
|
||||
|
||||
|
||||
createOrUpdateFunction("getMaterialiDistinta", "CREATE FUNCTION [dbo].[getMaterialiDistinta](@codProd VARCHAR(15), @explodeSemilavorati bit)\n" +
|
||||
" RETURNS TABLE\n" +
|
||||
" AS\n" +
|
||||
" RETURN\n" +
|
||||
" ( \n" +
|
||||
" -- Add the SELECT statement with parameter references here\n" +
|
||||
" WITH distinta AS (SELECT cod_prod,\n" +
|
||||
" CONVERT(VARCHAR(15), NULL) AS cod_parent,\n" +
|
||||
" cod_prod AS cod_mart,\n" +
|
||||
" jtb_cicl.descrizione_prod AS descrizione,\n" +
|
||||
" jtb_cicl.descrizione_estesa,\n" +
|
||||
" CONVERT(VARCHAR(3), unt_mis_prod) AS unt_mis_prod,\n" +
|
||||
" CONVERT(NUMERIC(20, 5), rap_conv_prod) AS rap_conv_prod,\n" +
|
||||
" CONVERT(NUMERIC(20, 5), jtb_cicl.qta_prod ) AS qta_prod,\n" +
|
||||
" CONVERT(NUMERIC(20, 5), jtb_cicl.qta_prod ) AS qta_dist,\n" +
|
||||
" 1 AS livello,\n" +
|
||||
" FORMAT(ROW_NUMBER() OVER ( ORDER BY cod_prod), '00000') AS item_id,\n" +
|
||||
" CONVERT(VARCHAR(15), cod_prod) AS cod_prod_pri,\n" +
|
||||
" CAST(0 AS BIT) AS ricorsione,\n" +
|
||||
" CONVERT(numeric(5,2), 0) as perc_sfrido,\n" +
|
||||
" convert(int, null ) as num_fase,\n" +
|
||||
" convert(varchar(1), null ) as flag_pri, \n" +
|
||||
" convert(varchar(1024), null ) as note,\n" +
|
||||
" cast(1 as bit) as is_root,\n" +
|
||||
" cast(0 as bit) as is_foglia\n" +
|
||||
" FROM jtb_cicl\n" +
|
||||
" WHERE (@codProd IS NULL OR cod_prod = @codProd)\n" +
|
||||
" UNION ALL\n" +
|
||||
" SELECT distinta.cod_prod,\n" +
|
||||
" CONVERT(VARCHAR(15), jtb_dist_mate.cod_prod) AS cod_parent,\n" +
|
||||
" jtb_dist_mate.cod_mart,\n" +
|
||||
" jtb_dist_mate.descrizione,\n" +
|
||||
" jtb_dist_mate.descrizione_estesa,\n" +
|
||||
" CONVERT(VARCHAR(3), jtb_dist_mate.unt_mis_dist) as unt_mis_prod,\n" +
|
||||
" CONVERT(NUMERIC(20, 5), jtb_dist_mate.rap_conv_dist) as rap_conv_prod,\n" +
|
||||
" CONVERT(NUMERIC(20, 5), ((jtb_dist_mate.qta_std * ( 1 + jtb_dist_mate.perc_sfrido/100)) / ( jtb_cicl.qta_prod )) * distinta.qta_prod ) as qta_prod,\n" +
|
||||
" CONVERT(NUMERIC(20, 5), null),\n" +
|
||||
" distinta.livello + 1,\n" +
|
||||
" distinta.item_id + '_' +\n" +
|
||||
" FORMAT(ROW_NUMBER() OVER ( ORDER BY jtb_dist_mate.flag_pri desc, jtb_dist_mate.num_fase, id_riga ), '00000') AS item_id,\n" +
|
||||
" CONVERT(VARCHAR(15), distinta.cod_mart) AS cod_prod_pri,\n" +
|
||||
" CAST(CASE\n" +
|
||||
" WHEN jtb_dist_mate.cod_mart = jtb_dist_mate.cod_prod THEN 1\n" +
|
||||
" ELSE 0 END AS BIT) AS ricorsione,\n" +
|
||||
" jtb_dist_mate.perc_sfrido,\n" +
|
||||
" jtb_dist_mate.num_fase, \n" +
|
||||
" convert(varchar(1), jtb_dist_mate.flag_pri) as flag_pri, \n" +
|
||||
" convert(varchar(1024), jtb_dist_mate.note) as note,\n" +
|
||||
" cast(0 as bit) as is_root,\n" +
|
||||
" cast(IIF(jtb_dist_mate.flag_pri = 's',0,1) as bit) as is_foglia\n" +
|
||||
" FROM jtb_dist_mate\n" +
|
||||
" INNER JOIN distinta ON jtb_dist_mate.cod_prod = distinta.cod_mart\n" +
|
||||
" INNER JOIN jtb_cicl ON jtb_dist_mate.cod_prod = jtb_cicl.cod_mart\n" +
|
||||
" INNER JOIN mtb_aart ON mtb_aart.cod_mart = jtb_dist_mate.cod_mart\n" +
|
||||
" WHERE distinta.ricorsione = 0 and (distinta.is_root = 1 or distinta.flag_pri = 'S' or @explodeSemilavorati = 1))\n" +
|
||||
"\n" +
|
||||
" SELECT cod_prod,\n" +
|
||||
" cod_parent,\n" +
|
||||
" cod_mart,\n" +
|
||||
" descrizione,\n" +
|
||||
" descrizione_estesa,\n" +
|
||||
" unt_mis_prod,\n" +
|
||||
" rap_conv_prod,\n" +
|
||||
" IsNull(qta_dist,qta_prod) as qta_prod,\n" +
|
||||
" livello,\n" +
|
||||
" item_id,\n" +
|
||||
" cod_prod_pri,\n" +
|
||||
" perc_sfrido,\n" +
|
||||
" num_fase, \n" +
|
||||
" dense_rank() over ( partition by cod_prod order by cod_prod_pri ) - 1 + num_fase as num_fase_calc,\n" +
|
||||
" flag_pri,\n" +
|
||||
" note,\n" +
|
||||
" is_root,\n" +
|
||||
" is_foglia\n" +
|
||||
" FROM distinta\n" +
|
||||
" )");
|
||||
createOrUpdateProcedure("MRP_UpdateQtaImpProx", "CREATE Procedure [dbo].[MRP_UpdateQtaImpProx](@elencoArticoli varchar(max) = null)\n" +
|
||||
"AS \n" +
|
||||
"--DECLARE @elencoarticoli VARCHAR(MAX) --= 'CEB1TREORI6|CEB1LMS5|CEBB1MRCH2|CVINACBO1LEV2'\n" +
|
||||
"--DROP TABLE #tmp\n" +
|
||||
"\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,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,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" +
|
||||
" /*\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" +
|
||||
" */\n" +
|
||||
" IsNull(max(ORD.data_imp_prox), convert(date,GetDate())) as data_imp_prox,\n" +
|
||||
" IsNull(max(ORD.data_imp_prox_contr), convert(date,GetDate())) as data_imp_prox_contr\n" +
|
||||
"INTO #tmp\n" +
|
||||
"FROM tmp_impegni\n" +
|
||||
" INNER JOIN\n" +
|
||||
" (\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, 1)\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 (\n" +
|
||||
" /* Modifcata da Massimo 10/07/24 la vecchia query creva quantità doppie in presenza di ordini L e A\n" +
|
||||
" 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" +
|
||||
" */\n" +
|
||||
" Select isNull(ODL.cod_mart,ODA.cod_mart) as cod_mart, ODL.data_imp_prox, ODA.data_imp_prox_contr\n" +
|
||||
" from \n" +
|
||||
" (select cod_mart, dtb_ordt.gestione, MAX(dtb_ordr.data_cons) as data_imp_prox\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 = 'L' 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_ordt.flag_evaso_prod = 'I' and\n" +
|
||||
" dtb_ordr.flag_evaso = 'I' \n" +
|
||||
" group by cod_mart, dtb_ordt.gestione\n" +
|
||||
" )ODL full outer join\n" +
|
||||
" (\n" +
|
||||
" select cod_mart, dtb_ordt.gestione, MAX(dtb_ordr.data_cons) as data_imp_prox_contr\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 = 'A' 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" +
|
||||
" \n" +
|
||||
" group by cod_mart, dtb_ordt.gestione)\n" +
|
||||
" ODA on ODA.cod_mart = ODL.cod_mart\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" +
|
||||
" case when data_imp_prox < convert(date, GetDate()) then convert(date, getDate()) else data_imp_prox end data_imp_prox,\n" +
|
||||
" case when data_imp_prox_contr < case when data_imp_prox < convert(date, GetDate()) then convert(date, getDate()) else data_imp_prox end \n" +
|
||||
" then case when data_imp_prox < convert(date, GetDate()) then convert(date, getDate()) else data_imp_prox end \n" +
|
||||
" else data_imp_prox_contr end as data_imp_prox_contr\n" +
|
||||
" --case when data_imp_prox_contr is null then isNull(data_imp_prox,convert(date,GetDate())) else data_imp_prox_contr end as data_imp_prox_contr\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 isNull(data_imp_prox_contr,data_imp_prox) < 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 {
|
||||
|
||||
}
|
||||
|
||||
}
|
||||
Reference in New Issue
Block a user