USE [DD_ECM] GO /****** Object: StoredProcedure [dbo].[PRDEX_WRITE_FILE] Script Date: 14.02.2026 17:23:12 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- TSQL Prozedur welche die bereitsgesammelten Daten abruft und in Folge in eine Datei und ins Archiv schreibt. -- MK // 08.10.2024 -- 08.10.2024 MK Implementierung @EXPORT_HEADER -- 04.10.2024 MK Implementierung von SQL TRANSACTION und @BATCH_TIMESTAMP für Massenverarbeitung -- 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; -- GO -- RECONFIGURE WITH OVERRIDE; -- GO -- sp_configure 'Ole Automation Procedures', 1; -- GO -- RECONFIGURE WITH OVERRIDE; -- GO -- EXEC sp_configure 'xp_cmdshell', 1 -- GO -- RECONFIGURE WITH OVERRIDE -- GO CREATE OR ALTER PROCEDURE [dbo].[PRDEX_WRITE_FILE] @JOB_GUID INT, @BATCH_TIMESTAMP VARCHAR(25) AS PRINT '===============================' PRINT 'PROCEDURE - START [PRCUST_EXPORT_POSTING_DATA_WRITE_FILE] @ ' + CONVERT(varchar(50),GETDATE(),120) PRINT 'PARAMETER1 - @JOB_GUID: ' + CONVERT(varchar(50),@JOB_GUID) PRINT 'PARAMETER2 - @BATCH_TIMESTAMP: ' + CONVERT(varchar(50),@BATCH_TIMESTAMP) BEGIN TRY SET XACT_ABORT ON; BEGIN TRANSACTION DECLARE @JOB_NAME VARCHAR(50), @MANDATOR VARCHAR(50), @EXPORT_TYPE VARCHAR(50), @EXPORT_HEADER TINYINT, @EXPORT_BOOKING_NUMBER VARCHAR(100), @EXPORT_BOOKING_NUMBER_ARRAY VARCHAR(MAX), @EXPORT_BOOKING_NUMBER_FIRST_VALUE VARCHAR(50), @EXPORT_BOOKING_NUMBER_LAST_VALUE VARCHAR(50), @OLE_RESULT INT, @FSO INT, @GUID BIGINT, @windreamDocID VARCHAR(MAX), @windreamDocID_ARRAY VARCHAR(MAX), @ERROR VARCHAR(1000), @ERROR_LINE VARCHAR(10), @FILE_ID INT, @FILE_CONTENT NVARCHAR(MAX) = '', @FILE_CONTENT_HEAD NVARCHAR(MAX), @FILE_CONTENT_HEAD_QUERY NVARCHAR(MAX), @FILE_CONTENT_BODY_COUNT INT, @FILE_CONTENT_BODY_LINE NVARCHAR(MAX), @FILE_NAME VARCHAR(50), @FILE_PATH_TEMP VARCHAR(500), @FILE_PATH_EXPORT VARCHAR(500), @FILE_PATH_ARCHIV VARCHAR(500), @FILE_PATH_ERROR VARCHAR(500), @FILE_PATH_AND_NAME VARCHAR(600), @FILE_NAME_SEPARATOR VARCHAR(10) = '-', @FILE_DATA_SEPARATOR VARCHAR(10) = ';', @CMD VARCHAR(1000); -- declare runtime vars DECLARE @MyProcedureName NVARCHAR(128) = OBJECT_NAME(@@PROCID); DECLARE @DBName NVARCHAR(100), @DBNameCount INT, @FULLLOCALBACKUPPATH NVARCHAR(255), @ProductVersion sql_variant, @ProductMainVersion INT, @ProductLevel sql_variant, @ProductEdition sql_variant, @ProductEditionSimpleString NVARCHAR(50), @MySessionID NVARCHAR(50) = @@SPID, @Date_YYYYMMDD NVARCHAR(20) = CONVERT(VARCHAR(20),GETDATE(),112), @sysconfigurations INT = 0, @SQLCommand NVARCHAR(1000) = NULL, @CMDCommand NVARCHAR(1000) = NULL, @CMDCommandResult INT = 0, @return_status NVARCHAR(50) = 0, @return_status_text NVARCHAR(MAX) = 'START ' + @MyProcedureName + ' @ ' + CONVERT(varchar(50),GETDATE(),120); --==========================================-- Checking system configuration --============================================-- PRINT 'Checking system configuration'; SELECT @sysconfigurations = SUM(CAST([value] AS INT)) FROM [master].[sys].[configurations] WHERE [name] in ('show advanced options','Ole Automation Procedures','xp_cmdshell'); If (@sysconfigurations = 3) BEGIN SET @return_status = 0; SET @return_status_text = 'System configuration does fit! (' + CONVERT(varchar,@sysconfigurations) + ')'; PRINT @return_status_text; END; ELSE BEGIN PRINT 'System configuration does NOT fit! Try to reconfigure... (' + CONVERT(varchar,@sysconfigurations) + ')'; EXEC sp_configure 'show advanced options', 1; RECONFIGURE WITH OVERRIDE; EXEC sp_configure 'Ole Automation Procedures', 1; RECONFIGURE WITH OVERRIDE; EXEC sp_configure 'xp_cmdshell', 1; RECONFIGURE WITH OVERRIDE; -- Check again SELECT @sysconfigurations = SUM(CAST(value AS INT)) FROM [master].[sys].[configurations] WHERE [name] in ('show advanced options','Ole Automation Procedures','xp_cmdshell'); If (@sysconfigurations = 3) BEGIN SET @return_status = 0; SET @return_status_text = 'System configuration does fit, now! (' + CONVERT(varchar,@sysconfigurations) + ')'; PRINT @return_status_text; END; ELSE BEGIN SET @return_status = 1; SET @return_status_text = 'System configuration does NOT fit! (' + CONVERT(varchar,@sysconfigurations) + ')'; PRINT @return_status_text; END; END; ----------------------------------------------------------------------------------------------------------------------------- DECLARE @FILE_CONTENT_BODY as TABLE (GUID INT, [EXPORT_BOOKING_NUMBER] VARCHAR(50),FILE_CONTENT_BODY_LINE VARCHAR(max)); DECLARE @FILE_CONTENT_HEAD_Result as TABLE (ResultText VARCHAR(500)); -- 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 Export config SELECT @EXPORT_HEADER = [EXPORT_HEADER] FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] (NOLOCK) WHERE [JOB_GUID] = @JOB_GUID; -- Get export file content INSERT INTO @FILE_CONTENT_BODY ([GUID],[EXPORT_BOOKING_NUMBER],[FILE_CONTENT_BODY_LINE]) SELECT [T1].[GUID], [T1].[EXPORT_BOOKING_NUMBER], [T1].[FILE_CONTENT] FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONTENT] AS [T1], [TBCUST_EXPORT_POSTING_DATA_FILE_CONFIG] AS [T2] WHERE [T1].[BATCH_TIMESTAMP] = @BATCH_TIMESTAMP and [T2].[JOB_GUID] = @JOB_GUID and [T2].[GUID] = [T1].[FILE_CONFIG_GUID] ORDER BY [T1].[EXPORT_BOOKING_NUMBER] ASC; IF (SELECT COUNT(*) FROM [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] (NOLOCK) WHERE [BATCH_TIMESTAMP] = @BATCH_TIMESTAMP) > 1 BEGIN -- Create a temporary table PRINT 'Creating temp table'; CREATE TABLE #TempBookingNumbers (EXPORT_BOOKING_NUMBER NVARCHAR(50), DOCID BIGINT); -- Insert the required data into the temporary table PRINT 'Filling temp table'; INSERT INTO #TempBookingNumbers SELECT [EXPORT_BOOKING_NUMBER], [DOCID] FROM [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] (NOLOCK) WHERE [BATCH_TIMESTAMP] = @BATCH_TIMESTAMP ORDER BY [EXPORT_BOOKING_NUMBER],[DOCID] ASC; -- Get the aggregated values and concat PRINT 'Retriving from temp table'; SELECT @windreamDocID = STRING_AGG([DOCID],', '), @EXPORT_BOOKING_NUMBER_ARRAY = STRING_AGG([EXPORT_BOOKING_NUMBER],', ') FROM #TempBookingNumbers -- Get the first and last values PRINT 'Getting lowest and hights numbers'; SELECT @EXPORT_BOOKING_NUMBER_FIRST_VALUE = MIN([EXPORT_BOOKING_NUMBER]), @EXPORT_BOOKING_NUMBER_LAST_VALUE = MAX([EXPORT_BOOKING_NUMBER]) FROM #TempBookingNumbers; -- Drop the temporary table PRINT 'Dropping temp table'; DROP TABLE #TempBookingNumbers; PRINT '@EXPORT_BOOKING_NUMBER_ARRAY: ' + @EXPORT_BOOKING_NUMBER_ARRAY; PRINT '@EXPORT_BOOKING_NUMBER_FIRST_VALUE: ' + convert(varchar,@EXPORT_BOOKING_NUMBER_FIRST_VALUE); PRINT '@EXPORT_BOOKING_NUMBER_LAST_VALUE: ' + convert(varchar,@EXPORT_BOOKING_NUMBER_LAST_VALUE); SET @EXPORT_BOOKING_NUMBER = @EXPORT_BOOKING_NUMBER_FIRST_VALUE + @FILE_NAME_SEPARATOR + @EXPORT_BOOKING_NUMBER_LAST_VALUE; END; ELSE BEGIN -- get windream DocId SELECT @windreamDocID = [DOCID] FROM [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] (NOLOCK) WHERE [BATCH_TIMESTAMP] = @BATCH_TIMESTAMP; -- get booking number SELECT @EXPORT_BOOKING_NUMBER = [EXPORT_BOOKING_NUMBER] FROM [dbo].[TBCUST_EXPORT_POSTING_DATA_FILE_TEMP] (NOLOCK) WHERE [BATCH_TIMESTAMP] = @BATCH_TIMESTAMP; END; SET @FILE_CONTENT_BODY_COUNT = (SELECT COUNT(*) FROM @FILE_CONTENT_BODY); -- Go on, if there is a contetn to export IF (@FILE_CONTENT_BODY_COUNT > 0) BEGIN PRINT '@FILE_CONTENT_BODY_COUNT (lines in FILE_CONTENT Table): ' + CONVERT(VARCHAR(50),@FILE_CONTENT_BODY_COUNT) -- Textdatei erzeugen -- Create an instance of the file system object EXECUTE @OLE_RESULT = sp_OACreate 'Scripting.FileSystemObject',@FSO OUT -- If Scripting object cannot be created IF (@OLE_RESULT <> 0) BEGIN SET @ERROR = 'Scripting.FileSystemObject ' + ' Error code: ' + CONVERT(VARCHAR(300),@OLE_RESULT) SET @ERROR_LINE = CONVERT(VARCHAR(10),@OLE_RESULT) EXEC [PRCUST_EXPORT_POSTING_DATA_WRITE_JOB_LOG] @JOB_GUID,'File:','Procedure: PRCUST_EXPORT_POSTING_DATA_CREATE_FILE',@ERROR_LINE,@ERROR END -- If Scripting object can be created ELSE BEGIN -- Open the text file for writing SELECT @FILE_NAME_SEPARATOR = RTRIM(LTRIM(CONVERT(VARCHAR(10), [FILE_NAME_SEPARATOR]))), @FILE_DATA_SEPARATOR = RTRIM(LTRIM(CONVERT(VARCHAR(10), [FILE_DATA_SEPARATOR]))), @FILE_PATH_TEMP = RTRIM(LTRIM(CONVERT(VARCHAR(500),[FILE_PATH_TEMP]))), @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] (NOLOCK) WHERE [JOB_GUID] = @JOB_GUID PRINT ' ' PRINT '@FILE_PATH_TEMP: ' + @FILE_PATH_TEMP PRINT '@FILE_PATH_EXPORT: ' + @FILE_PATH_EXPORT PRINT '@FILE_PATH_ARCHIV: ' + @FILE_PATH_ARCHIV PRINT '@FILE_PATH_ERROR: ' + @FILE_PATH_ERROR -- Build Filename @FILE_NAME = EXECUTE [dbo].[PRCUST_EXPORT_POSTING_DATA_BUILD_FILE_NAME] @JOB_GUID = @JOB_GUID, @EXPORT_BOOKING_NUMBER = @EXPORT_BOOKING_NUMBER, @FILE_NAME = @FILE_NAME OUTPUT; PRINT 'Determined @FILE_NAME: ' + @FILE_NAME -- Build Filename and path SET @FILE_PATH_AND_NAME = @FILE_PATH_TEMP + '\' + @FILE_NAME PRINT 'Determined @FILE_PATH_AND_NAME: ' + @FILE_PATH_AND_NAME EXEC @OLE_RESULT = sp_OAMethod @FSO,'OpenTextFile',@FILE_ID OUT, @FILE_PATH_AND_NAME, 2, TRUE, 0 IF @OLE_RESULT <> 0 BEGIN SET @ERROR = 'OpenTextFile ' + ' Error code: ' + CONVERT(VARCHAR(300),@OLE_RESULT) SET @ERROR_LINE = CONVERT(VARCHAR(10),@OLE_RESULT) --EXEC [PRCUST_EXPORT_POSTING_DATA_WRITE_JOB_LOG] 'File:','Procedure: PRCUST_EXPORT_POSTING_DATA_CREATE_FILE',@ERROR_LINE,@ERROR END -- If file could be created, fill the content ELSE BEGIN -- Set File Head PRINT ' ' PRINT '@JOB_NAME: ' + CONVERT(VARCHAR(50),@JOB_NAME) -- Write Headline to Var and file if enabled IF (@EXPORT_HEADER = 0) BEGIN PRINT 'Header from [TBCUST_EXPORT_POSTING_DATA_FILE_TEMPLATE] should NOT be exported' END ELSE BEGIN PRINT 'Header from [TBCUST_EXPORT_POSTING_DATA_FILE_TEMPLATE] should be exported' SET @FILE_CONTENT_HEAD_QUERY = [dbo].[FNCUST_EXPORT_POSTING_DATA_BUILD_FILE_HEAD](@JOB_NAME,1) PRINT '@FILE_CONTENT_HEAD_QUERY (unprocessed): ' + @FILE_CONTENT_HEAD_QUERY INSERT INTO @FILE_CONTENT_HEAD_RESULT EXECUTE sp_executesql @FILE_CONTENT_Head_Query, N'@FILE_DATA_SEPARATOR varchar(1)', @FILE_DATA_SEPARATOR = @FILE_DATA_SEPARATOR; -- Get File Head and replace word wrap / line breaks SET @FILE_CONTENT_HEAD = (SELECT TOP 1 [ResultText] FROM @FILE_CONTENT_HEAD_RESULT) SET @FILE_CONTENT_HEAD = REPLACE(@FILE_CONTENT_HEAD,CHAR(13) + CHAR(10),'') PRINT '@FILE_CONTENT_Head: ' + @FILE_CONTENT_Head SET @FILE_CONTENT = @FILE_CONTENT_Head + @FILE_CONTENT EXECUTE @OLE_RESULT = sp_OAMethod @FILE_ID,'WriteLine',NULL,@FILE_CONTENT END -- prepare cursor to write every content line DECLARE CURSOR_WRITE_FILE_CONTENT CURSOR LOCAL FAST_FORWARD FOR SELECT [FILE_CONTENT_BODY_LINE] FROM @FILE_CONTENT_BODY ORDER BY [EXPORT_BOOKING_NUMBER], [GUID] ASC OPEN CURSOR_WRITE_FILE_CONTENT FETCH NEXT FROM CURSOR_WRITE_FILE_CONTENT INTO @FILE_CONTENT_BODY_LINE WHILE @@FETCH_STATUS = 0 BEGIN -- Write the line into the file PRINT '@FILE_CONTENT_BODY_LINE: ' + @FILE_CONTENT_BODY_LINE EXECUTE @OLE_RESULT = sp_OAMethod @FILE_ID,'WriteLine',NULL,@FILE_CONTENT_BODY_LINE -- Set Var to write into Archiv SET @FILE_CONTENT = @FILE_CONTENT + CHAR(13) + CHAR(10) + @FILE_CONTENT_BODY_LINE FETCH NEXT FROM CURSOR_WRITE_FILE_CONTENT INTO @FILE_CONTENT_BODY_LINE END CLOSE CURSOR_WRITE_FILE_CONTENT DEALLOCATE CURSOR_WRITE_FILE_CONTENT -- Remove filesystemobject EXECUTE @OLE_RESULT = sp_OADestroy @FILE_ID EXECUTE @OLE_RESULT = sp_OADestroy @FSO -- prepare cursor to delete content lines DECLARE CURSOR_DELETE_FILE_CONTENT CURSOR LOCAL FAST_FORWARD FOR SELECT [GUID] FROM @FILE_CONTENT_BODY OPEN CURSOR_DELETE_FILE_CONTENT FETCH NEXT FROM CURSOR_DELETE_FILE_CONTENT INTO @GUID WHILE @@FETCH_STATUS = 0 BEGIN DELETE FROM [TBCUST_EXPORT_POSTING_DATA_FILE_CONTENT] WHERE [GUID] = @GUID FETCH NEXT FROM CURSOR_DELETE_FILE_CONTENT INTO @GUID END CLOSE CURSOR_DELETE_FILE_CONTENT DEALLOCATE CURSOR_DELETE_FILE_CONTENT -- Copy file to archiv folder SET @CMD = 'copy "' + @FILE_PATH_AND_NAME + '" "' + @FILE_PATH_ARCHIV + '"' EXEC master..xp_cmdshell @CMD, no_output -- If copy was successfull, move to output folder SET @CMD = 'move "' + @FILE_PATH_AND_NAME + '" "' + @FILE_PATH_EXPORT + '"' EXEC master..xp_cmdshell @CMD, no_output PRINT 'File: ' + @FILE_PATH_AND_NAME + ' has been created, and moved to: ' + @FILE_PATH_EXPORT -- Archive to DB IF LEN(@EXPORT_BOOKING_NUMBER_ARRAY) > 0 BEGIN EXECUTE [dbo].[PRCUST_EXPORT_POSTING_DATA_WRITE_FILE_ARCHIV] @JOB_GUID, @windreamDocID, @BATCH_TIMESTAMP, @EXPORT_BOOKING_NUMBER_ARRAY, @FILE_NAME, @FILE_CONTENT; END; ELSE BEGIN EXECUTE [dbo].[PRCUST_EXPORT_POSTING_DATA_WRITE_FILE_ARCHIV] @JOB_GUID, @windreamDocID, @BATCH_TIMESTAMP, @EXPORT_BOOKING_NUMBER, @FILE_NAME, @FILE_CONTENT; END; PRINT 'Data now written to archive table' PRINT '' PRINT 'PROCEDURE - END [PRCUST_EXPORT_POSTING_DATA_WRITE_FILE] @ ' + CONVERT(varchar(50),GETDATE(),120) PRINT '===============================' COMMIT TRANSACTION END END END ELSE BEGIN 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 true/wahr, ' PRINT ' have to be false/falsch!' PRINT '' PRINT 'PROCEDURE - END [PRCUST_EXPORT_POSTING_DATA_WRITE_FILE] @ ' + CONVERT(varchar(50),GETDATE(),120) PRINT '===============================' END END TRY BEGIN CATCH 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 ROLLBACK TRANSACTION RETURN 1; END CATCH GO