Example to Transform SAP Data into Eventlog in Snowflake: Difference between revisions

From QPR ProcessAnalyzer Wiki
Jump to navigation Jump to search
m (Ollvihe moved page Transform SAP in Snowflake to Transform SAP Data into Eventlogs in Snowflake without leaving a redirect)
(No difference)

Revision as of 23:28, 18 May 2023

Create case attributes

Following script creates case attributes. When it is run it (re)creates snowflake table created in ProcessAnalyzer for CaseAttributes. This way if model is changes the CaseAttribute table structure does not to be changed all the time.


Amount in local currency (and Cost) attributes are calculated by summing up table BSAK entries with SHKZG ='S' (Debit entry). Table BSAK contains Cleared Accounting entries for Vendor items. Currency conversions are made with hardcoded value (currency rates for 2023/03 taken from somewhere). They should be taken on day/month basis using existing Snowflake datasets for which we should link to.

// Set BSAK DATA as oneliner
create or replace temporary view BSAK_TEMP 
as 
SELECT BUKRS,BELNR,GJAHR,WAERS,min(ZLSCH) ZLSCH,min(ZTERM) ZTERM,min(LIFNR)LIFNR, count( * ) "My_COUNT"
, SUM (case when SHKZG ='S' then WRBTR else 0 end) "SSUM"
, SUM (case when SHKZG ='H' then WRBTR else 0 end) "HSUM"
, sum(WRBTR) "mySUM2"
FROM BSAK_PROD
--where SHKZG = 'S'
group by BUKRS,BELNR,GJAHR,WAERS;

CREATE OR replace TEMPORARY TABLE TEMP_CURRENCIES (CURR_CODE String, CURR_RATE Float);

INSERT INTO TEMP_CURRENCIES (CURR_CODE,CURR_RATE) VALUES
('ZMW',	21.1079),
('UAH',	39.06615),
('TZS',	2475.255),
('NOK',	10.98025),
('NIO',	38.655),
('LAK',	17903.27),
('KZT',	470.985),
('KYD',	0.87795),
('KWD',	0.32475),
('KRW',	1399.93),
('KPW',	137.49),
('KMF',	491.96775),
('KHR',	4288.5),
('KGS',	92.505),
('KES',	134.29),
('JPY',	144.095),
('GEL',	2.75295),
('GBP',	0.8799);

DROP TABLE IF EXISTS "qprpa_dt_d2856b537a5749f89aa796544569ee9f_299";
CREATE OR REPLACE TABLE "qprpa_dt_d2856b537a5749f89aa796544569ee9f_299"
AS
// CASE ATTRIBUTE SELECTION IN HERE
 SELECT    DISTINCT BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
           SUBSTRING(BKPF.BUDAT,1,4) || '/' || SUBSTRING(BKPF.BUDAT,5,2) as "Creation Month",
           BKPF.BUKRS || ' - ' || COALESCE(T001.BUTXT, '*') as "Company Code",
            //BKPF.USNAM as "Created By",
           BSAK.ZTERM || ' - ' || COALESCE(T052U.TEXT1, '*') as "Payment Terms",
           BSAK.LIFNR || ' - ' || COALESCE(LFA1.NAME1, '*') as "Vendor",
           BSAK.ZLSCH as "Payment Method",
           LFA1.KTOKK || ' - ' || coalesce(T077Y.TXT30,'*') as "Vendor: Group",
           LFA1.LAND1 || ' - ' || coalesce(T005T.LANDX,'*') as "Vendor: Country",
           BKPF.BLART || ' - ' || T003T.LTEXT as "Document Type",
           BSAK.WAERS as "Currency",
           BSAK.SSUM :: Float as "Amount in doc currency",
           IFNULL(BSAK.SSUM :: Float / CURR.CURR_RATE :: Float, 0)  as "Cost",
           CURR.CURR_RATE as "Currency Rate",
           EKPO.EBELN as "PO Number",
           CASE WHEN EKPO.EBELN IS NOT NULL THEN 'PO'
                WHEN BKPF.BLART = 'K3' THEN 'IFS/K3'
                ELSE 'No PO' END as "Invoice Type",
           EKKO.BSART || ' - ' || COALESCE(T161T.BATXT, '*') as "PO Type"    
                
FROM BKPF_PROD as BKPF
join BSAK_TEMP as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
left outer join T052U_PROD as T052U 
on BSAK.ZTERM = T052U.ZTERM and T052U.SPRAS = 'EN'
left outer join LFA1_PROD as LFA1 
on BSAK.LIFNR = LFA1.LIFNR
left outer join T005T_PROD as T005T 
on LFA1.LAND1 = T005T.LAND1
left outer join T077Y_PROD as T077Y
on LFA1.KTOKK = T077Y.KTOKK
left outer join T001_PROD as T001
on BKPF.BUKRS = T001.BUKRS //and T001.SPRAS = 'EN'
left outer join T003T_PROD as T003T 
on BKPF.BLART = T003T.BLART
left outer join TEMP_CURRENCIES CURR
on TRIM(BSAK.WAERS) = TRIM(CURR.CURR_CODE)
-- link to PO
left outer join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
left outer join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
left outer join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
left outer join EKKO_PROD EKKO
on EKPO.EBELN = EKKO.EBELN
left outer join T161T_PROD T161T
on EKKO.BSART = T161T.BSART and EKKO.BSTYP = T161T.BSTYP

WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3');

DROP VIEW IF EXISTS BSAK_TEMP;
DROP TABLE IF EXISTS TEMP_CURRENCIES;

Create events

Following script creates the eventlog, i.e., the events datatable contents. When it is run it (re)creates snowflake table created in ProcessAnalyzer for Events. This way if model is changes the Events table structure does not to be changed all the time.

Events are limited to CompanyCode and document type level with where clause for BKPF.BUKRS and BKPF.BLART. All the events are getting their CaseId from table BKPF, so all the events are restricted to the wanted companies and document.

DROP TABLE IF EXISTS "qprpa_dt_d2856b537a5749f89aa796544569ee9f_300";

CREATE OR REPLACE TABLE "qprpa_dt_d2856b537a5749f89aa796544569ee9f_300" //Events Table
AS

-----------------------------
--AP Document Created
-----------------------------
select DISTINCT BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'AP Document Created' as ProcessStep,
TO_TIMESTAMP(BKPF.CPUDT || ' ' || BKPF.CPUTM,'YYYYMMDD HH24MISS') as TimeStamp,
BKPF.USNAM as User,
CASE WHEN BKPF.USNAM like '%ROBOT%' THEN 'Robotic' WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation
FROM BKPF_PROD as BKPF 
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
left outer join T003T_PROD as T003T 
on T003T.BLART = BKPF.BLART
left outer join USR02_PROD as USR02 
on USR02.BNAME = BKPF.USNAM
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL

-----------------------------
--PO Created
-----------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'PO Created' as ProcessStep,
CASE WHEN CH2.UDATE IS NOT NULL THEN TO_TIMESTAMP(CH2.UDATE || ' ' || CH2.UTIME,'YYYYMMDD HH24MISS') ELSE TO_TIMESTAMP(CH1.UDATE || ' ' || CH1.UTIME,'YYYYMMDD HH24MISS') END as TimeStamp,
CASE WHEN CH2.UDATE IS NOT NULL THEN CH2.USERNAME ELSE EKKO.ERNAM END as User,
CASE WHEN CH2.UDATE IS NOT NULL THEN
  CASE WHEN CH2.USERNAME like '%ROBOT%' THEN 'Robotic' WHEN U2.USTYP = 'A' THEN 'Manual' 
  ELSE 'Automatic' END
ELSE 	
  CASE WHEN EKKO.ERNAM like '%ROBOT%' THEN 'Robotic'  WHEN U1.USTYP = 'A' THEN 'Manual' 
  ELSE 'Automatic' END
END as Automation

FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO 
on EKKO.EBELN = EKPO.EBELN
join CDPOS_EINKBELEG_PROD as  CP1
on TRIM(CP1.OBJECTID) = EKKO.EBELN and trim(CP1.TABNAME) = 'EKKO' and trim(CP1.FNAME) = 'KEY'
join CDHDR_EINKBELEG_PROD as  CH1
on trim(CH1.OBJECTID) = trim(CP1.OBJECTID) and trim(CH1.CHANGENR) = trim(CP1.CHANGENR)
left outer join CDPOS_EINKBELEG_PROD as  CP2
on EKPO.EBELN || EKPO.EBELP = SUBSTR(CP2.tabkey, 4, 15) and CP2.TABNAME = 'EKPO' and CP2.FNAME = 'KEY'
left outer join CDHDR_EINKBELEG_PROD as  CH2
on CH2.OBJECTID = CP2.OBJECTID and CH2.CHANGENR = CP2.CHANGENR
left outer join T161T_PROD as T161T 
on T161T.BSART = EKKO.BSART and T161T.BSTYP = EKKO.BSTYP
left outer join USR02_PROD as  U1
on U1.BNAME = EKKO.ERNAM
left outer join USR02_PROD as  U2
on U2.BNAME = CH2.USERNAME
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL

---------------------------------------------
--PR Created
---------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'PR Created' as ProcessStep,
TO_TIMESTAMP(EBAN.BADAT,'YYYYMMDD') as TimeStamp,
EBAN.ERNAM as User,
CASE WHEN EBAN.ERNAM like '%ROBOT%' THEN 'Robotic' WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO 
on EKKO.EBELN = EKPO.EBELN
join EBAN_PROD as EBAN
on EKPO.BANFN = EBAN.BANFN and EKPO.BNFPO = EBAN.BNFPO 
left outer join USR02_PROD as USR02
on USR02.BNAME = EBAN.ERNAM
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

---------------------------------------------
--PO History
---------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
case when EKBE.VGABE = '1' and EKBE.SHKZG = 'H' THEN 'Goods Receipt Reversal'
  when EKBE.VGABE = '1' and EKBE.SHKZG = 'S' THEN 'Goods Receipt'		
  when EKBE.VGABE = '2' then 'Invoice Receipt'
  when EKBE.VGABE = '3' then 'Subseq. Debit/Credit'
  when EKBE.VGABE = '4' then 'Down Payment'
  when EKBE.VGABE = '5' then 'Payment'
  when EKBE.VGABE = '6' then 'Goods Issue for Stock Transfer'
  when EKBE.VGABE = '7' then 'Consumption (Subcontracting)'
  when EKBE.VGABE = '8' then 'Delivery (Stock Transfer)'
  when EKBE.VGABE = '9' then 'Service Entry Sheet'
  when EKBE.VGABE = 'A' then 'Down Payment Request'
  when EKBE.VGABE = 'C' then 'Down Payment Clearing'
  when EKBE.VGABE = 'Q' then 'Comparison for Internally Posted Material'
  when EKBE.VGABE = 'R' then 'Return Delivery via Delivery Note'
  when EKBE.VGABE = 'P' then 'Invoice Parking'
  when EKBE.VGABE = 'V' then 'Down Payment Request Clearing'
  when EKBE.VGABE = 'M' then 'Posted Subsequent Debit with Reference to a Contract'
  when EKBE.VGABE = 'K' then 'Posted Invoice with Reference to a Contract'
  when EKBE.VGABE = 'L' then 'Parked Invoice with Reference to a Contract'
  when EKBE.VGABE = 'N' then 'Posted Subsequent Debit for Contract in Blanket PO'
  when EKBE.VGABE = 'O' then 'Posted Invoice for Contract in Blanket Purchase Order'
  when EKBE.VGABE = 'G' then 'Parked Invoice for Contract in Blanket Purchase Order'
END as ProcessStep,
TO_TIMESTAMP(EKBE.CPUDT || ' ' || EKBE.CPUTM,'YYYYMMDD HH24MISS') as TimeStamp,
EKBE.ERNAM as User,
CASE WHEN EKBE.ERNAM like '%ROBOT%' THEN 'Robotic' WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO 
on EKKO.EBELN = EKPO.EBELN
join EKBE_PROD as EKBE
on EKPO.EBELN = EKBE.EBELN and EKPO.EBELP = EKBE.EBELP 
left outer join USR02_PROD as USR02
on USR02.BNAME = EKBE.ERNAM
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

---------------------------------------------
--Vendor Confirmation
---------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'Vendor Confirmation: ' ||  T163F.EBTXT as ProcessStep,
TO_TIMESTAMP(EKES.ERDAT || ' ' || EKES.EZEIT,'YYYYMMDD HH24MISS') as TimeStamp,
'N/A' as User,
CASE WHEN EKES.ESTKZ = '1' THEN 'Manual'  WHEN EKES.ESTKZ = '3' THEN 'Automatic' ELSE 'N/A' END 
as Automation // 2= shipping notification 4= return deliveryhttps://www.sapdatasheet.org/abap/doma/bbest.html
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO 
on EKKO.EBELN = EKPO.EBELN
join EKES_PROD as EKES
on EKPO.EBELN = EKES.EBELN and EKPO.EBELP = EKES.EBELP 
join T163F_PROD as T163F            
on EKES.EBTYP = T163F.EBTYP
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

---------------------------------------------
--Invoice Clearing
---------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'Invoice Clearing' as ProcessStep,
TO_TIMESTAMP(BSAK.AUGDT || ' 235957','YYYYMMDD HH24MISS') as TimeStamp,
COALESCE(BKPF_CLE.USNAM,'N/A') as User,
CASE WHEN BKPF_CLE.USNAM like '%ROBOT%' THEN 'Robotic' WHEN  USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
left outer join BKPF_PROD as  BKPF_CLE
on BKPF_CLE.BELNR = BSAK.AUGBL and BKPF_CLE.GJAHR = BSAK.GJAHR and BKPF_CLE.BUKRS = BSAK.BUKRS
left outer join USR02_PROD as USR02
on USR02.BNAME = BKPF_CLE.USNAM
where BKPF_CLE.BUDAT > 20190000
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL

------------------------------------------------------
--Invoice Due Date
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'Invoice Due Date' as ProcessStep,
CASE WHEN BSAK.ZBD1P = 0 THEN DATEADD(d,TO_NUMBER(BSAK.ZBD1T),TO_TIMESTAMP(BSAK.ZFBDT || ' 235959','YYYYMMDD HH24MISS'))
ELSE CASE WHEN BSAK.ZBD2P = 0 THEN DATEADD(d,TO_NUMBER(BSAK.ZBD2T),TO_TIMESTAMP(BSAK.ZFBDT || ' 235959','YYYYMMDD         HH24MISS'))
ELSE DATEADD(d,TO_NUMBER(BSAK.ZBD3T),TO_TIMESTAMP(BSAK.ZFBDT || ' 235959','YYYYMMDD HH24MISS'))
END END as "TimeStamp", 
'N/A' as User,
'N/A' as Automation
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
where BSAK.ZFBDT < 20300001
and BSAK.ZFBDT > 20200101
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL  

------------------------------------------------------
--Invoice Document Date
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
'Invoice Document Date' as ProcessStep,
DATEADD(second,1,TO_TIMESTAMP(BKPF.BLDAT,'YYYYMMDD')) as TimeStamp, 
'N/A' as User,
'N/A' as Automation
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
where BKPF.BLDAT < 20300001
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 
------------------------------------------------------
--Invoice Posting Date
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
	    'Invoice Posting Date' as ProcessStep,
        DATEADD(second,1,TO_TIMESTAMP(BKPF.BUDAT,'YYYYMMDD')) as TimeStamp, 
    	'N/A' as User,
	    'N/A' as Automation
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
where BKPF.BUDAT < 20300001
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

------------------------------------------------------
--PO Item Changes
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
        'PO Changed: ' || COALESCE(DD04T.SCRTEXT_L,REPLACE(CDPOS_EINKBELEG.FNAME,' ','')) as ProcessStep,
        TO_TIMESTAMP(CDHDR_EINKBELEG.UDATE || ' ' || CDHDR_EINKBELEG.UTIME,'YYYYMMDD HH24MISS') as TimeStamp,
        CDHDR_EINKBELEG.USERNAME as User,
        CASE WHEN CDHDR_EINKBELEG.USERNAME like '%ROBOT%' THEN 'Robotic'  WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO
on EKKO.EBELN = EKPO.EBELN
join CDPOS_EINKBELEG_PROD as CDPOS_EINKBELEG 
on EKPO.EBELN || EKPO.EBELP = SUBSTR(CDPOS_EINKBELEG.tabkey, 4, 15) and trim(CDPOS_EINKBELEG.TABNAME) = 'EKPO' and trim(CDPOS_EINKBELEG.CHNGIND) = 'U'
join CDHDR_EINKBELEG_PROD as CDHDR_EINKBELEG
on CDHDR_EINKBELEG.OBJECTID = CDPOS_EINKBELEG.OBJECTID and CDHDR_EINKBELEG.CHANGENR = CDPOS_EINKBELEG.CHANGENR
left outer join DD04T_PROD as DD04T
on DD04T.ROLLNAME = CDPOS_EINKBELEG.FNAME
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_EINKBELEG.USERNAME
where trim(CDPOS_EINKBELEG.FNAME) NOT IN ('STAPO','AEDAT','LOEKZ','PROCSTAT') 
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

------------------------------------------------------
--PO Approval
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
		'PO ' ||  CASE when CDPOS_EINKBELEG.VALUE_NEW LIKE '%X%' then 'Approved' else 'Approval Revoked' end as ProcessStep,
        DATEADD(ms,200,TO_TIMESTAMP(CDHDR_EINKBELEG.UDATE || ' ' || CDHDR_EINKBELEG.UTIME,'YYYYMMDD HH24MISS')) as TimeStamp,
        CDHDR_EINKBELEG.USERNAME as User,
        CASE WHEN CDHDR_EINKBELEG.USERNAME like '%ROBOT%' THEN 'Robotic'  WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO 
on EKKO.EBELN = EKPO.EBELN
join CDPOS_EINKBELEG_PROD as CDPOS_EINKBELEG
on TRIM(CDPOS_EINKBELEG.OBJECTID) = EKKO.EBELN and trim(CDPOS_EINKBELEG.TABNAME) = 'EKKO' and trim(CDPOS_EINKBELEG.CHNGIND) = 'U' and trim(CDPOS_EINKBELEG.FNAME) = 'FRGZU'
join CDHDR_EINKBELEG_PROD as CDHDR_EINKBELEG 
on CDHDR_EINKBELEG.OBJECTID = CDPOS_EINKBELEG.OBJECTID and CDHDR_EINKBELEG.CHANGENR = CDPOS_EINKBELEG.CHANGENR
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_EINKBELEG.USERNAME
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

------------------------------------------------------
--PO Deletion indicator
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
        CASE WHEN TRIM(CDPOS_EINKBELEG.VALUE_NEW) = 'L' then 'PO Deletion Indicator: Activated' 
        WHEN TRIM(CDPOS_EINKBELEG.VALUE_NEW) = 'S' then 'PO Block Indicator: Activated' 
        else 'PO Deletion Indicator: Deactivated' end as ProcessStep,
        TO_TIMESTAMP(CDHDR_EINKBELEG.UDATE || ' ' || CDHDR_EINKBELEG.UTIME,'YYYYMMDD HH24MISS') as TimeStamp,
        CDHDR_EINKBELEG.USERNAME as User,
    CASE WHEN CDHDR_EINKBELEG.USERNAME like '%ROBOT%' THEN 'Robotic'  WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK            
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO
on EKKO.EBELN = EKPO.EBELN
join CDPOS_EINKBELEG_PROD as CDPOS_EINKBELEG 
on EKPO.EBELN || EKPO.EBELP = SUBSTR(CDPOS_EINKBELEG.tabkey, 4, 15) and trim(CDPOS_EINKBELEG.FNAME) = 'LOEKZ' and trim(CDPOS_EINKBELEG.CHNGIND) = 'U'
join CDHDR_EINKBELEG_PROD as CDHDR_EINKBELEG 
on CDHDR_EINKBELEG.OBJECTID = CDPOS_EINKBELEG.OBJECTID and CDHDR_EINKBELEG.CHANGENR = CDPOS_EINKBELEG.CHANGENR
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_EINKBELEG.USERNAME
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

------------------------------------------------------
--PR Approval
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
        CASE WHEN TRIM(CDPOS_BANF.VALUE_NEW) != '' then 'PR Approved' else 'PR Approval Revoked' END as ProcessStep,
        TO_TIMESTAMP(CDHDR_BANF.UDATE || ' ' || CDHDR_BANF.UTIME,'YYYYMMDD HH24MISS') as TimeStamp,
        CDHDR_BANF.USERNAME as User,
        CASE WHEN CDHDR_BANF.USERNAME like '%ROBOT%' THEN 'Robotic' WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join EKPO_PROD as EKPO
on RSEG.EBELN = EKPO.EBELN and RSEG.EBELP = EKPO.EBELP
join EKKO_PROD as EKKO 
on EKKO.EBELN = EKPO.EBELN
join EBAN_PROD as EBAN
on EKPO.BANFN = EBAN.BANFN and EKPO.BNFPO = EBAN.BNFPO 
join CDPOS_BANF_PROD as CDPOS_BANF
on EBAN.BANFN || EBAN.BNFPO = SUBSTR(CDPOS_BANF.tabkey, 4, 15) and trim(CDPOS_BANF.FNAME) = 'FRGDT' and trim(CDPOS_BANF.CHNGIND) = 'U'
join CDHDR_BANF_PROD as CDHDR_BANF
on CDHDR_BANF.OBJECTID = CDPOS_BANF.OBJECTID and CDHDR_BANF.CHANGENR = CDPOS_BANF.CHANGENR
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_BANF.USERNAME
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

------------------------------------------------------
--Invoice Blocks
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
	CASE WHEN CDPOS_INCOMINGINVOICE.TABNAME = 'RBKP_BLOCKED' THEN 'Invoice Released' ELSE 'Invoice Block:' || CASE WHEN CDPOS_INCOMINGINVOICE.VALUE_NEW = '' THEN ' Deactivated' ELSE ' Activated' END END as ProcessStep,
    TO_TIMESTAMP(CDHDR_INCOMINGINVOICE.UDATE || ' ' || CDHDR_INCOMINGINVOICE.UTIME,'YYYYMMDD HH24MISS') as TimeStamp,
    CDHDR_INCOMINGINVOICE.USERNAME as User,
    CASE WHEN CDHDR_INCOMINGINVOICE.USERNAME like '%ROBOT%' THEN 'Robotic'  WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join CDHDR_INCOMINGINVOICE_PROD as CDHDR_INCOMINGINVOICE 
on RBKP.BELNR || RBKP.GJAHR = CDHDR_INCOMINGINVOICE.OBJECTID
join CDPOS_INCOMINGINVOICE_PROD as CDPOS_INCOMINGINVOICE
on CDHDR_INCOMINGINVOICE.OBJECTID = CDPOS_INCOMINGINVOICE.OBJECTID and CDHDR_INCOMINGINVOICE.CHANGENR = CDPOS_INCOMINGINVOICE.CHANGENR
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_INCOMINGINVOICE.USERNAME
left outer join DD04T_PROD as DD04T
on DD04T.ROLLNAME = CDPOS_INCOMINGINVOICE.FNAME
where CDPOS_INCOMINGINVOICE.TABNAME in ('RSEG','RBKP_BLOCKED') and (CDPOS_INCOMINGINVOICE.FNAME LIKE 'SPGR%' or CDPOS_INCOMINGINVOICE.FNAME = 'KEY')
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL

------------------------------------------------------
--Invoice Changes
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
	'Invoice Changed: ' || COALESCE(DD04T.SCRTEXT_L, REPLACE(CDPOS_INCOMINGINVOICE.FNAME,' ','')) as ProcessStep,
    TO_TIMESTAMP(CDHDR_INCOMINGINVOICE.UDATE || ' ' || CDHDR_INCOMINGINVOICE.UTIME,'YYYYMMDD HH24MISS') as TimeStamp,
    CDHDR_INCOMINGINVOICE.USERNAME as User,
    CASE WHEN CDHDR_INCOMINGINVOICE.USERNAME like '%ROBOT%' THEN 'Robotic'  WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF    
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join RBKP_PROD as RBKP
on TRIM(BKPF.AWKEY) = RBKP.BELNR || RBKP.GJAHR and BKPF.BUKRS = RBKP.BUKRS
join RSEG_PROD as RSEG                        
on RBKP.BELNR = RSEG.BELNR and RBKP.GJAHR = RSEG.GJAHR and RBKP.BUKRS = RSEG.BUKRS
join CDHDR_INCOMINGINVOICE_PROD as CDHDR_INCOMINGINVOICE 
on RBKP.BELNR || RBKP.GJAHR = CDHDR_INCOMINGINVOICE.OBJECTID
join CDPOS_INCOMINGINVOICE_PROD as CDPOS_INCOMINGINVOICE 
on CDHDR_INCOMINGINVOICE.OBJECTID = CDPOS_INCOMINGINVOICE.OBJECTID and CDHDR_INCOMINGINVOICE.CHANGENR = CDPOS_INCOMINGINVOICE.CHANGENR
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_INCOMINGINVOICE.USERNAME
left outer join DD04T_PROD as DD04T
on DD04T.ROLLNAME = CDPOS_INCOMINGINVOICE.FNAME
where CDPOS_INCOMINGINVOICE.TABNAME in ('RSEG','RBKP') and CDPOS_INCOMINGINVOICE.FNAME NOT LIKE 'SPGR%'
and CDPOS_INCOMINGINVOICE.CHNGIND = 'U'
AND BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3')

UNION ALL 

------------------------------------------------------
--Payment Blocks
------------------------------------------------------

------------------------------------------------------
--Payment Blocks
------------------------------------------------------
select DISTINCT  BKPF.BELNR || BKPF.BUKRS || BKPF.GJAHR as CaseId,
        CASE WHEN TRIM(CDPOS_BELEG.VALUE_NEW) = '' or TRIM(CDPOS_BELEG.VALUE_NEW) IS NULL THEN 'Payment Block Deactivated' ELSE 'Payment Block Activated: ' || TRIM(T008T.TEXTL) END as ProcessStep,
        TO_TIMESTAMP(CDHDR_BELEG.UDATE || ' ' || CDHDR_BELEG.UTIME,'YYYYMMDD HH24MISS') as TimeStamp,
        CDHDR_BELEG.USERNAME as User,
    CASE WHEN CDHDR_BELEG.USERNAME like '%ROBOT%' THEN 'Robotic'  WHEN USR02.USTYP = 'A' THEN 'Manual' ELSE 'Automatic' END as Automation 
FROM BKPF_PROD as BKPF
join BSAK_PROD as BSAK
on BKPF.BELNR = BSAK.BELNR and BKPF.GJAHR = BSAK.GJAHR and BKPF.BUKRS = BSAK.BUKRS
join CDHDR_BELEG_PROD as CDHDR_BELEG 
on BKPF.BUKRS || BKPF.BELNR || BKPF.GJAHR = SUBSTR(CDHDR_BELEG.OBJECTID, 4, 18)
join CDPOS_BELEG_ALL_PROD as CDPOS_BELEG 
on CDHDR_BELEG.OBJECTID = CDPOS_BELEG.OBJECTID and CDHDR_BELEG.CHANGENR = CDPOS_BELEG.CHANGENR and trim(CDPOS_BELEG.FNAME) = 'ZLSPR' and trim(CDPOS_BELEG.CHNGIND) = 'U'
left outer join T008T_PROD as T008T
on TRIM(CDPOS_BELEG.VALUE_NEW) = T008T.ZAHLS 
left outer join USR02_PROD as USR02
on USR02.BNAME = CDHDR_BELEG.USERNAME
WHERE BKPF.BUKRS IN ('CZ10','DK10','FI00','FI10','FI11','FI12','FI17','PL10','PL71','SE10','SE75','SE77','SE78','SE79','SK30','TR20')
AND BKPF.BLART IN ('K8','K9','KA','KG','KP','KR','KZ','PR','RB','RD','RE','RG','SA','SB','SC','SD','SG','SK','SP','SR','SU','WA','WE','WI','WL','ZP','ZV','K3');