DLLG#66674 -- Koppeling met Brivo
svn path=/Customer/trunk/; revision=51927
This commit is contained in:
549
DLLG/DLLG.sql
549
DLLG/DLLG.sql
@@ -20,23 +20,29 @@ SET DEFINE OFF
|
||||
|
||||
CREATE OR REPLACE PACKAGE DLLG
|
||||
AS
|
||||
FUNCTION res_presave (p_user_key IN NUMBER,
|
||||
p_rsv_ruimte_key IN NUMBER,
|
||||
p_activiteit_key IN NUMBER,
|
||||
p_res_deel_key IN NUMBER,
|
||||
p_datum_van IN DATE,
|
||||
p_datum_tot IN DATE,
|
||||
p_volgnr IN NUMBER)
|
||||
RETURN VARCHAR2;
|
||||
|
||||
FUNCTION res_presave (p_user_key IN NUMBER,
|
||||
p_rsv_ruimte_key IN NUMBER,
|
||||
p_activiteit_key IN NUMBER,
|
||||
p_res_deel_key IN NUMBER,
|
||||
p_datum_van IN DATE,
|
||||
p_datum_tot IN DATE,
|
||||
p_volgnr IN NUMBER)
|
||||
RETURN VARCHAR2;
|
||||
FUNCTION get_hex_card_data (p_card_number IN VARCHAR2,
|
||||
p_facility_code IN VARCHAR2)
|
||||
RETURN VARCHAR2;
|
||||
|
||||
PROCEDURE update_bezoeker (p_bezkey IN NUMBER);
|
||||
PROCEDURE update_bezoeker (p_bezkey IN NUMBER);
|
||||
|
||||
PROCEDURE set_bezoeker_syncdate (p_bezkey IN NUMBER,
|
||||
p_user_id IN NUMBER,
|
||||
p_credential_id IN NUMBER);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PACKAGE BODY DLLG
|
||||
AS
|
||||
|
||||
FUNCTION res_presave (p_user_key IN NUMBER,
|
||||
p_rsv_ruimte_key IN NUMBER,
|
||||
p_activiteit_key IN NUMBER,
|
||||
@@ -46,80 +52,446 @@ AS
|
||||
p_volgnr IN NUMBER)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_result VARCHAR2 (300);
|
||||
v_date DATE;
|
||||
v_count NUMBER;
|
||||
v_discipline_key NUMBER;
|
||||
v_result VARCHAR2 (300);
|
||||
v_date DATE;
|
||||
v_count NUMBER;
|
||||
v_discipline_key NUMBER;
|
||||
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_errormsg VARCHAR2 (200);
|
||||
v_errorhint VARCHAR2 (200);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_errormsg VARCHAR2 (200);
|
||||
v_errorhint VARCHAR2 (200);
|
||||
BEGIN
|
||||
v_result := 'OK';
|
||||
|
||||
v_errorhint := 'Controleer activiteit: ' || p_activiteit_key;
|
||||
IF p_activiteit_key = 30 AND p_rsv_ruimte_key = -1 -- workplace en alleen nieuwe reserveringen
|
||||
|
||||
IF p_activiteit_key = 30 AND p_rsv_ruimte_key = -1 -- workplace en alleen nieuwe reserveringen
|
||||
THEN
|
||||
v_errorhint := 'Kijk hoeveel reserveringen er al zijn voor die dag';
|
||||
SELECT count(*)
|
||||
v_errorhint :=
|
||||
'Kijk hoeveel reserveringen er al zijn voor die dag';
|
||||
|
||||
SELECT COUNT (*)
|
||||
INTO v_count
|
||||
FROM res_rsv_ruimte rrr
|
||||
WHERE rrr.res_rsv_ruimte_verwijder IS NULL
|
||||
AND rrr.res_activiteit_key = 30 -- 30 workplace
|
||||
AND TRUNC(res_rsv_ruimte_van) = TRUNC (p_datum_tot);
|
||||
AND rrr.res_activiteit_key = 30 -- 30 workplace
|
||||
AND TRUNC (res_rsv_ruimte_van) = TRUNC (p_datum_tot);
|
||||
|
||||
IF v_count > 3
|
||||
THEN
|
||||
v_result := 'Beste collega,' || CHR(10) ||
|
||||
'We hebben deze maand al vier reserveringen van je gevonden. Je maximaal aantal te reserveren werkplekken per maand is dus bereikt.' || CHR(10) ||
|
||||
'Hartelijke groet, KPN Facilities';
|
||||
v_result :=
|
||||
'Beste collega,'
|
||||
|| CHR (10)
|
||||
|| 'We hebben deze maand al vier reserveringen van je gevonden. Je maximaal aantal te reserveren werkplekken per maand is dus bereikt.'
|
||||
|| CHR (10)
|
||||
|| 'Hartelijke groet, KPN Facilities';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN v_result;
|
||||
EXCEPTION WHEN OTHERS
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||||
v_errormsg := 'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
RETURN v_result;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||||
v_errormsg :=
|
||||
'OTHERS (error '
|
||||
|| oracle_err_num
|
||||
|| '/'
|
||||
|| oracle_err_mes
|
||||
|| ')';
|
||||
RETURN v_result;
|
||||
END;
|
||||
|
||||
PROCEDURE update_bezoeker (p_bezkey IN NUMBER)
|
||||
AS
|
||||
|
||||
CURSOR c
|
||||
IS
|
||||
SELECT pf.prs_perslid_naam_full, prs_perslid_email, prs_perslid_mobiel
|
||||
FROM bez_bezoekers b, bez_afspraak a, prs_perslid p, prs_v_perslid_fullnames pf
|
||||
WHERE bez_bezoekers_key = p_bezkey
|
||||
AND b.bez_afspraak_key = a.bez_afspraak_key
|
||||
AND a.bez_afspraak_host_key = p.prs_perslid_key
|
||||
AND p.prs_perslid_key = pf.prs_perslid_key;
|
||||
FUNCTION get_hex_card_data (p_card_number VARCHAR2,
|
||||
p_facility_code VARCHAR2)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_card_bin VARCHAR2 (100);
|
||||
v_facility_bin VARCHAR2 (100);
|
||||
v_card_hex VARCHAR2 (100);
|
||||
v_facility_hex VARCHAR2 (100);
|
||||
v_bin VARCHAR2 (100);
|
||||
v_bin_str VARCHAR2 (100);
|
||||
v_result VARCHAR2 (100);
|
||||
v_length NUMBER;
|
||||
|
||||
BEGIN
|
||||
FOR rec IN c
|
||||
LOOP
|
||||
-- Naam
|
||||
IF FLX.getflex ('BEZ', 1020, p_bezkey) IS NULL
|
||||
THEN
|
||||
FLX.setflex ('BEZ', 1020, p_bezkey, rec.prs_perslid_naam_full);
|
||||
END IF;
|
||||
-- Email
|
||||
IF FLX.getflex ('BEZ', 1021, p_bezkey) IS NULL
|
||||
THEN
|
||||
FLX.setflex ('BEZ', 1021, p_bezkey, rec.prs_perslid_email);
|
||||
END IF;
|
||||
-- Mobiel
|
||||
IF FLX.getflex ('BEZ', 1022, p_bezkey) IS NULL
|
||||
THEN
|
||||
FLX.setflex ('BEZ', 1022, p_bezkey, rec.prs_perslid_mobiel);
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
FUNCTION OneHex2Bin (p_hex VARCHAR2)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_result VARCHAR2 (10);
|
||||
BEGIN
|
||||
IF p_hex = '0'
|
||||
THEN
|
||||
v_result := '0000';
|
||||
ELSIF p_hex = '1'
|
||||
THEN
|
||||
v_result := '0001';
|
||||
ELSIF p_hex = '2'
|
||||
THEN
|
||||
v_result := '0010';
|
||||
ELSIF p_hex = '3'
|
||||
THEN
|
||||
v_result := '0011';
|
||||
ELSIF p_hex = '4'
|
||||
THEN
|
||||
v_result := '0100';
|
||||
ELSIF p_hex = '5'
|
||||
THEN
|
||||
v_result := '0101';
|
||||
ELSIF p_hex = '6'
|
||||
THEN
|
||||
v_result := '0110';
|
||||
ELSIF p_hex = '7'
|
||||
THEN
|
||||
v_result := '0111';
|
||||
ELSIF p_hex = '8'
|
||||
THEN
|
||||
v_result := '1000';
|
||||
ELSIF p_hex = '9'
|
||||
THEN
|
||||
v_result := '1001';
|
||||
ELSIF p_hex = 'A'
|
||||
THEN
|
||||
v_result := '1010';
|
||||
ELSIF p_hex = 'B'
|
||||
THEN
|
||||
v_result := '1011';
|
||||
ELSIF p_hex = 'C'
|
||||
THEN
|
||||
v_result := '1100';
|
||||
ELSIF p_hex = 'D'
|
||||
THEN
|
||||
v_result := '1101';
|
||||
ELSIF p_hex = 'E'
|
||||
THEN
|
||||
v_result := '1110';
|
||||
ELSIF p_hex = 'F'
|
||||
THEN
|
||||
v_result := '1111';
|
||||
END IF;
|
||||
|
||||
RETURN v_result;
|
||||
END;
|
||||
|
||||
FUNCTION FourBin2Hex (p_bin VARCHAR2)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_result VARCHAR2 (10);
|
||||
BEGIN
|
||||
IF p_bin = '0000'
|
||||
THEN
|
||||
v_result := '0';
|
||||
ELSIF p_bin = '0001'
|
||||
THEN
|
||||
v_result := '1';
|
||||
ELSIF p_bin = '0010'
|
||||
THEN
|
||||
v_result := '2';
|
||||
ELSIF p_bin = '0011'
|
||||
THEN
|
||||
v_result := '3';
|
||||
ELSIF p_bin = '0100'
|
||||
THEN
|
||||
v_result := '4';
|
||||
ELSIF p_bin = '0101'
|
||||
THEN
|
||||
v_result := '5';
|
||||
ELSIF p_bin = '0110'
|
||||
THEN
|
||||
v_result := '6';
|
||||
ELSIF p_bin = '0111'
|
||||
THEN
|
||||
v_result := '7';
|
||||
ELSIF p_bin = '1000'
|
||||
THEN
|
||||
v_result := '8';
|
||||
ELSIF p_bin = '1001'
|
||||
THEN
|
||||
v_result := '9';
|
||||
ELSIF p_bin = '1010'
|
||||
THEN
|
||||
v_result := 'A';
|
||||
ELSIF p_bin = '1011'
|
||||
THEN
|
||||
v_result := 'B';
|
||||
ELSIF p_bin = '1100'
|
||||
THEN
|
||||
v_result := 'C';
|
||||
ELSIF p_bin = '1101'
|
||||
THEN
|
||||
v_result := 'D';
|
||||
ELSIF p_bin = '1110'
|
||||
THEN
|
||||
v_result := 'E';
|
||||
ELSIF p_bin = '1111'
|
||||
THEN
|
||||
v_result := 'F';
|
||||
END IF;
|
||||
|
||||
|
||||
RETURN v_result;
|
||||
END;
|
||||
|
||||
|
||||
FUNCTION set_parity (p_bin VARCHAR2,
|
||||
p_mode VARCHAR2,
|
||||
p_parity NUMBER)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
BEGIN
|
||||
IF p_mode = 'after'
|
||||
THEN
|
||||
IF MOD (LENGTH (REPLACE (p_bin || p_parity, '0')), 2) = 0
|
||||
THEN
|
||||
RETURN p_bin || '0';
|
||||
ELSE
|
||||
RETURN p_bin || '1';
|
||||
END IF;
|
||||
ELSE
|
||||
IF MOD (LENGTH (REPLACE (p_bin || p_parity, '0')), 2) = 0
|
||||
THEN
|
||||
RETURN '0' || p_bin;
|
||||
ELSE
|
||||
RETURN '1' || p_bin;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
BEGIN
|
||||
v_card_hex := p_card_number;
|
||||
|
||||
-- transform the hex card data into a binary string
|
||||
FOR v_index IN 1 .. 4
|
||||
LOOP
|
||||
v_card_bin :=
|
||||
v_card_bin || OneHex2Bin (SUBSTR (v_card_hex, 1, 1));
|
||||
v_card_hex := SUBSTR (v_card_hex, 2, 4);
|
||||
END LOOP;
|
||||
|
||||
-- add the parity bit
|
||||
--v_card_bin := set_parity (v_card_bin, 'after', 1);
|
||||
|
||||
-- transform the hex facility data into a binary string
|
||||
v_facility_hex := p_facility_code;
|
||||
|
||||
FOR v_index IN 1 .. 2
|
||||
LOOP
|
||||
v_facility_bin :=
|
||||
v_facility_bin || OneHex2Bin (SUBSTR (v_facility_hex, 1, 1));
|
||||
v_facility_hex := SUBSTR (v_facility_hex, 2, 4);
|
||||
END LOOP;
|
||||
|
||||
-- add the parity bit
|
||||
-- v_facility_bin := set_parity (v_facility_bin, 'before', 0);
|
||||
|
||||
-- combine the facility data and the card data
|
||||
v_bin := v_facility_bin || v_card_bin;
|
||||
-- the first 12 bits have an even leading parity bit
|
||||
-- the last 12 bits have a trailing odd parity bit
|
||||
v_bin := set_parity (SUBSTR(v_bin, 1,12), 'before', 0) || set_parity (SUBSTR(v_bin, 13,12), 'after', 1);
|
||||
|
||||
-- and convert the binary string into hex
|
||||
WHILE v_bin IS NOT NULL
|
||||
LOOP
|
||||
IF LENGTH (v_bin) <= 4
|
||||
THEN
|
||||
v_bin_str := LPAD (v_bin, 4, '0');
|
||||
v_bin := NULL;
|
||||
ELSE
|
||||
v_bin_str := SUBSTR (v_bin, LENGTH (v_bin) - 3, 4);
|
||||
v_bin := SUBSTR (v_bin, 1, LENGTH (v_bin) - 4);
|
||||
END IF;
|
||||
|
||||
v_result := FourBin2Hex (v_bin_str) || v_result;
|
||||
END LOOP;
|
||||
|
||||
RETURN v_result;
|
||||
END;
|
||||
|
||||
|
||||
|
||||
PROCEDURE update_bezoeker (p_bezkey IN NUMBER)
|
||||
AS
|
||||
CURSOR c IS
|
||||
SELECT pf.prs_perslid_naam_full,
|
||||
prs_perslid_email,
|
||||
prs_perslid_mobiel
|
||||
FROM bez_bezoekers b,
|
||||
bez_afspraak a,
|
||||
prs_perslid p,
|
||||
prs_v_perslid_fullnames pf
|
||||
WHERE bez_bezoekers_key = p_bezkey
|
||||
AND b.bez_afspraak_key = a.bez_afspraak_key
|
||||
AND a.bez_afspraak_host_key = p.prs_perslid_key
|
||||
AND p.prs_perslid_key = pf.prs_perslid_key;
|
||||
|
||||
v_count NUMBER;
|
||||
v_found NUMBER;
|
||||
v_code VARCHAR2 (5);
|
||||
v_exists NUMBER;
|
||||
v_card_number_key NUMBER;
|
||||
v_facility_code_key NUMBER;
|
||||
v_hex_code_key NUMBER;
|
||||
v_date DATE;
|
||||
BEGIN
|
||||
FOR rec IN c
|
||||
LOOP
|
||||
-- Naam
|
||||
IF FLX.getflex ('BEZ', 1020, p_bezkey) IS NULL
|
||||
THEN
|
||||
FLX.setflex ('BEZ',
|
||||
1020,
|
||||
p_bezkey,
|
||||
rec.prs_perslid_naam_full);
|
||||
END IF;
|
||||
|
||||
-- Email
|
||||
IF FLX.getflex ('BEZ', 1021, p_bezkey) IS NULL
|
||||
THEN
|
||||
FLX.setflex ('BEZ',
|
||||
1021,
|
||||
p_bezkey,
|
||||
rec.prs_perslid_email);
|
||||
END IF;
|
||||
|
||||
-- Mobiel
|
||||
IF FLX.getflex ('BEZ', 1022, p_bezkey) IS NULL
|
||||
THEN
|
||||
FLX.setflex ('BEZ',
|
||||
1022,
|
||||
p_bezkey,
|
||||
rec.prs_perslid_mobiel);
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
|
||||
-- Vul een uniek kaarnummer in die uniek is voor deze dag
|
||||
v_count := 0;
|
||||
v_found := 0;
|
||||
|
||||
DBMS_OUTPUT.put_line ('kenmerken');
|
||||
|
||||
SELECT bez_kenmerk_key
|
||||
INTO v_card_number_key
|
||||
FROM bez_kenmerk
|
||||
WHERE bez_kenmerk_upper = 'CARD NUMBER';
|
||||
|
||||
SELECT bez_kenmerk_key
|
||||
INTO v_facility_code_key
|
||||
FROM bez_kenmerk
|
||||
WHERE bez_kenmerk_upper = 'FACILITY CODE';
|
||||
|
||||
SELECT bez_kenmerk_key
|
||||
INTO v_hex_code_key
|
||||
FROM bez_kenmerk
|
||||
WHERE bez_kenmerk_upper = 'HEX CODE';
|
||||
|
||||
DBMS_OUTPUT.put_line ('v_date');
|
||||
|
||||
SELECT bez_afspraak_datum
|
||||
INTO v_date
|
||||
FROM bez_afspraak a, bez_bezoekers b
|
||||
WHERE a.bez_afspraak_key = b.bez_afspraak_key
|
||||
AND b.bez_bezoekers_key = p_bezkey;
|
||||
|
||||
DBMS_OUTPUT.put_line ('v_code');
|
||||
|
||||
SELECT MAX (bez_kenmerkwaarde_waarde)
|
||||
INTO v_code
|
||||
FROM bez_kenmerkwaarde kw
|
||||
WHERE kw.bez_bezoekers_key = p_bezkey
|
||||
AND kw.bez_kenmerk_key = v_card_number_key;
|
||||
|
||||
WHILE v_found = 0 AND v_count < 1000
|
||||
LOOP
|
||||
--DBMS_OUTPUT.put_line (COALESCE (v_code, '-1'));
|
||||
|
||||
SELECT COUNT (*)
|
||||
INTO v_exists
|
||||
FROM bez_bezoekers b, bez_kenmerkwaarde kw, bez_afspraak a
|
||||
WHERE a.bez_afspraak_key = b.bez_afspraak_key
|
||||
AND kw.bez_bezoekers_key = b.bez_bezoekers_key
|
||||
AND b.bez_bezoekers_key <> p_bezkey
|
||||
AND kw.bez_kenmerk_key = v_card_number_key
|
||||
AND kw.bez_kenmerkwaarde_waarde = COALESCE (v_code, '-1')
|
||||
AND bez_afspraak_datum BETWEEN v_date - 1 AND v_date + 2;
|
||||
|
||||
IF v_exists > 0 OR v_code IS NULL
|
||||
THEN
|
||||
v_code := TRUNC (DBMS_RANDOM.VALUE (9999, 50000));
|
||||
--DBMS_OUTPUT.put_line ('Nieuwe code:' || v_code);
|
||||
ELSE
|
||||
v_found := 1;
|
||||
FLX.setflex ('BEZ',
|
||||
v_card_number_key,
|
||||
p_bezkey,
|
||||
v_code);
|
||||
END IF;
|
||||
|
||||
v_count := v_count + 1;
|
||||
END LOOP;
|
||||
|
||||
FLX.setflex ('BEZ',
|
||||
v_facility_code_key,
|
||||
p_bezkey,
|
||||
'123');
|
||||
|
||||
-- Vul het flexveld hex code met de hex waarde die gescant moet worden.
|
||||
-- We gebruiken hiervoor 'The Standard 26-Bit Format'
|
||||
FLX.setflex (
|
||||
'BEZ',
|
||||
v_hex_code_key,
|
||||
p_bezkey,
|
||||
DLLG.get_hex_card_data (
|
||||
LPAD (TRIM (TO_CHAR (v_code, 'XXXXXX')), 4, '0'),
|
||||
LPAD (TRIM (TO_CHAR (123, 'XXXXXX')), 2, '0')));
|
||||
END;
|
||||
|
||||
PROCEDURE set_bezoeker_syncdate (p_bezkey IN NUMBER,
|
||||
p_user_id IN NUMBER,
|
||||
p_credential_id IN NUMBER)
|
||||
AS
|
||||
v_credential_id_key NUMBER;
|
||||
v_user_id_key NUMBER;
|
||||
v_sync_timestamp_key NUMBER;
|
||||
BEGIN
|
||||
-- De id van de badge die in Brivo aangemaakt is.
|
||||
SELECT bez_kenmerk_key
|
||||
INTO v_credential_id_key
|
||||
FROM bez_kenmerk
|
||||
WHERE bez_kenmerk_upper = 'BRIVO CREDENTIAL ID';
|
||||
|
||||
FLX.setflex ('BEZ',
|
||||
v_credential_id_key,
|
||||
p_bezkey,
|
||||
p_credential_id);
|
||||
|
||||
-- De id van de aangemaakte user in Brivo
|
||||
SELECT bez_kenmerk_key
|
||||
INTO v_user_id_key
|
||||
FROM bez_kenmerk
|
||||
WHERE bez_kenmerk_upper = 'BRIVO USER ID';
|
||||
|
||||
FLX.setflex ('BEZ',
|
||||
v_user_id_key,
|
||||
p_bezkey,
|
||||
p_user_id);
|
||||
|
||||
-- Als de elementen in Brivo aangemaakt zijn, zetten we de timestamp.
|
||||
-- Hierdoor wordt deze bezoeker niet weer opnieuw aangeboden.
|
||||
SELECT bez_kenmerk_key
|
||||
INTO v_sync_timestamp_key
|
||||
FROM bez_kenmerk
|
||||
WHERE bez_kenmerk_upper = 'BRIVO SYNC TIMESTAMP';
|
||||
|
||||
FLX.setflex ('BEZ',
|
||||
v_sync_timestamp_key,
|
||||
p_bezkey,
|
||||
TO_CHAR(SYSDATE, 'YYYY-MM-DD HH24:MI:SSS'));
|
||||
|
||||
END;
|
||||
END;
|
||||
/
|
||||
|
||||
@@ -1376,6 +1748,7 @@ END;
|
||||
|
||||
-- Koppeling met Nsecure
|
||||
-- Koppeling gaat via API2: https://dllg.facilitor.nl/api2/reports.json/?usrrap_key=821
|
||||
-- Depricated !!!!!!!!!!!!!!
|
||||
CREATE OR REPLACE VIEW dllg_v_rap_aeos_bez
|
||||
(
|
||||
afspraak_key, -- appointment_id
|
||||
@@ -1434,6 +1807,58 @@ AS
|
||||
ON x.bez_afspraak_key = t.fac_tracking_refkey;
|
||||
|
||||
|
||||
-- Koppeling met Brivo
|
||||
CREATE OR REPLACE VIEW dllg_v_bezoeker_brivo
|
||||
(
|
||||
request,
|
||||
omschrijving,
|
||||
afspraak_key,
|
||||
bezoeker_key,
|
||||
bezoeker_naam,
|
||||
bezoeker_bedrijf,
|
||||
bezoeker_email,
|
||||
card_number,
|
||||
facility_code,
|
||||
afspraak_van,
|
||||
afspraak_tot,
|
||||
meeting_id
|
||||
)
|
||||
AS
|
||||
SELECT 'POST',
|
||||
'Afspraak vanuit Facilitor'
|
||||
omschr,
|
||||
a.bez_afspraak_key,
|
||||
b.bez_bezoekers_key,
|
||||
b.bez_afspraak_naam,
|
||||
b.bez_afspraak_bedrijf,
|
||||
b.bez_bezoekers_email,
|
||||
c.card,
|
||||
f.facility,
|
||||
TRUNC(a.bez_afspraak_datum),
|
||||
TRUNC(a.bez_afspraak_datum)+1,
|
||||
''
|
||||
FROM bez_bezoekers b,
|
||||
bez_afspraak a,
|
||||
(SELECT kw.bez_bezoekers_key, bez_kenmerkwaarde_waarde card
|
||||
FROM bez_kenmerk k, bez_kenmerkwaarde kw
|
||||
WHERE k.bez_kenmerk_upper LIKE 'CARD NUMBER%'
|
||||
AND kw.bez_kenmerk_key = k.bez_kenmerk_key) c,
|
||||
(SELECT kw.bez_bezoekers_key, bez_kenmerkwaarde_waarde facility
|
||||
FROM bez_kenmerk k, bez_kenmerkwaarde kw
|
||||
WHERE k.bez_kenmerk_upper LIKE 'FACILITY CODE%'
|
||||
AND kw.bez_kenmerk_key = k.bez_kenmerk_key) f
|
||||
WHERE b.bez_afspraak_key = a.bez_afspraak_key
|
||||
AND TRUNC(a.bez_afspraak_datum) = TRUNC (SYSDATE) -- Alleen afspraken nu
|
||||
AND b.bez_bezoekers_key = c.bez_bezoekers_key
|
||||
AND b.bez_bezoekers_key = f.bez_bezoekers_key
|
||||
AND NOT EXISTS
|
||||
(SELECT kw.bez_bezoekers_key, bez_kenmerkwaarde_waarde
|
||||
FROM bez_kenmerk k, bez_kenmerkwaarde kw
|
||||
WHERE k.bez_kenmerk_upper = 'BRIVO SYNC TIMESTAMP' -- Er is nog geen sync naar brivo geweest
|
||||
AND kw.bez_kenmerk_key = k.bez_kenmerk_key
|
||||
AND kw.bez_bezoekers_key = b.bez_bezoekers_key);
|
||||
|
||||
|
||||
------ payload end ------
|
||||
|
||||
SET DEFINE OFF
|
||||
|
||||
Reference in New Issue
Block a user