VHM-DIGITALDATA/SQL-Server/Tabellenwertfunktionen/[FNCUST_GET-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN].sql gelöscht

Dateiname zu lang für lokalen commit
This commit is contained in:
KammM 2024-09-27 19:27:44 +02:00
parent 61dc5c7824
commit 2b259dbeed

View File

@ -1,521 +0,0 @@
USE [DD_ECM]
GO
/****** Object: UserDefinedFunction [dbo].[FNCUST_GET-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN] Script Date: 21.03.2024 16:22:12 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- Stand: MK // 01.09.2021
-- 01.09.2021 Skontotage und Skontoprozent entfernt / auf NULL gesetzt
-- 27.08.2021 Satzart für die Sortierung eingefügt --> Funktion "FNCUST_FORMAT-EXPORT_POSTING_DATA_FROM_WINDREAM_FOR_SCHLEUPEN" ruft dies ab
-- 03.08.2021 [Kontonummer (X)] von int auf varchar umgestellt, da die Nummern auch mit 0 beginnen kann!
-- 11.03.2021 Zeilenumbruch in Buchungstext abgefangen REPLACE(REPLACE([szText02],';',''),CHAR(13) + CHAR(10),'')
-- 10.03.2021 REPLACE(@INVOICE_SPLIT_BUSINESS_UNIT,';','') in die Cursor eingebaut, eigener Cursor für Geschäftsbereich hinzugefügt
-- 25.02.2021 Expliziete Float Konvertierung für "Betrag" eingebaut
-- 17.02.2021 Datumsfelder getauscht
-- 11.02.2021 Fehler im 3. cursor behoben (@INVOICE_SPLIT_COSTUNIT)
-- 11.02.2021 Cursor für neue Rechnungsaufteilungstabelle überarbeitet
-- 11.02.2021 and LEN(INVOICE_SPLIT_AMOUNT)
CREATE 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]
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]
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]
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]
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
FOR
SELECT [szValue] -- Vektor Tabelle für Rechnungsaufteilung - bis zu 7 Spalten
FROM [windream60].[dbo].[Vector]
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
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
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]
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
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]
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
GO