From 40199558a7a0d1b998ee2bdcedaa73ed7ff37e79 Mon Sep 17 00:00:00 2001 From: KammM Date: Thu, 11 Apr 2024 16:19:41 +0200 Subject: [PATCH] =?UTF-8?q?Neue=20Struktur=20implementiert=20f=C3=BCr=20Pr?= =?UTF-8?q?ozedur=20und=20Funktionsaufrufe?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- SERVER/Insiders/SPL/DD_DbExport.spl.txt | 260 +++++++++--------- ...LYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM].sql | 78 ++++++ .../SQL/[PRDD_INSERT_ANALYZER_RESULT].sql | 124 +++++---- 3 files changed, 285 insertions(+), 177 deletions(-) create mode 100644 SERVER/Insiders/SQL/[FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM].sql diff --git a/SERVER/Insiders/SPL/DD_DbExport.spl.txt b/SERVER/Insiders/SPL/DD_DbExport.spl.txt index ad8ccb4..fd12b24 100644 --- a/SERVER/Insiders/SPL/DD_DbExport.spl.txt +++ b/SERVER/Insiders/SPL/DD_DbExport.spl.txt @@ -7,140 +7,146 @@ ******************************************************************************/ /****************************************************************************** - DD MD/MK 06/03/2024 + DD MD/MK 27/03/2024 ******************************************************************************/ + FUNCTION OnAnalyserFinishDocument() { + // Hole Nummer des Analyse-Durchlaufs anhand gesetzter smartBlocks + documentnumber := NUM_DOCS(); + // Setzte Dateinamen als primären Schlüssel uid := DOC_ID(); - - // Kopfdaten - Head := DICT(); - Head['AA'] := uid; - Head['AB'] := [RE_CITY]; - Head['AC'] := [RE_COUNTRY]; - Head['AD'] := [RE_ILN]; - Head['AE'] := [RE_NAME]; - Head['AF'] := [RE_PK]; - Head['AG'] := [RE_RECIPIENT_NO]; - Head['AH'] := [RE_STREET]; - Head['AI'] := [RE_SYSTEM]; - Head['AJ'] := [RE_TAX_ID_NO]; - Head['AK'] := [RE_VAT_ID_NO]; - Head['AL'] := [RE_ZIPCODE]; - Head['AM'] := [VE_ACCOUNT_NO]; - Head['AN'] := [VE_BANK]; - Head['AO'] := [VE_BANK_NO]; - Head['AP'] := [VE_CITY]; - Head['AQ'] := [VE_CLERK_ID]; - Head['AR'] := [VE_COUNTRY]; - Head['AS'] := [VE_EMAIL]; - Head['AT'] := [VE_FAX_NO]; - Head['AU'] := [VE_IBAN]; - Head['AV'] := [VE_ILN]; - Head['AW'] := [VE_NAME]; - Head['AX'] := [VE_RECIPIENT_NO]; - Head['AY'] := [VE_STREET]; - Head['AZ'] := [VE_SWIFT_BIC]; - Head['BA'] := [VE_TAX_ID_NO]; - Head['BB'] := [VE_TELEFONE_NO]; - Head['BC'] := [VE_VAT_ID_NO]; - Head['BD'] := [VE_VENDOR_NO]; - Head['BE'] := [VE_ZIPCODE]; - Head['BF'] := [INV_AMOUNT]; - Head['BG'] := [INV_AMOUNT_ROUNDING]; - Head['BH'] := [INV_CASCADED_ITEM_DISCOUNTS]; - Head['BI'] := [INV_COMPLIANCE_COMMENTS]; - Head['BJ'] := [INV_COMPLIANT]; - Head['BK'] := [INV_CREDIT_NOTE]; - Head['BL'] := [INV_CURRENCY]; - Head['BM'] := [INV_CUSTOMS_CHARGE]; - Head['BN'] := [INV_DATE]; - Head['BO'] := [INV_DELIVERY_DATE]; - Head['BP'] := [INV_DELIVERY_MONTH]; - Head['BQ'] := [INV_DELIVERY_WEEK]; - Head['BR'] := [INV_DISCOUNTABLE_AMOUNT]; - Head['BS'] := [INV_DISCOUNT_AMOUNT1]; - Head['BT'] := [INV_DISCOUNT_AMOUNT2]; - Head['BU'] := [INV_DISCOUNT_PERCENT1]; - Head['BV'] := [INV_DISCOUNT_PERCENT2]; - Head['BW'] := [INV_FREIGHT_CHARGE]; - //Head['AX'] := [INV_GROSS_AMOUNT1]; - //Head['AY'] := [INV_GROSS_AMOUNT2]; - //Head['BA'] := [INV_GROSS_AMOUNT3]; - Head['CB'] := [INV_INSURANCE_CHARGE]; - Head['CC'] := [INV_IS_INTERCOMPANY]; - Head['CD'] := [INV_IS_MM]; - Head['CE'] := [INV_NET_AMOUNT1]; - Head['CF'] := [INV_NET_AMOUNT2]; - Head['CG'] := [INV_NET_AMOUNT3]; - Head['CH'] := [INV_NUMBER]; - Head['CI'] := [INV_PACKING_CHARGE]; - Head['CJ'] := [INV_POSTAL_CHARGE]; - Head['CK'] := [INV_POS_DIFF_CHK]; - Head['CL'] := [INV_REFERENCE_DATE]; - Head['CM'] := [INV_REFERENCE_NUMBER]; - Head['CN'] := [INV_SMALL_VOL_CHARGE]; - Head['CO'] := [INV_SPECIAL_CHARGE]; - Head['CP'] := [INV_TAX_AMOUNT1]; - Head['CQ'] := [INV_TAX_AMOUNT2]; - Head['CR'] := [INV_TAX_AMOUNT3]; - Head['CS'] := [INV_TAX_RATE1]; - Head['CT'] := [INV_TAX_RATE2]; - Head['CU'] := [INV_TAX_RATE3]; - Head['CV'] := [INV_TOLL_CHARGE]; - Head['CW'] := [INV_VALUTA_DATE]; - Head['CX'] := [INV_VALUTA_DAYS]; - Head['CY'] := [INV_VALUTA_WEEKS]; - Head['CZ'] := 'DD_DbExport.spl'; - //stdWriteLog('Message',STRING_FORMAT('DD_DbExport - OnAnalyserFinishDocument - Head: %1','EXEC dbo.PRDD_INSERT_ANALYZER_HEAD'),''); - SQL_EXEC dbeGetHandle(),'EXEC dbo.PRDD_INSERT_ANALYZER_HEAD ?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?' PARAMS dbuDictToVector(Head); - SQL_COMMIT(dbeGetHandle()); + IF (documentnumber = 1) THEN { - // Schleife für die Positionsmitte - FOR lineIdx := 1 TO NUM_LINES('InvoiceItems')-1 { + // Kopfdaten + Head := DICT(); + Head['AA'] := uid; + Head['AB'] := [RE_CITY]; + Head['AC'] := [RE_COUNTRY]; + Head['AD'] := [RE_ILN]; + Head['AE'] := [RE_NAME]; + Head['AF'] := [RE_PK]; + Head['AG'] := [RE_RECIPIENT_NO]; + Head['AH'] := [RE_STREET]; + Head['AI'] := [RE_SYSTEM]; + Head['AJ'] := [RE_TAX_ID_NO]; + Head['AK'] := [RE_VAT_ID_NO]; + Head['AL'] := [RE_ZIPCODE]; + Head['AM'] := [VE_ACCOUNT_NO]; + Head['AN'] := [VE_BANK]; + Head['AO'] := [VE_BANK_NO]; + Head['AP'] := [VE_CITY]; + Head['AQ'] := [VE_CLERK_ID]; + Head['AR'] := [VE_COUNTRY]; + Head['AS'] := [VE_EMAIL]; + Head['AT'] := [VE_FAX_NO]; + Head['AU'] := [VE_IBAN]; + Head['AV'] := [VE_ILN]; + Head['AW'] := [VE_NAME]; + Head['AX'] := [VE_RECIPIENT_NO]; + Head['AY'] := [VE_STREET]; + Head['AZ'] := [VE_SWIFT_BIC]; + Head['BA'] := [VE_TAX_ID_NO]; + Head['BB'] := [VE_TELEFONE_NO]; + Head['BC'] := [VE_VAT_ID_NO]; + Head['BD'] := [VE_VENDOR_NO]; + Head['BE'] := [VE_ZIPCODE]; + Head['BF'] := [INV_AMOUNT]; + Head['BG'] := [INV_AMOUNT_ROUNDING]; + Head['BH'] := [INV_CASCADED_ITEM_DISCOUNTS]; + Head['BI'] := [INV_COMPLIANCE_COMMENTS]; + Head['BJ'] := [INV_COMPLIANT]; + Head['BK'] := [INV_CREDIT_NOTE]; + Head['BL'] := [INV_CURRENCY]; + Head['BM'] := [INV_CUSTOMS_CHARGE]; + Head['BN'] := [INV_DATE]; + Head['BO'] := [INV_DELIVERY_DATE]; + Head['BP'] := [INV_DELIVERY_MONTH]; + Head['BQ'] := [INV_DELIVERY_WEEK]; + Head['BR'] := [INV_DISCOUNTABLE_AMOUNT]; + Head['BS'] := [INV_DISCOUNT_AMOUNT1]; + Head['BT'] := [INV_DISCOUNT_AMOUNT2]; + Head['BU'] := [INV_DISCOUNT_PERCENT1]; + Head['BV'] := [INV_DISCOUNT_PERCENT2]; + Head['BW'] := [INV_FREIGHT_CHARGE]; + //Head['AX'] := [INV_GROSS_AMOUNT1]; + //Head['AY'] := [INV_GROSS_AMOUNT2]; + //Head['BA'] := [INV_GROSS_AMOUNT3]; + Head['CB'] := [INV_INSURANCE_CHARGE]; + Head['CC'] := [INV_IS_INTERCOMPANY]; + Head['CD'] := [INV_IS_MM]; + Head['CE'] := [INV_NET_AMOUNT1]; + Head['CF'] := [INV_NET_AMOUNT2]; + Head['CG'] := [INV_NET_AMOUNT3]; + Head['CH'] := [INV_NUMBER]; + Head['CI'] := [INV_PACKING_CHARGE]; + Head['CJ'] := [INV_POSTAL_CHARGE]; + Head['CK'] := [INV_POS_DIFF_CHK]; + Head['CL'] := [INV_REFERENCE_DATE]; + Head['CM'] := [INV_REFERENCE_NUMBER]; + Head['CN'] := [INV_SMALL_VOL_CHARGE]; + Head['CO'] := [INV_SPECIAL_CHARGE]; + Head['CP'] := [INV_TAX_AMOUNT1]; + Head['CQ'] := [INV_TAX_AMOUNT2]; + Head['CR'] := [INV_TAX_AMOUNT3]; + Head['CS'] := [INV_TAX_RATE1]; + Head['CT'] := [INV_TAX_RATE2]; + Head['CU'] := [INV_TAX_RATE3]; + Head['CV'] := [INV_TOLL_CHARGE]; + Head['CW'] := [INV_VALUTA_DATE]; + Head['CX'] := [INV_VALUTA_DAYS]; + Head['CY'] := [INV_VALUTA_WEEKS]; + Head['CZ'] := 'DD_DbExport.spl'; - Items := DICT(); - Items['AA'] := uid; - Items['AB'] := CELL(*FIELD('INVI_POS_NO'), lineIdx)+0; - Items['AC'] := CELL(*FIELD('INVI_ARTICLE_NO'), lineIdx); - Items['AD'] := CELL(*FIELD('INVI_CHARGE_AMOUNT1'), lineIdx); - Items['AE'] := CELL(*FIELD('INVI_CHARGE_AMOUNT2'), lineIdx); - Items['AF'] := CELL(*FIELD('INVI_CHARGE_AMOUNT3'), lineIdx); - Items['AG'] := CELL(*FIELD('INVI_CHARGE_PERCENT1'), lineIdx); - Items['AH'] := CELL(*FIELD('INVI_CHARGE_PERCENT2'), lineIdx); - Items['AI'] := CELL(*FIELD('INVI_CHARGE_PERCENT3'), lineIdx); - Items['AJ'] := CELL(*FIELD('INVI_CHARGE_PER_PIECE1'), lineIdx); - Items['AK'] := CELL(*FIELD('INVI_CHARGE_PER_PIECE2'), lineIdx); - Items['AL'] := CELL(*FIELD('INVI_CHARGE_PER_PIECE3'), lineIdx); - Items['AM'] := CELL(*FIELD('INVI_DELIVERY_DATE'), lineIdx); - Items['AN'] := CELL(*FIELD('INVI_DELIVERY_NO'), lineIdx); - Items['AO'] := CELL(*FIELD('INVI_DIFF_CHK'), lineIdx); - Items['AP'] := CELL(*FIELD('INVI_DISCOUNT_AMOUNT1'), lineIdx); - Items['AQ'] := CELL(*FIELD('INVI_DISCOUNT_AMOUNT2'), lineIdx); - Items['AR'] := CELL(*FIELD('INVI_DISCOUNT_AMOUNT3'), lineIdx); - Items['AS'] := CELL(*FIELD('INVI_DISCOUNT_PERCENT1'), lineIdx); - Items['AT'] := CELL(*FIELD('INVI_DISCOUNT_PERCENT2'), lineIdx); - Items['AU'] := CELL(*FIELD('INVI_DISCOUNT_PERCENT3'), lineIdx); - Items['AV'] := CELL(*FIELD('INVI_DISCOUNT_PER_PIECE1'), lineIdx); - Items['AW'] := CELL(*FIELD('INVI_DISCOUNT_PER_PIECE2'), lineIdx); - Items['AX'] := CELL(*FIELD('INVI_DISCOUNT_PER_PIECE3'), lineIdx); - Items['AY'] := CELL(*FIELD('INVI_IS_DELIVERY'), lineIdx); - Items['AZ'] := CELL(*FIELD('INVI_ORI_ARTICLE_NO'), lineIdx); - Items['BA'] := CELL(*FIELD('INVI_ORI_DESCRIPTION'), lineIdx); - Items['BB'] := CELL(*FIELD('INVI_QUANTITY'), lineIdx); - Items['BC'] := CELL(*FIELD('INVI_QUANTITY_UNIT'), lineIdx); - Items['BD'] := CELL(*FIELD('INVI_SINGLE_NET_PRICE'), lineIdx); - Items['BE'] := CELL(*FIELD('INVI_TOTAL_NET_PRICE'), lineIdx); - Items['BF'] := 'DD_DbExport.spl'; - - //stdWriteLog('Message',STRING_FORMAT('DD_DbExport - OnAnalyserFinishDocument - Items: %1','EXEC dbo.PRDD_INSERT_ANALYZER_ITEMS'),''); - SQL_EXEC dbeGetHandle(),'EXEC dbo.PRDD_INSERT_ANALYZER_ITEMS ?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?' PARAMS dbuDictToVector(Items); + //stdWriteLog('Message',STRING_FORMAT('DD_DbExport - OnAnalyserFinishDocument - Head: %1','EXEC dbo.PRDD_INSERT_ANALYZER_HEAD'),''); + SQL_EXEC dbeGetHandle(),'EXEC dbo.PRDD_INSERT_ANALYZER_HEAD ?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?' PARAMS dbuDictToVector(Head); SQL_COMMIT(dbeGetHandle()); + + // Schleife für die Positionsmitte + FOR lineIdx := 1 TO NUM_LINES('InvoiceItems')-1 { + + Items := DICT(); + Items['AA'] := uid; + Items['AB'] := CELL(*FIELD('INVI_POS_NO'), lineIdx)+0; + Items['AC'] := CELL(*FIELD('INVI_ARTICLE_NO'), lineIdx); + Items['AD'] := CELL(*FIELD('INVI_CHARGE_AMOUNT1'), lineIdx); + Items['AE'] := CELL(*FIELD('INVI_CHARGE_AMOUNT2'), lineIdx); + Items['AF'] := CELL(*FIELD('INVI_CHARGE_AMOUNT3'), lineIdx); + Items['AG'] := CELL(*FIELD('INVI_CHARGE_PERCENT1'), lineIdx); + Items['AH'] := CELL(*FIELD('INVI_CHARGE_PERCENT2'), lineIdx); + Items['AI'] := CELL(*FIELD('INVI_CHARGE_PERCENT3'), lineIdx); + Items['AJ'] := CELL(*FIELD('INVI_CHARGE_PER_PIECE1'), lineIdx); + Items['AK'] := CELL(*FIELD('INVI_CHARGE_PER_PIECE2'), lineIdx); + Items['AL'] := CELL(*FIELD('INVI_CHARGE_PER_PIECE3'), lineIdx); + Items['AM'] := CELL(*FIELD('INVI_DELIVERY_DATE'), lineIdx); + Items['AN'] := CELL(*FIELD('INVI_DELIVERY_NO'), lineIdx); + Items['AO'] := CELL(*FIELD('INVI_DIFF_CHK'), lineIdx); + Items['AP'] := CELL(*FIELD('INVI_DISCOUNT_AMOUNT1'), lineIdx); + Items['AQ'] := CELL(*FIELD('INVI_DISCOUNT_AMOUNT2'), lineIdx); + Items['AR'] := CELL(*FIELD('INVI_DISCOUNT_AMOUNT3'), lineIdx); + Items['AS'] := CELL(*FIELD('INVI_DISCOUNT_PERCENT1'), lineIdx); + Items['AT'] := CELL(*FIELD('INVI_DISCOUNT_PERCENT2'), lineIdx); + Items['AU'] := CELL(*FIELD('INVI_DISCOUNT_PERCENT3'), lineIdx); + Items['AV'] := CELL(*FIELD('INVI_DISCOUNT_PER_PIECE1'), lineIdx); + Items['AW'] := CELL(*FIELD('INVI_DISCOUNT_PER_PIECE2'), lineIdx); + Items['AX'] := CELL(*FIELD('INVI_DISCOUNT_PER_PIECE3'), lineIdx); + Items['AY'] := CELL(*FIELD('INVI_IS_DELIVERY'), lineIdx); + Items['AZ'] := CELL(*FIELD('INVI_ORI_ARTICLE_NO'), lineIdx); + Items['BA'] := CELL(*FIELD('INVI_ORI_DESCRIPTION'), lineIdx); + Items['BB'] := CELL(*FIELD('INVI_QUANTITY'), lineIdx); + Items['BC'] := CELL(*FIELD('INVI_QUANTITY_UNIT'), lineIdx); + Items['BD'] := CELL(*FIELD('INVI_SINGLE_NET_PRICE'), lineIdx); + Items['BE'] := CELL(*FIELD('INVI_TOTAL_NET_PRICE'), lineIdx); + Items['BF'] := 'DD_DbExport.spl'; + + //stdWriteLog('Message',STRING_FORMAT('DD_DbExport - OnAnalyserFinishDocument - Items: %1','EXEC dbo.PRDD_INSERT_ANALYZER_ITEMS'),''); + SQL_EXEC dbeGetHandle(),'EXEC dbo.PRDD_INSERT_ANALYZER_ITEMS ?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?' PARAMS dbuDictToVector(Items); + SQL_COMMIT(dbeGetHandle()); - } // end for loop - + } // end for loop + // Vergleiche Head und Items und schreibe Result in TB Result := DICT(); Result['AA'] := uid; @@ -152,6 +158,12 @@ FUNCTION OnAnalyserFinishDocument() { //IF [#AMOUNT_LEARN] = [INV_AMOUNT] THEN // stdWriteLog('Message',STRING_FORMAT('DD OnAnalyserFinishDocument - : %1','[#AMOUNT_LEARN] = [INV_AMOUNT]'),''); + + } // End IF (documentnumber = 1) + + ELSE { + stdWriteLog('Message',STRING_FORMAT('DD Skipping NUM_DOCS: %1',documentnumber),''); + } } // end OnAnalyserFinishDocument /****************************************************************************** diff --git a/SERVER/Insiders/SQL/[FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM].sql b/SERVER/Insiders/SQL/[FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM].sql new file mode 100644 index 0000000..ec75579 --- /dev/null +++ b/SERVER/Insiders/SQL/[FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM].sql @@ -0,0 +1,78 @@ + +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +CREATE OR ALTER FUNCTION [FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM] ( + @pREFERENCE_ID NVARCHAR(100), + @pSTATUS NVARCHAR(50), + @pSTATUS_DETAIL NVARCHAR(MAX) +) +RETURNS @vTB_RESULT TABLE ([REFERENCE_ID] [NVARCHAR](100) NOT NULL, + [STATUS] [NVARCHAR](50) NOT NULL, + [STATUS_DETAIL] [NVARCHAR](max) NOT NULL) +AS +BEGIN + + ---------------------------------------------------------------------------------------------- + -- Define vars + ---------------------------------------------------------------------------------------------- + DECLARE @REFERENCE_ID NVARCHAR(100), + @STATUS NVARCHAR(50), + @STATUS_DETAIL NVARCHAR(MAX), + @HEAD_SUM FLOAT, + @ITEMS_SUM FLOAT; + + SET @REFERENCE_ID = @pREFERENCE_ID + SET @STATUS = @pSTATUS + SET @STATUS_DETAIL = @pSTATUS_DETAIL + + ---------------------------------------------------------------------------------------------- + -- Check sum of Head and Items + ---------------------------------------------------------------------------------------------- + + -- Get sum from head + SELECT @HEAD_SUM = [INV_NET_AMOUNT1] + FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_HEAD] + WHERE [REFERENCE_ID] = @pREFERENCE_ID + + -- Get sum from items + SELECT @ITEMS_SUM = SUM(INVI_TOTAL_NET_PRICE) + FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_ITEMS] + WHERE [REFERENCE_ID] = @pREFERENCE_ID + + -- Status "failed" must not be overwritten + IF (@STATUS <> 'FAILED') + BEGIN + SET @STATUS = CASE + WHEN (@HEAD_SUM = @ITEMS_SUM) THEN 'SUCCESS' + WHEN (@HEAD_SUM > @ITEMS_SUM) THEN 'FAILED' + WHEN (@HEAD_SUM < @ITEMS_SUM) THEN 'FAILED' + ELSE 'ERROR' + END + END + + SET @STATUS_DETAIL = CASE + WHEN (@HEAD_SUM = @ITEMS_SUM) THEN @STATUS_DETAIL + 'Head and Item sum match!' + char(10) + char(13) + WHEN (@HEAD_SUM > @ITEMS_SUM) THEN @STATUS_DETAIL + 'Head sum (' + convert(VARCHAR(100),@HEAD_SUM) +') is bigger then Item sum (' + convert(VARCHAR(100),@ITEMS_SUM) +')!' + char(10) + char(13) + WHEN (@HEAD_SUM < @ITEMS_SUM) THEN @STATUS_DETAIL + 'Head sum (' + convert(VARCHAR(100),@HEAD_SUM) +') is lesser then Item sum (' + convert(VARCHAR(100),@ITEMS_SUM) +')!' + char(10) + char(13) + ELSE @STATUS_DETAIL + 'ERROR in FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM' + char(10) + char(13) + END + + ---------------------------------------------------------------------------------------------- + -- Set function result Table + ---------------------------------------------------------------------------------------------- + + INSERT INTO @vTB_RESULT ([REFERENCE_ID], + [STATUS], + [STATUS_DETAIL]) + + VALUES (@REFERENCE_ID, + @STATUS, + @STATUS_DETAIL); + + RETURN; + ---------------------------------------------------------------------------------------------- + +END diff --git a/SERVER/Insiders/SQL/[PRDD_INSERT_ANALYZER_RESULT].sql b/SERVER/Insiders/SQL/[PRDD_INSERT_ANALYZER_RESULT].sql index f2132c4..c939110 100644 --- a/SERVER/Insiders/SQL/[PRDD_INSERT_ANALYZER_RESULT].sql +++ b/SERVER/Insiders/SQL/[PRDD_INSERT_ANALYZER_RESULT].sql @@ -1,91 +1,96 @@ USE [SmartFix_Export_DB_Invoice] GO - -/****** Object: StoredProcedure [dbo].[PRDD_INSERT_ANALYZER_RESULT] Script Date: 06.03.2024 16:20:47 ******/ +/****** Object: StoredProcedure [dbo].[PRDD_INSERT_ANALYZER_RESULT] Script Date: 08.04.2024 13:37:51 ******/ SET ANSI_NULLS ON GO - SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: Digital Data GmbH MD/MK --- Create date: 06.03.2024 +-- Create date: 11.04.2024 -- Description: Insert row in TBDD_ANALYZER_RESULT -- ============================================= -CREATE OR ALTER PROCEDURE [dbo].[PRDD_INSERT_ANALYZER_RESULT] +ALTER PROCEDURE [dbo].[PRDD_INSERT_ANALYZER_RESULT] @pREFERENCE_ID NVARCHAR(100), - @pAdded_who NVARCHAR(50) + @pADDED_WHO NVARCHAR(50) AS BEGIN + ---------------------------------------------------------------------------------------------- + -- Get Configuration + ---------------------------------------------------------------------------------------------- + + DECLARE @WORKING_MODE TINYINT; + SELECT @WORKING_MODE = [WORKING_MODE] FROM [TBDD_ANALYZER_BASE_CONFIG] WHERE [GUID] = (SELECT max(GUID) FROM [TBDD_ANALYZER_BASE_CONFIG]); + + ---------------------------------------------------------------------------------------------- -- Final Vars for insert - DECLARE @STATUS NVARCHAR(50), + ---------------------------------------------------------------------------------------------- + + DECLARE @REFERENCE_ID NVARCHAR(100), + @ADDED_WHO NVARCHAR(50), + @STATUS NVARCHAR(50), @STATUS_DETAIL NVARCHAR(MAX); + SET @REFERENCE_ID = @pREFERENCE_ID; + SET @ADDED_WHO = @pADDED_WHO; SET @STATUS = 'UNDEFINED'; SET @STATUS_DETAIL = ''; - -- Temp vars for calculation - DECLARE @HEAD_SUM FLOAT, - @ITEMS_SUM FLOAT; + ---------------------------------------------------------------------------------------------- + -- Ermittle, ob es zu verarbeitende Zeilen für die ReferenzID gibt + ---------------------------------------------------------------------------------------------- + + IF (((SELECT COUNT(*) FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_HEAD] (NOLOCK) WHERE [REFERENCE_ID] = @REFERENCE_ID AND [STATUS] = 'unprocessed') = 1) and (SELECT count(*) FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_ITEMS] (NOLOCK) WHERE [REFERENCE_ID] = @REFERENCE_ID AND [STATUS] = 'unprocessed') >= 1) + BEGIN + + PRINT 'Unprocessed DB lines rows found, proceeding...' - IF (((SELECT COUNT(*) FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_HEAD] (NOLOCK) WHERE [REFERENCE_ID] = @pREFERENCE_ID AND [STATUS] = 'unprocessed') = 1) and (SELECT count(*) FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_ITEMS] (NOLOCK) WHERE [REFERENCE_ID] = @pREFERENCE_ID AND [STATUS] = 'unprocessed') >= 1) - BEGIN - ---------------------------------------------------------------------------------------------- - -- 1. Check sum of Head and Items + -- 1 = Kopf&Fuß-daten ohne Matching; 2 = Kopf&Fuß-daten mit Matching ---------------------------------------------------------------------------------------------- - -- Get sum from head - SELECT @HEAD_SUM = [INV_NET_AMOUNT1] - FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_HEAD] - WHERE [REFERENCE_ID] = @pREFERENCE_ID + IF @WORKING_MODE in (1,2) + BEGIN - -- Get sum from items - SELECT @ITEMS_SUM = SUM(INVI_TOTAL_NET_PRICE) - FROM [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_ITEMS] - WHERE [REFERENCE_ID] = @pREFERENCE_ID + PRINT 'WORKING_MODE = 1 or 2' - -- Status "failed" must not be overwritten - IF (@STATUS <> 'FAILED') - BEGIN - SET @STATUS = CASE - WHEN (@HEAD_SUM = @ITEMS_SUM) THEN 'SUCCESS' - WHEN (@HEAD_SUM > @ITEMS_SUM) THEN 'FAILED' - WHEN (@HEAD_SUM < @ITEMS_SUM) THEN 'FAILED' - END END - SET @STATUS_DETAIL = CASE - WHEN (@HEAD_SUM = @ITEMS_SUM) THEN @STATUS_DETAIL + 'Head and Item sum match!' + char(10) + char(13) - WHEN (@HEAD_SUM > @ITEMS_SUM) THEN @STATUS_DETAIL + 'Head sum (' + convert(VARCHAR(100),@HEAD_SUM) +') is bigger then Item sum (' + convert(VARCHAR(100),@ITEMS_SUM) +')!' + char(10) + char(13) - WHEN (@HEAD_SUM < @ITEMS_SUM) THEN @STATUS_DETAIL + 'Head sum (' + convert(VARCHAR(100),@HEAD_SUM) +') is lesser then Item sum (' + convert(VARCHAR(100),@ITEMS_SUM) +')!' + char(10) + char(13) - END - + ---------------------------------------------------------------------------------------------- + -- 3 Kopf&Fuß&Positionen ohne Matching; 4 Kopf&Fuß&Positionen mit Matching ---------------------------------------------------------------------------------------------- - INSERT INTO [TBDD_ANALYZER_RESULT] ([REFERENCE_ID], - [STATUS], - [STATUS_DETAIL], - [ADDED_WHO]) + ELSE IF @WORKING_MODE in (3,4) + BEGIN - VALUES (@pREFERENCE_ID, - @STATUS, - @STATUS_DETAIL, - @pAdded_who); + PRINT 'WORKING_MODE = 3 or 4' + + -- Compare Head with Item sum + SELECT @STATUS = [STATUS], + @STATUS_DETAIL = [STATUS_DETAIL] + FROM [SmartFix_Export_DB_Invoice].[dbo].[FNDD_ANALYZER_COMPARE_HEAD_SUM_WITH_ITEMS_SUM](@REFERENCE_ID,@STATUS,@STATUS_DETAIL) + + END ---------------------------------------------------------------------------------------------- + -- Nach erfolgreicher Verarbeitung, die Zeilen als "processed" markieren + ---------------------------------------------------------------------------------------------- + + PRINT 'Setting processed rows in [TBDD_ANALYZER_HEAD] and [TBDD_ANALYZER_ITEMS]' UPDATE [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_HEAD] SET [STATUS] = 'processed' - WHERE [REFERENCE_ID] = @pREFERENCE_ID + WHERE [REFERENCE_ID] = @REFERENCE_ID UPDATE [SmartFix_Export_DB_Invoice].[dbo].[TBDD_ANALYZER_ITEMS] SET [STATUS] = 'processed' - WHERE [REFERENCE_ID] = @pREFERENCE_ID + WHERE [REFERENCE_ID] = @REFERENCE_ID + ---------------------------------------------------------------------------------------------- + -- Rückmeldung an insiders DB geben ---------------------------------------------------------------------------------------------- IF (@STATUS = 'SUCCESS') @@ -94,6 +99,20 @@ BEGIN END ---------------------------------------------------------------------------------------------- + -- Ergebnis in Result Tabelle schreiben + ---------------------------------------------------------------------------------------------- + + PRINT 'Inserting Results in [TBDD_ANALYZER_RESULT]' + + INSERT INTO [TBDD_ANALYZER_RESULT] ([REFERENCE_ID], + [STATUS], + [STATUS_DETAIL], + [ADDED_WHO]) + + VALUES (@REFERENCE_ID, + @STATUS, + @STATUS_DETAIL, + @ADDED_WHO); END @@ -101,18 +120,17 @@ BEGIN BEGIN - SET @STATUS = 'UNREFERENCED'; - SET @STATUS_DETAIL = 'Insufficient rows in DB!' + PRINT 'Inappropriate rows in DB!' INSERT INTO [TBDD_ANALYZER_RESULT] ([REFERENCE_ID], [STATUS], [STATUS_DETAIL], [ADDED_WHO]) - VALUES (@pREFERENCE_ID, - @STATUS, - @STATUS_DETAIL, - @pAdded_who); + VALUES (@REFERENCE_ID, + 'UNREFERENCED', + 'Inappropriate rows in DB!', + @ADDED_WHO); END + END -GO \ No newline at end of file