8
0
Files
Skriptentwickung/archive/Packtisch Modul/Packtisch 4.1.0.0/UPDATE_ARTICLE_PSEUDO_SERIALNUMBER.sql
2024-01-24 16:42:38 +01:00

167 lines
5.0 KiB
Transact-SQL

USE [CWLDATEN_MEDP]
GO
/****** Object: StoredProcedure [dbo].[UPDATE_ARTICLE_PSEUDO_SERIALNUMBER] Script Date: 14.06.2023 09:05:23 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- UPDATE_ARTICLE_PSEUDO_SERIALNUMBER
-- =================================================================
-- Ersetzt die Pseudo-Seriennummer durch die konkrete Seriennummer
-- Betroffen sind neben der Artikeltabelle (t024) folgende Tabellen
-- - Artikelmatch (t027)
-- - Statistik (t039)
-- - Lagerbuchungsjournal (t083)
--
-- Returns: BOOLEAN
-- =================================================================
-- Copyright (c) 2023 by Digital Data GmbH
--
-- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim
-- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works
-- =================================================================
-- Creation Date / Author: 31.05.2023 / JJ / MP
-- Version Date / Editor: 01.06.2023 / JJ / MP
-- Version Number: 4.0.0.0
-- =================================================================
-- History:
-- 14.06.2023 / JJ / MP - Seriennummern in t027, t039, t083 updaten
-- 31.05.2023 / JJ / MP - Erste Version
CREATE OR ALTER PROCEDURE [dbo].[UPDATE_ARTICLE_PSEUDO_SERIALNUMBER]
-- Add the parameters for the stored procedure here
@AUFTRAGSNR NVARCHAR(100),
@COMPUTERNAME NVARCHAR(100),
@STATUS NVARCHAR(20),
@MESOCOMP NVARCHAR(4),
@MESOYEAR NVARCHAR(4)
AS
BEGIN
BEGIN TRY
BEGIN TRANSACTION
DECLARE @ARTIKELNR NVARCHAR(30)
DECLARE @PSEUDOSN NVARCHAR(255)
DECLARE @REALSN NVARCHAR(255)
DECLARE @TEMPSN NVARCHAR(255)
--PRINT 'END DECLARE'
DECLARE tableCursor CURSOR FOR
SELECT [ArtikelNr], [PseudoSN], [RealSN]
FROM TBDD_PACKTISCH_HISTORY
WHERE
AuftragsNr = @AUFTRAGSNR AND
Rechnername = @COMPUTERNAME AND
mesocomp = @MESOCOMP AND
mesoyear = @MESOYEAR AND
RealSN IS NOT NULL AND
[Status] = @STATUS
--PRINT 'END DECLARE CURSOR'
OPEN tableCursor
FETCH next FROM tableCursor INTO @ARTIKELNR, @PSEUDOSN, @REALSN
--PRINT 'END OPEN CURSOR'
WHILE @@fetch_status=0
BEGIN
IF @STATUS = 'Replaced'
BEGIN
SET @TEMPSN = @PSEUDOSN
SET @PSEUDOSN = @REALSN
SET @REALSN = @TEMPSN
END
--PRINT 'PSEUDOSN' + @PSEUDOSN
--PRINT 'REALSN' + @REALSN
IF EXISTS(SELECT 1 FROM T024 WHERE c011 = @ARTIKELNR AND C068 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR)
BEGIN
--PRINT 'UPDATE t024'
UPDATE T024 SET C068 = @REALSN WHERE c011 = @ARTIKELNR AND C068 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR
--PRINT 'END UPDATE t024'
END
IF EXISTS(SELECT 1 FROM T027 WHERE c011 = @ARTIKELNR AND C068 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR)
BEGIN
--PRINT 'UPDATE t027'
UPDATE T027 SET C068 = @REALSN, C200 = @REALSN WHERE c011 = @ARTIKELNR AND C068 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR
--PRINT 'END UPDATE t027'
END
IF EXISTS(SELECT 1 FROM T039 WHERE c048 = @ARTIKELNR AND C019 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR)
BEGIN
--PRINT 'UPDATE t039'
UPDATE T039 SET C019 = @REALSN WHERE c048 = @ARTIKELNR AND C019 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR
--PRINT 'END UPDATE t039'
END
IF EXISTS(SELECT 1 FROM T083 WHERE c036 = @ARTIKELNR AND C018 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR)
BEGIN
--PRINT 'UPDATE t083'
UPDATE T083 SET C018 = @REALSN WHERE c036 = @ARTIKELNR AND C018 = @PSEUDOSN AND MESOCOMP = @MESOCOMP AND MESOYEAR = @MESOYEAR
--PRINT 'END UPDATE t083'
END
-- move to next record
FETCH next FROM tableCursor INTO @ARTIKELNR, @PSEUDOSN, @REALSN
END
CLOSE tableCursor
DEALLOCATE tableCursor
IF @STATUS = 'Scanned'
BEGIN
--PRINT 'UPDATE TBDD_PACKTISCH_HISTORY'
UPDATE TBDD_PACKTISCH_HISTORY
SET [Status] = 'Replaced', [GeaendertWann] = GETDATE()
WHERE
AuftragsNr = @AUFTRAGSNR AND
Rechnername = @COMPUTERNAME AND
[Status] = 'Scanned' AND
mesocomp = @MESOCOMP AND
mesoyear = @MESOYEAR
--PRINT 'END UPDATE TBDD_PACKTISCH_HISTORY'
END
ELSE
BEGIN
--PRINT 'UPDATE TBDD_PACKTISCH_HISTORY'
UPDATE TBDD_PACKTISCH_HISTORY
SET [Status] = 'Scanned', [GeaendertWann] = GETDATE()
WHERE
AuftragsNr = @AUFTRAGSNR AND
Rechnername = @COMPUTERNAME AND
[Status] = 'Replaced' AND
mesocomp = @MESOCOMP AND
mesoyear = @MESOYEAR
--PRINT 'END UPDATE TBDD_PACKTISCH_HISTORY'
END
COMMIT TRANSACTION
END TRY
BEGIN CATCH
CLOSE tableCursor
DEALLOCATE tableCursor
ROLLBACK TRANSACTION
--PRINT 'UPDATE TBDD_PACKTISCH_HISTORY ERROR'
UPDATE TBDD_PACKTISCH_HISTORY
SET [Status] = 'Error', [GeaendertWann] = GETDATE()
WHERE
AuftragsNr = @AUFTRAGSNR AND
Rechnername = @COMPUTERNAME AND
[Status] = @STATUS AND
mesocomp = @MESOCOMP AND
mesoyear = @MESOYEAR
--PRINT 'END UPDATE TBDD_PACKTISCH_HISTORY ERROR'
END CATCH
END
GO