Revision der Schleupen Schnittstelle

- NOLOCKs und FAST_FORWARDs eingebaut
- Arbeitstabelle eingebaut um Überschneidungen der Exportnummern zu verhindern
This commit is contained in:
KammM 2024-09-27 19:25:51 +02:00
parent 1ffac8878c
commit de25541233
7 changed files with 713 additions and 73 deletions

View File

@ -1,20 +1,18 @@
USE [DD_ECM]
GO
Object StoredProcedure [dbo].[PRCUST_EXPORT_POSTING_DATA] Script Date 21.03.2024 155901
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- TSQL Prozedur - Zentrale Logik zur Erstellung der Schnittstellendatei für Schleupen.
-- Stand MK 04.02.2022
-- 04.02.2022 Änderung des Dateinamensschemas - es wird nun die Buchungsnummer in den Dateinamen geschrieben und nicht mehr die Export Zählernummer
-- 27.11.2021 Erweiterung der Logik, um die Möglichkeit EXPORT_BOOKING_NUMBERs gemischt aus diesem und dem nächsten Jahr (- Unterschiedliche Nummernkreise!) zu erstellen (Basis ist das windream Belegdatum)
-- 31.01.2021 Initial
-- MK // 27.09.2024
-- 27.09.2024 MK Implementierung, um doppelte Nummernvergabe zu verhindern
-- 04.02.2022 MK Änderung des Dateinamensschemas - es wird nun die Buchungsnummer in den Dateinamen geschrieben und nicht mehr die Export Zählernummer
-- 27.11.2021 MK Erweiterung der Logik, um die Möglichkeit "EXPORT_BOOKING_NUMBERs" gemischt aus diesem und dem nächsten Jahr (-> Unterschiedliche Nummernkreise!) zu erstellen (Basis ist das windream Belegdatum)
-- 31.01.2021 MK Initial
---- To run the file export in this procedure, it is n to reconfigure the sql server
-- sp_configure 'show advanced options', 1;
@ -30,7 +28,7 @@ GO
-- RECONFIGURE WITH OVERRIDE
-- GO
CREATE PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA]
CREATE OR ALTER PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA]
@JOB_GUID INT,
@windreamDocID BIGINT,
@windreamStatus VARCHAR(20) = 'erledigt',
@ -39,10 +37,10 @@ AS
PRINT '==============================='
PRINT 'PROCEDURE - START [PRCUST_EXPORT_POSTING_DATA] @ ' + CONVERT(varchar(50),GETDATE(),120)
PRINT 'PARAMETER1 - @JOB_GUID ' + CONVERT(varchar(50),@JOB_GUID)
PRINT 'PARAMETER2 - @windreamDocID ' + CONVERT(varchar(50),@windreamDocID)
PRINT 'PARAMETER3 - @windreamStatus ' + CONVERT(varchar(50),@windreamStatus)
PRINT 'PARAMETER4 - @windreamExportDate ' + CONVERT(varchar(50),@windreamExportDate)
PRINT 'PARAMETER1 - @JOB_GUID: ' + CONVERT(varchar(50),@JOB_GUID)
PRINT 'PARAMETER2 - @windreamDocID: ' + CONVERT(varchar(50),@windreamDocID)
PRINT 'PARAMETER3 - @windreamStatus: ' + CONVERT(varchar(50),@windreamStatus)
PRINT 'PARAMETER4 - @windreamExportDate: ' + CONVERT(varchar(50),@windreamExportDate)
BEGIN TRY
@ -65,12 +63,12 @@ BEGIN TRY
--===============================================-- There should be exact one file --===============================================--
(SELECT @FileCount = count()
FROM [windream60].[dbo].[BaseAttributes]
(SELECT @FileCount = count(*)
FROM [windream60].[dbo].[BaseAttributes] (NOLOCK)
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate)
OR ([dwDate04] = '19700101') -- Dummy Value, because PM FinalIndex cannot handle NUll as Result in case of Angehalten or Abgelehnt
OR ([dwDate04] = '19700101') -- Dummy Value, because PM FinalIndex cannot handle NUll as Result in case of "Angehalten" or "Abgelehnt"
OR ([dwDate04] IS NULL)))
IF ((@windreamStatus = 'erledigt') and (@FileCount = 1))
@ -80,24 +78,23 @@ BEGIN TRY
SELECT @JOB_NAME = [JOB_NAME],
@MANDATOR = [MANDANTOR],
@EXPORT_TYPE = [EXPORT_TYPE]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG] (NOLOCK)
WHERE [GUID] = @JOB_GUID
--=============================================-- Get windream File Indices --=============================================--
SELECT @DocumentDate = [dwDate09] -- = Needed for setting Booking Number
FROM [windream60].[dbo].[BaseAttributes]
FROM [windream60].[dbo].[BaseAttributes] (NOLOCK)
WHERE [dwDocID] = @windreamDocID
--===============================================-- Get File config infos --===============================================--
SELECT @GUID = [GUID],
@EXPORT_BOOKING_NUMBER_BASE = [EXPORT_BOOKING_NUMBER_BASE],
@EXPORT_BOOKING_NUMBER_COUNTER = [EXPORT_BOOKING_NUMBER_COUNTER]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG]
@EXPORT_BOOKING_NUMBER_BASE = [EXPORT_BOOKING_NUMBER_BASE]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] (NOLOCK)
WHERE [JOB_GUID] = @JOB_GUID
--===============================================-- Get and Set Booking Number --===============================================--
IF (@DocumentDate IS NOT NULL)
BEGIN -- If windream Belegdatum is set, take year as base value
BEGIN -- If "windream Belegdatum" is set, take year as base value
SET @DATE_YY = RIGHT(LEFT(@DocumentDate,4),2)
END
ELSE
@ -107,18 +104,40 @@ BEGIN TRY
----------------------------------------------------------------------------------------------------------------------------------
PRINT 'Searching for existing numbers in temp table...'
IF (SELECT COUNT(*) FROM [TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] (NOLOCK) WHERE [JOB_GUID] = @JOB_GUID AND [ADDED_WHO] = '[PRCUST_EXPORT_POSTING_DATA]') > 0
BEGIN
SELECT TOP 1 @EXPORT_BOOKING_NUMBER_COUNTER = [EXPORT_BOOKING_NUMBER_COUNTER]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] (NOLOCK)
WHERE [JOB_GUID] = @JOB_GUID
AND [ADDED_WHO] = '[PRCUST_EXPORT_POSTING_DATA]'
ORDER BY [EXPORT_BOOKING_NUMBER] DESC
PRINT 'Found value in temp table!'
END
ELSE
BEGIN
SELECT @EXPORT_BOOKING_NUMBER_COUNTER = [EXPORT_BOOKING_NUMBER_COUNTER]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] (NOLOCK)
WHERE [JOB_GUID] = @JOB_GUID
PRINT 'Nothing found in temp table using config table!'
END
----------------------------------------------------------------------------------------------------------------------------------
PRINT 'Searching for existing numbers in history table...'
PRINT (convert(varchar(2),@DATE_YY) + '%')
-- Check histroy table if there are numbers with same prefix (= the year)
-- Check history table if there are numbers with same prefix (= the year)
SELECT @EXPORT_BOOKING_NUMBER_MAXCOUNT = MAX(EXPORT_BOOKING_NUMBER)
FROM [DD_ECM].[dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_ARCHIV]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_ARCHIV] (NOLOCK)
WHERE [EXPORT_BOOKING_NUMBER] LIKE (convert(varchar(2),@DATE_YY) + '%')
IF (@EXPORT_BOOKING_NUMBER_MAXCOUNT IS NOT NULL)
BEGIN
PRINT 'Highest number found ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_MAXCOUNT)
PRINT 'Highest number found: ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_MAXCOUNT)
SET @EXPORT_BOOKING_NUMBER = CONVERT(INT,@EXPORT_BOOKING_NUMBER_MAXCOUNT)
SET @EXPORT_BOOKING_NUMBER = CONVERT(INT,@EXPORT_BOOKING_NUMBER)
@ -135,13 +154,13 @@ BEGIN TRY
END
PRINT ''
PRINT '@EXPORT_BOOKING_NUMBER_BASE ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_BASE)
PRINT '@EXPORT_BOOKING_NUMBER_BASENOW ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_BASE_NOW)
PRINT '@EXPORT_BOOKING_NUMBER_COUNTER ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_COUNTER)
PRINT '@EXPORT_BOOKING_NUMBER_BASE: ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_BASE)
PRINT '@EXPORT_BOOKING_NUMBER_BASENOW: ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_BASE_NOW)
PRINT '@EXPORT_BOOKING_NUMBER_COUNTER: ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_COUNTER)
----------------------------------------------------------------------------------------------------------------------------------
-- If Booking number base (like 2100000) is not the initial value
IF (@EXPORT_BOOKING_NUMBER_BASE @EXPORT_BOOKING_NUMBER_BASE_NOW)
IF (@EXPORT_BOOKING_NUMBER_BASE <> @EXPORT_BOOKING_NUMBER_BASE_NOW)
BEGIN
SET @EXPORT_BOOKING_NUMBER_BASE = @EXPORT_BOOKING_NUMBER_BASE_NOW
Update [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG]
@ -149,10 +168,11 @@ BEGIN TRY
WHERE JOB_GUID = @JOB_GUID
END;
PRINT '@EXPORT_BOOKING_NUMBER_BASE (final) ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_BASE)
PRINT '@EXPORT_BOOKING_NUMBER_BASE (final): ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_BASE)
----------------------------------------------------------------------------------------------------------------------------------
SET @EXPORT_BOOKING_NUMBER_COUNTER = convert(bigint,@EXPORT_BOOKING_NUMBER_COUNTER)
IF (@EXPORT_BOOKING_NUMBER_COUNTER = 0) or (@EXPORT_BOOKING_NUMBER_COUNTER is null)
IF (@EXPORT_BOOKING_NUMBER_COUNTER <= 0) or (@EXPORT_BOOKING_NUMBER_COUNTER is null)
BEGIN
SET @EXPORT_BOOKING_NUMBER_COUNTER = 1
Update [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG]
@ -169,22 +189,27 @@ BEGIN TRY
WHERE JOB_GUID = @JOB_GUID
END;
PRINT '@EXPORT_BOOKING_NUMBER_COUNTER ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_COUNTER)
PRINT '@EXPORT_BOOKING_NUMBER_COUNTER: ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER_COUNTER)
----------------------------------------------------------------------------------------------------------------------------------
IF (@EXPORT_BOOKING_NUMBER_BASE = 1) and (@EXPORT_BOOKING_NUMBER_COUNTER = 1)
IF (@EXPORT_BOOKING_NUMBER_BASE >= 1) and (@EXPORT_BOOKING_NUMBER_COUNTER >= 1)
BEGIN
SET @EXPORT_BOOKING_NUMBER = convert(bigint,@EXPORT_BOOKING_NUMBER_BASE) + convert(bigint,@EXPORT_BOOKING_NUMBER_COUNTER)
END
ELSE
SET @EXPORT_BOOKING_NUMBER = '9999999';
PRINT '@EXPORT_BOOKING_NUMBER (final) ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER)
PRINT '@EXPORT_BOOKING_NUMBER (final): ' + convert(varchar(100),@EXPORT_BOOKING_NUMBER)
----------------------------------------------------------------------------------------------------------------------------------
--=============================================-- Fill temp table for busy check --=============================================--
INSERT INTO [TBCUST_EXPORT_POSTING_DATA_FILE_TEMP]([JOB_GUID],[DOCID],[EXPORT_BOOKING_NUMBER_COUNTER],[EXPORT_BOOKING_NUMBER],[COMMENT],[ADDED_WHO],[ADDED_WHEN])
VALUES(@JOB_GUID,@windreamDocID,@EXPORT_BOOKING_NUMBER_COUNTER,@EXPORT_BOOKING_NUMBER,NULL,'[PRCUST_EXPORT_POSTING_DATA]',GETDATE())
----------------------------------------------------------------------------------------------------------------------------------
--===============================================-- Fill table with content --===============================================--
INSERT INTO [TBCUST_EXPORT_POSTING_DATA_FILE_CONTENT]
([FILE_CONFIG_GUID],
[FILE_CONTENT])
INSERT INTO [TBCUST_EXPORT_POSTING_DATA_FILE_CONTENT]([FILE_CONFIG_GUID],[FILE_CONTENT])
SELECT @GUID, [FILE_CONTENT_BODY]
FROM [FNCUST_FORMAT-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN](@JOB_GUID,@EXPORT_BOOKING_NUMBER,@windreamDocID,@windreamStatus,@windreamExportDate)
@ -196,6 +221,17 @@ BEGIN TRY
PRINT 'PROCEDURE - END [PRCUST_EXPORT_POSTING_DATA] @ ' + CONVERT(varchar(50),GETDATE(),120)
PRINT '==============================='
--=============================================-- Clear temp table for busy check --=============================================--
DELETE
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_TEMP]
WHERE [JOB_GUID] = @JOB_GUID
AND [DOCID] = @windreamDocID
AND [EXPORT_BOOKING_NUMBER_COUNTER] = @EXPORT_BOOKING_NUMBER_COUNTER
AND [EXPORT_BOOKING_NUMBER] = @EXPORT_BOOKING_NUMBER
AND [ADDED_WHO] = '[PRCUST_EXPORT_POSTING_DATA]'
----------------------------------------------------------------------------------------------------------------------------------
END
ELSE
@ -203,16 +239,16 @@ BEGIN TRY
PRINT 'No rows in data table found!'
PRINT ''
PRINT 'Please check if File was already exported!'
PRINT '1. Check if windream Date [dwdate04] is set Must be unset or 19700101! (19700101 = 1.1.1970)! '
PRINT '2. Check if windream Status [szText33] is set to erledigt!'
PRINT '3. Check if WF Zahlungsfreigabe der Geschäftsführung [Vektor_Boolean_06] ist set to truewahr, '
PRINT ' have to be falsefalsch!'
PRINT '1. Check if windream Date [dwdate04] is set? Must be unset or 19700101! (19700101 = 1.1.1970)! '
PRINT '2. Check if windream Status [szText33] is set to "erledigt"!'
PRINT '3. Check if WF: Zahlungsfreigabe der Geschäftsführung [Vektor_Boolean_06] ist set to true/wahr, '
PRINT ' have to be false/falsch!'
PRINT ''
PRINT 'PROCEDURE - END [PRCUST_EXPORT_POSTING_DATA] @ ' + CONVERT(varchar(50),GETDATE(),120)
PRINT '==============================='
RETURN 1 -- IF @windreamStatus 'erledigt'
RETURN 1 -- IF @windreamStatus <> 'erledigt'
END
END TRY
@ -223,12 +259,9 @@ BEGIN CATCH
--FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONTENT]
--WHERE [FILE_CONFIG_GUID] = @GUID
PRINT 'ERROR IN PROCEDURE ' + CONVERT(VARCHAR(50),ERROR_PROCEDURE())
+ ' - ERROR-MESSAGE '
PRINT 'ERROR IN PROCEDURE: ' + CONVERT(VARCHAR(50),ERROR_PROCEDURE())
+ ' - ERROR-MESSAGE: '
+ CONVERT(VARCHAR(500),ERROR_MESSAGE())
--EXEC [PRCUST_EXPORT_POSTING_DATA_WRITE_JOB_LOG] @JOB_GUID, 'File','Procedure PRCUST_EXPORT_POSTING_DATA_CREATE_FILE'--, CONVERT(VARCHAR(30),ERROR_PROCEDURE()), ERROR_MESSAGE
--EXEC [PRCUST_EXPORT_POSTING_DATA_WRITE_JOB_LOG] @JOB_GUID, 'File:','Procedure: PRCUST_EXPORT_POSTING_DATA_CREATE_FILE'--, CONVERT(VARCHAR(30),ERROR_PROCEDURE()), ERROR_MESSAGE
RETURN 1
END CATCH
GO

View File

@ -1,16 +1,13 @@
USE [DD_ECM]
GO
/****** Object: StoredProcedure [dbo].[PRCUST_EXPORT_POSTING_DATA_BUILD_FILE_NAME] Script Date: 21.03.2024 15:59:35 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA_BUILD_FILE_NAME]
CREATE OR ALTER PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA_BUILD_FILE_NAME]
@JOB_GUID INT, -- Mandatory Parameter, to build the file name
@EXPORT_BOOKING_NUMBER VARCHAR(50),
@FILE_NAME VARCHAR(50) OUTPUT
@ -33,7 +30,7 @@ BEGIN TRY
@FILE_NAME_SEPARATOR = [FILE_NAME_SEPARATOR],
@FILE_RUNNING_NUMBER = [FILE_RUNNING_NUMBER],
@FILE_EXTENSION = [FILE_EXTENSION]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] (NOLOCK)
WHERE [JOB_GUID] = @JOB_GUID
IF (@EXPORT_BOOKING_NUMBER is null) or (@EXPORT_BOOKING_NUMBER < 0)

View File

@ -1,15 +1,12 @@
USE [DD_ECM]
GO
/****** Object: StoredProcedure [dbo].[PRCUST_EXPORT_POSTING_DATA_COLLECT_FILE_CONTENT] Script Date: 21.03.2024 16:00:05 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA_COLLECT_FILE_CONTENT]
CREATE OR ALTER PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA_COLLECT_FILE_CONTENT]
@JOB_GUID INT,
@windreamDocID BIGINT,
@windreamStatus VARCHAR(20) = 'erledigt',
@ -60,7 +57,7 @@ BEGIN TRY
SELECT @JOB_NAME = [JOB_NAME],
@MANDATOR = [MANDANTOR],
@EXPORT_TYPE = [EXPORT_TYPE]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG] (NOLOCK)
WHERE [GUID] = @JOB_GUID
INSERT INTO @WINDREAM_2_SCHLEUPEN ([Belegnummer (X)],
@ -113,7 +110,7 @@ BEGIN TRY
NULL as [Skontotage 2],
NULL as [Skonto Prozent 2],
NULL as [Nettotage]
FROM [windream60].[dbo].[BaseAttributes]
FROM [windream60].[dbo].[BaseAttributes] (NOLOCK)
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate) OR ([dwDate04] IS NULL))
@ -138,6 +135,3 @@ BEGIN CATCH
RETURN 1
END CATCH
GO

View File

@ -1,16 +1,16 @@
USE [DD_ECM]
GO
/****** Object: StoredProcedure [dbo].[PRCUST_EXPORT_POSTING_DATA_WRITE_FILE] Script Date: 21.03.2024 16:00:33 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- Prozedur welche die bereitsgesammelten Daten abruft und in Folge in eine Datei und ins Archiv schreibt.
-- Stand: MK // 30.01.2021
-- MK // 27.09.2024
-- 27.09.2024 MK NOLOCK und LOCAL FAST_FORWARD eingebaut
-- 30.01.2021 MK Initial
---- To run the file export in this procedure, it is n to reconfigure the sql server
-- sp_configure 'show advanced options', 1;
@ -26,7 +26,7 @@ GO
-- RECONFIGURE WITH OVERRIDE
-- GO
CREATE PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA_WRITE_FILE]
CREATE OR ALTER PROCEDURE [dbo].[PRCUST_EXPORT_POSTING_DATA_WRITE_FILE]
@JOB_GUID INT,
@windreamDocID BIGINT,
@EXPORT_BOOKING_NUMBER BIGINT
@ -76,7 +76,7 @@ BEGIN TRY
SELECT @JOB_NAME = [JOB_NAME],
@MANDATOR = [MANDANTOR],
@EXPORT_TYPE = [EXPORT_TYPE]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG] (NOLOCK)
WHERE [GUID] = @JOB_GUID
-- Get export file content
@ -119,7 +119,7 @@ BEGIN TRY
@FILE_PATH_EXPORT = RTRIM(LTRIM(CONVERT(VARCHAR(500),[FILE_PATH_EXPORT]))),
@FILE_PATH_ARCHIV = RTRIM(LTRIM(CONVERT(VARCHAR(500),[FILE_PATH_ARCHIV]))),
@FILE_PATH_ERROR = RTRIM(LTRIM(CONVERT(VARCHAR(500),[FILE_PATH_ERROR])))
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] (NOLOCK)
WHERE [JOB_GUID] = @JOB_GUID
PRINT ' '
@ -175,7 +175,7 @@ BEGIN TRY
-- prepare cursor to write every content line
DECLARE CURSOR_WRITE_FILE_CONTENT CURSOR
FOR
LOCAL FAST_FORWARD FOR
SELECT [FILE_CONTENT_BODY_LINE]
FROM @FILE_CONTENT_BODY
@ -201,7 +201,7 @@ BEGIN TRY
-- prepare cursor to delete content lines
DECLARE CURSOR_DELETE_FILE_CONTENT CURSOR
FOR
LOCAL FAST_FORWARD FOR
SELECT [GUID]
FROM @FILE_CONTENT_BODY
@ -264,6 +264,3 @@ BEGIN CATCH
--EXEC [PRCUST_EXPORT_POSTING_DATA_WRITE_JOB_LOG] @JOB_GUID, 'File:','Procedure: PRCUST_EXPORT_POSTING_DATA_CREATE_FILE'--, CONVERT(VARCHAR(30),ERROR_PROCEDURE()), ERROR_MESSAGE
RETURN 1
END CATCH
GO

View File

@ -0,0 +1,32 @@
USE [DD_ECM]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP](
[GUID] [bigint] IDENTITY(1,1) NOT NULL,
[JOB_GUID] [int] NOT NULL,
[DOCID] [bigint] NOT NULL,
[EXPORT_BOOKING_NUMBER_COUNTER] [bigint] NOT NULL,
[EXPORT_BOOKING_NUMBER] [varchar](50) NOT NULL,
[COMMENT] [varchar](max) NULL,
[ADDED_WHO] [varchar](50) NOT NULL,
[ADDED_WHEN] [datetime] NOT NULL,
CONSTRAINT [PK_TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] PRIMARY KEY CLUSTERED
(
[GUID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
ALTER TABLE [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] ADD CONSTRAINT [DF_TBCUST_EXPORT_POSTING_DATA_FILE_TEMP_ADDED_WHO] DEFAULT ('DD_ECM DB-Internal') FOR [ADDED_WHO]
GO
ALTER TABLE [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] ADD CONSTRAINT [DF_TBCUST_EXPORT_POSTING_DATA_FILE_TEMP_ADDED_WHEN] DEFAULT (getdate()) FOR [ADDED_WHEN]
GO

View File

@ -0,0 +1,71 @@
USE [DD_ECM]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- MK // 27.09.2024
-- 27.09.2024 MK Trennzeichen wird nun variabel aus config Tabelle geholt
-- 27.08.2021 MK Sortierung nach Satzart eingefügt
-- 03.08.2021 MK Div. TRIM Befehle eingebaut
-- 25.02.2021 MK Betrag Konvertierung gäendert
CREATE OR ALTER FUNCTION [dbo].[FNCUST_FORMAT-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN] (
@JOB_GUID INT,
@EXPORT_BOOKING_NUMBER BIGINT,
@windreamDocID BIGINT,
@windreamStatus VARCHAR(20), -- Should be: 'erledigt'
@windreamExportDate VARCHAR(8) -- Should be: NULL
)
RETURNS @FILE_CONTENT TABLE (FILE_CONTENT_BODY [VARCHAR](max) NOT NULL)
AS
BEGIN
DECLARE @FILE_DATA_SEPARATOR VARCHAR(10);
SELECT @FILE_DATA_SEPARATOR = [FILE_DATA_SEPARATOR]
FROM [DD_ECM].[dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG]
WHERE [JOB_GUID] = @JOB_GUID
--Failsafe
SET @FILE_DATA_SEPARATOR = ISNULL(@FILE_DATA_SEPARATOR,';')
---------------------------------------------------------------------------------------------------------------------------------------------------------------
INSERT INTO @FILE_CONTENT(FILE_CONTENT_BODY)
SELECT ISNULL(CONVERT(VARCHAR(max),[Belegnummer (X)]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),CAST([Belegdatum (X)] as date), 104),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),CAST([Valutadatum] as date), 104),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Kontoart (X)]),'') + @FILE_DATA_SEPARATOR +
LTRIM(RTRIM(ISNULL(CONVERT(VARCHAR(max),[Kontonummer (X)]),''))) + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Gegenkontoart (X)]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Gegenkonto]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Zusatzkontoart]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Zusatzkonto]),'') + @FILE_DATA_SEPARATOR +
REPLACE(LTRIM(RTRIM(STR([Betrag],25,2))),'.',',') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[S/H-Kennzeichen]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Steuerschlüssel]),'') + @FILE_DATA_SEPARATOR +
LTRIM(RTRIM(ISNULL(CONVERT(VARCHAR(max),[Buchungstext]),''))) + @FILE_DATA_SEPARATOR +
LTRIM(RTRIM(ISNULL(CONVERT(VARCHAR(max),[Zahlungsträgerhinweis]),''))) + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),LTRIM(RTRIM([Geschäftsbereich]))),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),CAST([externes Rechnungsdatum] as date), 104),'') + @FILE_DATA_SEPARATOR +
LTRIM(RTRIM(ISNULL(CONVERT(VARCHAR(max),[externe Rechnungsnummer]),''))) + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Rechnungseinheit]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),CAST([Fälligkeitsdatum] as date), 104),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Skontotage 1]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Skonto Prozent 1]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Skontotage 2]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Skonto Prozent 2]),'') + @FILE_DATA_SEPARATOR +
ISNULL(CONVERT(VARCHAR(max),[Nettotage]),'')
FROM [FNCUST_GET-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN](@JOB_GUID,@EXPORT_BOOKING_NUMBER,@windreamDocID,@windreamStatus,@windreamExportDate)
ORDER BY [Satzart] ASC
---------------------------------------------------------------------------------------------------------------------------------------------------------------
RETURN;
END

View File

@ -0,0 +1,516 @@
USE [DD_ECM]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- MK // 27.09.2024
-- 27.09.2024 MK NOLOCK und LOCAL FAST_FORWARD eingebaut
-- 01.09.2021 MK Skontotage und Skontoprozent entfernt / auf NULL gesetzt
-- 27.08.2021 MK Satzart für die Sortierung eingefügt --> Funktion "FNCUST_FORMAT-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN" ruft dies ab
-- 03.08.2021 MK [Kontonummer (X)] von int auf varchar umgestellt, da die Nummern auch mit 0 beginnen kann!
-- 11.03.2021 MK Zeilenumbruch in Buchungstext abgefangen REPLACE(REPLACE([szText02],';',''),CHAR(13) + CHAR(10),'')
-- 10.03.2021 MK REPLACE(@INVOICE_SPLIT_BUSINESS_UNIT,';','') in die Cursor eingebaut, eigener Cursor für Geschäftsbereich hinzugefügt
-- 25.02.2021 MK Expliziete Float Konvertierung für "Betrag" eingebaut
-- 17.02.2021 MK Datumsfelder getauscht
-- 11.02.2021 MK Fehler im 3. cursor behoben (@INVOICE_SPLIT_COSTUNIT)
-- 11.02.2021 MK Cursor für neue Rechnungsaufteilungstabelle überarbeitet
-- 11.02.2021 MK and LEN(INVOICE_SPLIT_AMOUNT)
CREATE OR ALTER FUNCTION [dbo].[FNCUST_GET-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN] (
@JOB_GUID INT,
@EXPORT_BOOKING_NUMBER BIGINT,
@windreamDocID BIGINT,
@windreamStatus VARCHAR(20), -- Should be: 'erledigt'
@windreamExportDate VARCHAR(8) -- Should be: NULL
)
RETURNS @WINDREAM_2_SCHLEUPEN TABLE ([Satzart] [BIGINT] NULL,
[Belegnummer (X)] [BIGINT] NULL,
[Belegdatum (X)] [DATE] NULL,
[Valutadatum] [DATE] NULL,
[Kontoart (X)] [VARCHAR](20) NULL,
[Kontonummer (X)] [VARCHAR](20) NULL,
[Gegenkontoart (X)] [VARCHAR](20) NULL,
[Gegenkonto] [INT] NULL,
[Zusatzkontoart] [VARCHAR](20) NULL,
[Zusatzkonto] [INT] NULL,
[Betrag] [float] NULL, --Ursp. [VARCHAR](20) NULL
[S/H-Kennzeichen] [VARCHAR](20) NULL,
[Steuerschlüssel] [VARCHAR](20) NULL,
[Buchungstext] [VARCHAR](max) NULL,
[Zahlungsträgerhinweis] [VARCHAR](max) NULL,
[Geschäftsbereich] [VARCHAR](20) NULL,
[externes Rechnungsdatum] [DATE] NULL,
[externe Rechnungsnummer] [VARCHAR](50) NULL,
[Rechnungseinheit] [INT] NULL,
[Fälligkeitsdatum] [DATE] NULL,
[Skontotage 1] [INT] NULL,
[Skonto Prozent 1] [INT] NULL,
[Skontotage 2] [INT] NULL,
[Skonto Prozent 2] [INT] NULL,
[Nettotage] [INT] NULL)
AS
BEGIN
DECLARE @JOB_NAME VARCHAR(50),
@MANDATOR VARCHAR(50),
@EXPORT_TYPE VARCHAR(50),
@windreamVectorID1 INT, -- Vektor ID für Rechnungsaufteilungtabelle (Sachkonto, etc...)
@windreamVectorID2 INT, -- Vektor ID für S/H-Kennzeichen
@windreamVectorSeparator VARCHAR(1), -- Trennzeichen für Daten im Vektorfeld. Default: "~"
@IncomeExpensesFlag VARCHAR(1), -- Variable für S/H Kennzeichen im Kopf
@szValue VARCHAR(max), -- Variable für den gesamten Zeileninhalt aus der Vektortabelle
@INVOICE_SPLIT_TASKNR VARCHAR(max), -- Variable für evtl. Auftragsnummern in der Mitte
@INVOICE_SPLIT_COSTUNIT VARCHAR(max), -- Variable für evtl. Kostenstellen in der Mitte
@INVOICE_SPLIT_AMOUNT VARCHAR(max), -- Variable für den Betrag für die Zeile in der Mitte
@INVOICE_SPLIT_TAXKEY VARCHAR(max), -- Variable für Steuerschlüssel in der Mitte
@INVOICE_SPLIT_IMPERSONAL_ACCOUNT VARCHAR(max), -- Variable für das Sachkonto in der Mitte
@INVOICE_SPLIT_BUSINESS_UNIT VARCHAR(max), -- Variable für den Geschäftsbereich in der Mitte
@INVOICE_SPLIT_INCOMEEXPENSESFLAG VARCHAR(1); -- Variable für S/H Kennzeichen in der Mitte
DECLARE @TB_INVOICE_SPLIT as TABLE ([GUID] [INT] IDENTITY(1,1) NOT NULL,
INVOICE_SPLIT_TASKNR [VARCHAR](max) NULL,
INVOICE_SPLIT_COSTUNIT [VARCHAR](max) NULL,
INVOICE_SPLIT_AMOUNT [VARCHAR](max) NULL,
INVOICE_SPLIT_TAXKEY [VARCHAR](max) NULL,
INVOICE_SPLIT_IMPERSONAL_ACCOUNT [VARCHAR](max) NULL,
INVOICE_SPLIT_BUSINESS_UNIT [VARCHAR](max) NULL,
INVOICE_SPLIT_INCOMEEXPENSESFLAG [VARCHAR](1) NULL)
--===============================================-- Get Job infos --===============================================--
SELECT @JOB_NAME = [JOB_NAME],
@MANDATOR = [MANDANTOR],
@EXPORT_TYPE = [EXPORT_TYPE]
FROM [TBCUST_EXPORT_POSTING_DATA_JOB_CONFIG] (NOLOCK)
WHERE [GUID] = @JOB_GUID
--===============================================-- Get File config infos --===============================================--
SELECT @windreamVectorSeparator = [WD_VECTOR_VALUE_SEPERATOR],
@windreamVectorID1 = [WD_VECTOR_ID1],
@windreamVectorID2 = [WD_VECTOR_ID2]
FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] (NOLOCK)
WHERE [JOB_GUID] = @JOB_GUID
--===============================================-- Get BOOKING_NUMBER --===============================================--
IF (@EXPORT_BOOKING_NUMBER > 1) and (@EXPORT_BOOKING_NUMBER is not null)
SET @EXPORT_BOOKING_NUMBER = convert(VARCHAR(100),@EXPORT_BOOKING_NUMBER);
Else
BEGIN
SET @EXPORT_BOOKING_NUMBER = (SELECT [dwDocID] FROM [windream60].[dbo].[BaseAttributes]
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate)
OR ([dwDate04] = '19700101')
OR ([dwDate04] IS NULL)))
END;
--===============================================-- Get IncomeExpensesFlag for doc; NOT Pos! --===============================================--
SELECT TOP 1 @IncomeExpensesFlag = [szValue] -- S/H Kennzeichen
FROM [windream60].[dbo].[Vector] (NOLOCK)
WHERE szValue IS NOT NULL
and dwDocID = @windreamDocID
and dwAttrID = @windreamVectorID2
-- Failsafe for "S/H Kennzeichen" - Head
IF (@IncomeExpensesFlag NOT in ('H','S'))
SET @IncomeExpensesFlag = 'H';
--===============================================-- Get data for doc HEAD --===============================================--
INSERT INTO @WINDREAM_2_SCHLEUPEN ([Satzart],
[Belegnummer (X)],
[Belegdatum (X)],
[Valutadatum],
[Kontoart (X)],
[Kontonummer (X)],
[Gegenkontoart (X)],
[Gegenkonto],
[Zusatzkontoart],
[Zusatzkonto],
[Betrag],
[S/H-Kennzeichen],
[Steuerschlüssel],
[Buchungstext],
[Zahlungsträgerhinweis],
[Geschäftsbereich],
[externes Rechnungsdatum],
[externe Rechnungsnummer],
[Rechnungseinheit],
[Fälligkeitsdatum],
[Skontotage 1],
[Skonto Prozent 1],
[Skontotage 2],
[Skonto Prozent 2],
[Nettotage])
SELECT 10 as [Satzart],
@EXPORT_BOOKING_NUMBER as [Belegnummer (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate09],8)),104),'dd.MM.yyyy') as [Belegdatum (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate07],8)),104),'dd.MM.yyyy') as [Valutadatum],
'K' as [Kontoart (X)],
REPLACE(REPLACE([szText38],';',''),' ','') as [Kontonummer (X)],
NULL as [Gegenkontoart (X)],
NULL as [Gegenkonto],
NULL as [Zusatzkontoart],
NULL as [Zusatzkonto],
TRY_CONVERT(float,[lfFloat12]) as [Betrag],--TRY_CONVERT(float,[lfFloat12]) TRY_CONVERT(float,[lfFloat12])
@IncomeExpensesFlag as [S/H-Kennzeichen],
'' as [Steuerschlüssel],
REPLACE(REPLACE([szText02],';',''),CHAR(13) + CHAR(10),'') as [Buchungstext],
NULL as [Zahlungsträgerhinweis],
NULL as [Geschäftsbereich],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([decCreationTime],8)),104),'dd.MM.yyyy') as [externes Rechnungsdatum],
REPLACE([szText19],';','') as [externe Rechnungsnummer],
NULL as [Rechnungseinheit],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate06],8)),104),'dd.MM.yyyy') as [Fälligkeitsdatum],
NULL as [Skontotage 1], -- ursp. [dwInteger23]
NULL as [Skonto Prozent 1], -- ursp. [lfFloat09]
NULL as [Skontotage 2],
NULL as [Skonto Prozent 2],
[dwInteger22] as [Nettotage]
FROM [windream60].[dbo].[BaseAttributes] (NOLOCK)
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate)
OR ([dwDate04] = '19700101')
OR ([dwDate04] IS NULL))
--===============================================-- Get data for doc POS --===============================================--
DECLARE CURSOR_INVOICE_SPLIT CURSOR
LOCAL FAST_FORWARD FOR
SELECT [szValue] -- Vektor Tabelle für Rechnungsaufteilung - bis zu 7 Spalten
FROM [windream60].[dbo].[Vector] (NOLOCK)
WHERE szValue IS NOT NULL
and dwDocID = @windreamDocID
and dwAttrID = @windreamVectorID1
OPEN CURSOR_INVOICE_SPLIT
FETCH NEXT FROM CURSOR_INVOICE_SPLIT INTO @szValue
WHILE @@FETCH_STATUS = 0
BEGIN
-- Replace ";" everytime - otherwise if ";" appears, it will corrupt the export file
INSERT INTO @TB_INVOICE_SPLIT (INVOICE_SPLIT_TASKNR,INVOICE_SPLIT_COSTUNIT,INVOICE_SPLIT_AMOUNT,INVOICE_SPLIT_TAXKEY,INVOICE_SPLIT_IMPERSONAL_ACCOUNT,INVOICE_SPLIT_BUSINESS_UNIT,INVOICE_SPLIT_INCOMEEXPENSESFLAG)
VALUES (
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 1),';',''),
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 2),';',''),
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 3),';',''),
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 4),';',''),
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 5),';',''),
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 6),';',''),
REPLACE((SELECT [Item] FROM FNCUST_SPLIT_STRING_WITH_GUID (@szValue, @windreamVectorSeparator) where GUID = 7),';','')
)
FETCH NEXT FROM CURSOR_INVOICE_SPLIT INTO @szValue
END
CLOSE CURSOR_INVOICE_SPLIT
DEALLOCATE CURSOR_INVOICE_SPLIT
---------------------------------------------------------
-- For each order number (auftragsnummern) in windream db
---------------------------------------------------------
DECLARE CURSOR_ORDERNR_AND_AMOUNT CURSOR
LOCAL FAST_FORWARD FOR
-- Get lines where "Auftragsnummer" is set,
-- ignore if costunit ist set
SELECT [INVOICE_SPLIT_TASKNR],
[INVOICE_SPLIT_COSTUNIT],
[INVOICE_SPLIT_AMOUNT],
[INVOICE_SPLIT_TAXKEY],
[INVOICE_SPLIT_IMPERSONAL_ACCOUNT],
[INVOICE_SPLIT_BUSINESS_UNIT],
[INVOICE_SPLIT_INCOMEEXPENSESFLAG]
FROM @TB_INVOICE_SPLIT
where LEN([INVOICE_SPLIT_TASKNR]) > 1
-- and LEN(INVOICE_SPLIT_AMOUNT) > 0 -- Betrag kann auch '' sein
OPEN CURSOR_ORDERNR_AND_AMOUNT
FETCH NEXT FROM CURSOR_ORDERNR_AND_AMOUNT INTO @INVOICE_SPLIT_TASKNR,@INVOICE_SPLIT_COSTUNIT,@INVOICE_SPLIT_AMOUNT,@INVOICE_SPLIT_TAXKEY,@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,@INVOICE_SPLIT_BUSINESS_UNIT,@INVOICE_SPLIT_INCOMEEXPENSESFLAG
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN
-- Failsafe for "S/H Kennzeichen" - Pos
IF (@INVOICE_SPLIT_INCOMEEXPENSESFLAG NOT in ('H','S'))
SET @INVOICE_SPLIT_INCOMEEXPENSESFLAG = 'S';
INSERT INTO @WINDREAM_2_SCHLEUPEN ([Satzart],
[Belegnummer (X)],
[Belegdatum (X)],
[Valutadatum],
[Kontoart (X)],
[Kontonummer (X)],
[Gegenkontoart (X)],
[Gegenkonto],
[Zusatzkontoart],
[Zusatzkonto],
[Betrag],
[S/H-Kennzeichen],
[Steuerschlüssel],
[Buchungstext],
[Zahlungsträgerhinweis],
[Geschäftsbereich],
[externes Rechnungsdatum],
[externe Rechnungsnummer],
[Rechnungseinheit],
[Fälligkeitsdatum],
[Skontotage 1],
[Skonto Prozent 1],
[Skontotage 2],
[Skonto Prozent 2],
[Nettotage])
SELECT 21 as [Satzart],
@EXPORT_BOOKING_NUMBER as [Belegnummer (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate09],8)),104),'dd.MM.yyyy') as [Belegdatum (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate07],8)),104),'dd.MM.yyyy') as [Valutadatum],
'S' as [Kontoart (X)],
REPLACE(@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,' ','') as [Kontonummer (X)],
'K' as [Gegenkontoart (X)],
REPLACE([szText38],';','') as [Gegenkonto],
'AA' as [Zusatzkontoart],
@INVOICE_SPLIT_TASKNR as [Zusatzkonto],
TRY_CONVERT(FLOAT,(Replace(@INVOICE_SPLIT_AMOUNT,',','.'))) * 1.0 as [Betrag],--TRY_CONVERT(FLOAT,@INVOICE_SPLIT_AMOUNT) * 1.0
@INVOICE_SPLIT_INCOMEEXPENSESFLAG as [S/H-Kennzeichen],
@INVOICE_SPLIT_TAXKEY as [Steuerschlüssel],
REPLACE(REPLACE([szText02],';',''),CHAR(13) + CHAR(10),'') as [Buchungstext],
NULL as [Zahlungsträgerhinweis],
REPLACE(@INVOICE_SPLIT_BUSINESS_UNIT,';','') as [Geschäftsbereich],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([decCreationTime],8)),104),'dd.MM.yyyy') as [externes Rechnungsdatum],
REPLACE([szText19],';','') as [externe Rechnungsnummer],
NULL as [Rechnungseinheit],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate06],8)),104),'dd.MM.yyyy') as [Fälligkeitsdatum],
NULL as [Skontotage 1],
NULL as [Skonto Prozent 1],
NULL as [Skontotage 2],
NULL as [Skonto Prozent 2],
NULL as [Nettotage]
FROM [windream60].[dbo].[BaseAttributes]
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate)
OR ([dwDate04] = '19700101')
OR ([dwDate04] IS NULL))
END
FETCH NEXT FROM CURSOR_ORDERNR_AND_AMOUNT INTO @INVOICE_SPLIT_TASKNR,@INVOICE_SPLIT_COSTUNIT,@INVOICE_SPLIT_AMOUNT,@INVOICE_SPLIT_TAXKEY,@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,@INVOICE_SPLIT_BUSINESS_UNIT,@INVOICE_SPLIT_INCOMEEXPENSESFLAG
END
CLOSE CURSOR_ORDERNR_AND_AMOUNT
DEALLOCATE CURSOR_ORDERNR_AND_AMOUNT
----------------------------------------------------
----------------------------------------------------
-- For each cost unit (kostenstellen) in windream db
----------------------------------------------------
DECLARE CURSOR_COSTUNIT_AND_AMOUNT CURSOR
LOCAL FAST_FORWARD FOR
-- Get lines where "Kostenstelle" is set,
-- but only if "Auftragsnummer" is unset,
-- because Auftragsnummer has prio!
SELECT [INVOICE_SPLIT_TASKNR],
[INVOICE_SPLIT_COSTUNIT],
[INVOICE_SPLIT_AMOUNT],
[INVOICE_SPLIT_TAXKEY],
[INVOICE_SPLIT_IMPERSONAL_ACCOUNT],
[INVOICE_SPLIT_BUSINESS_UNIT],
[INVOICE_SPLIT_INCOMEEXPENSESFLAG]
FROM @TB_INVOICE_SPLIT
WHERE LEN(INVOICE_SPLIT_COSTUNIT) > 1
and LEN(INVOICE_SPLIT_COSTUNIT) > 0
and (LEN([INVOICE_SPLIT_TASKNR]) = 0
or [INVOICE_SPLIT_TASKNR] is null)
OPEN CURSOR_COSTUNIT_AND_AMOUNT
FETCH NEXT FROM CURSOR_COSTUNIT_AND_AMOUNT INTO @INVOICE_SPLIT_TASKNR,@INVOICE_SPLIT_COSTUNIT,@INVOICE_SPLIT_AMOUNT,@INVOICE_SPLIT_TAXKEY,@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,@INVOICE_SPLIT_BUSINESS_UNIT,@INVOICE_SPLIT_INCOMEEXPENSESFLAG
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN
-- Failsafe for "S/H Kennzeichen" - Pos
IF (@INVOICE_SPLIT_INCOMEEXPENSESFLAG NOT in ('H','S'))
SET @INVOICE_SPLIT_INCOMEEXPENSESFLAG = 'S';
INSERT INTO @WINDREAM_2_SCHLEUPEN ([Satzart],
[Belegnummer (X)],
[Belegdatum (X)],
[Valutadatum],
[Kontoart (X)],
[Kontonummer (X)],
[Gegenkontoart (X)],
[Gegenkonto],
[Zusatzkontoart],
[Zusatzkonto],
[Betrag],
[S/H-Kennzeichen],
[Steuerschlüssel],
[Buchungstext],
[Zahlungsträgerhinweis],
[Geschäftsbereich],
[externes Rechnungsdatum],
[externe Rechnungsnummer],
[Rechnungseinheit],
[Fälligkeitsdatum],
[Skontotage 1],
[Skonto Prozent 1],
[Skontotage 2],
[Skonto Prozent 2],
[Nettotage])
SELECT 22 as [Satzart],
@EXPORT_BOOKING_NUMBER as [Belegnummer (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate09],8)),104),'dd.MM.yyyy') as [Belegdatum (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate07],8)),104),'dd.MM.yyyy') as [Valutadatum],
'S' as [Kontoart (X)],
REPLACE(@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,' ','') as [Kontonummer (X)],
'K' as [Gegenkontoart (X)],
REPLACE([szText38],';','') as [Gegenkonto],
'KS' as [Zusatzkontoart],
@INVOICE_SPLIT_COSTUNIT as [Zusatzkonto],
TRY_CONVERT(FLOAT,(Replace(@INVOICE_SPLIT_AMOUNT,',','.'))) * 1.0 as [Betrag],--TRY_CONVERT(FLOAT,@INVOICE_SPLIT_AMOUNT) * 1.0
@INVOICE_SPLIT_INCOMEEXPENSESFLAG as [S/H-Kennzeichen],
@INVOICE_SPLIT_TAXKEY as [Steuerschlüssel],
REPLACE(REPLACE([szText02],';',''),CHAR(13) + CHAR(10),'') as [Buchungstext],
NULL as [Zahlungsträgerhinweis],
REPLACE(@INVOICE_SPLIT_BUSINESS_UNIT,';','') as [Geschäftsbereich],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([decCreationTime],8)),104),'dd.MM.yyyy') as [externes Rechnungsdatum],
REPLACE([szText19],';','') as [externe Rechnungsnummer],
NULL as [Rechnungseinheit],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate06],8)),104),'dd.MM.yyyy') as [Fälligkeitsdatum],
NULL as [Skontotage 1],
NULL as [Skonto Prozent 1],
NULL as [Skontotage 2],
NULL as [Skonto Prozent 2],
NULL as [Nettotage]
FROM [windream60].[dbo].[BaseAttributes] (NOLOCK)
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate)
OR ([dwDate04] = '19700101')
OR ([dwDate04] IS NULL))
END
FETCH NEXT FROM CURSOR_COSTUNIT_AND_AMOUNT INTO @INVOICE_SPLIT_TASKNR,@INVOICE_SPLIT_COSTUNIT,@INVOICE_SPLIT_AMOUNT,@INVOICE_SPLIT_TAXKEY,@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,@INVOICE_SPLIT_BUSINESS_UNIT,@INVOICE_SPLIT_INCOMEEXPENSESFLAG
END
CLOSE CURSOR_COSTUNIT_AND_AMOUNT
DEALLOCATE CURSOR_COSTUNIT_AND_AMOUNT
---------------------------------------------------------
----------------------------------------------------
-- For each business unit (Geschäftsbereich) in windream db
----------------------------------------------------
DECLARE CURSOR_COSTUNIT_AND_AMOUNT CURSOR
LOCAL FAST_FORWARD FOR
-- Get lines where "Geschäftsbereich" is set,
-- but only if "Auftragsnummer" and "Kostenstelle" is unset,
-- because Auftragsnummer has prio 1, Kostenstelle has prio 2
SELECT [INVOICE_SPLIT_TASKNR],
[INVOICE_SPLIT_COSTUNIT],
[INVOICE_SPLIT_AMOUNT],
[INVOICE_SPLIT_TAXKEY],
[INVOICE_SPLIT_IMPERSONAL_ACCOUNT],
[INVOICE_SPLIT_BUSINESS_UNIT],
[INVOICE_SPLIT_INCOMEEXPENSESFLAG]
FROM @TB_INVOICE_SPLIT
WHERE (LEN(INVOICE_SPLIT_COSTUNIT) = 0
or [INVOICE_SPLIT_COSTUNIT] is null)
and (LEN([INVOICE_SPLIT_TASKNR]) = 0
or [INVOICE_SPLIT_TASKNR] is null)
OPEN CURSOR_COSTUNIT_AND_AMOUNT
FETCH NEXT FROM CURSOR_COSTUNIT_AND_AMOUNT INTO @INVOICE_SPLIT_TASKNR,@INVOICE_SPLIT_COSTUNIT,@INVOICE_SPLIT_AMOUNT,@INVOICE_SPLIT_TAXKEY,@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,@INVOICE_SPLIT_BUSINESS_UNIT,@INVOICE_SPLIT_INCOMEEXPENSESFLAG
WHILE @@FETCH_STATUS = 0
BEGIN
BEGIN
-- Failsafe for "S/H Kennzeichen" - Pos
IF (@INVOICE_SPLIT_INCOMEEXPENSESFLAG NOT in ('H','S'))
SET @INVOICE_SPLIT_INCOMEEXPENSESFLAG = 'S';
INSERT INTO @WINDREAM_2_SCHLEUPEN ([Satzart],
[Belegnummer (X)],
[Belegdatum (X)],
[Valutadatum],
[Kontoart (X)],
[Kontonummer (X)],
[Gegenkontoart (X)],
[Gegenkonto],
[Zusatzkontoart],
[Zusatzkonto],
[Betrag],
[S/H-Kennzeichen],
[Steuerschlüssel],
[Buchungstext],
[Zahlungsträgerhinweis],
[Geschäftsbereich],
[externes Rechnungsdatum],
[externe Rechnungsnummer],
[Rechnungseinheit],
[Fälligkeitsdatum],
[Skontotage 1],
[Skonto Prozent 1],
[Skontotage 2],
[Skonto Prozent 2],
[Nettotage])
SELECT 23 as [Satzart],
@EXPORT_BOOKING_NUMBER as [Belegnummer (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate09],8)),104),'dd.MM.yyyy') as [Belegdatum (X)],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate07],8)),104),'dd.MM.yyyy') as [Valutadatum],
'S' as [Kontoart (X)],
@INVOICE_SPLIT_IMPERSONAL_ACCOUNT as [Kontonummer (X)],
'K' as [Gegenkontoart (X)],
REPLACE([szText38],';','') as [Gegenkonto],
NULL as [Zusatzkontoart],
NULL as [Zusatzkonto],
TRY_CONVERT(FLOAT,(Replace(@INVOICE_SPLIT_AMOUNT,',','.'))) * 1.0 as [Betrag],--TRY_CONVERT(FLOAT,@INVOICE_SPLIT_AMOUNT) * 1.0
@INVOICE_SPLIT_INCOMEEXPENSESFLAG as [S/H-Kennzeichen],
@INVOICE_SPLIT_TAXKEY as [Steuerschlüssel],
REPLACE([szText02],';','') as [Buchungstext],
NULL as [Zahlungsträgerhinweis],
REPLACE(@INVOICE_SPLIT_BUSINESS_UNIT,';','') as [Geschäftsbereich],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([decCreationTime],8)),104),'dd.MM.yyyy') as [externes Rechnungsdatum],
REPLACE([szText19],';','') as [externe Rechnungsnummer],
NULL as [Rechnungseinheit],
FORMAT(CONVERT(DATE,CONVERT(VARCHAR(8),LEFT([dwDate06],8)),104),'dd.MM.yyyy') as [Fälligkeitsdatum],
NULL as [Skontotage 1],
NULL as [Skonto Prozent 1],
NULL as [Skontotage 2],
NULL as [Skonto Prozent 2],
NULL as [Nettotage]
FROM [windream60].[dbo].[BaseAttributes] (NOLOCK)
WHERE [dwDocID] = @windreamDocID
and [szText33] = @windreamStatus
and (([dwDate04] = @windreamExportDate)
OR ([dwDate04] = '19700101')
OR ([dwDate04] IS NULL))
END
FETCH NEXT FROM CURSOR_COSTUNIT_AND_AMOUNT INTO @INVOICE_SPLIT_TASKNR,@INVOICE_SPLIT_COSTUNIT,@INVOICE_SPLIT_AMOUNT,@INVOICE_SPLIT_TAXKEY,@INVOICE_SPLIT_IMPERSONAL_ACCOUNT,@INVOICE_SPLIT_BUSINESS_UNIT,@INVOICE_SPLIT_INCOMEEXPENSESFLAG
END
CLOSE CURSOR_COSTUNIT_AND_AMOUNT
DEALLOCATE CURSOR_COSTUNIT_AND_AMOUNT
---------------------------------------------------------
RETURN;
END