SGGR#38837 Registratie poolauto's in Facilitor
svn path=/Customer/trunk/; revision=32190
This commit is contained in:
230
SGGR/sggr.sql
230
SGGR/sggr.sql
@@ -21,6 +21,101 @@ SET DEFINE OFF
|
||||
|
||||
------ payload begin ------
|
||||
|
||||
CREATE OR REPLACE PACKAGE sggr
|
||||
AS
|
||||
FUNCTION find_str (p_string IN VARCHAR2, p_search IN VARCHAR2)
|
||||
RETURN VARCHAR2;
|
||||
|
||||
FUNCTION find_oud (p_string IN VARCHAR2, p_default IN VARCHAR2)
|
||||
RETURN VARCHAR2;
|
||||
|
||||
FUNCTION find_nieuw (p_string IN VARCHAR2, p_default IN VARCHAR2)
|
||||
RETURN VARCHAR2;
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
CREATE OR REPLACE PACKAGE BODY sggr
|
||||
AS
|
||||
FUNCTION find_str (p_string IN VARCHAR2, p_search IN VARCHAR2)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_index NUMBER;
|
||||
v_van NUMBER;
|
||||
v_tot NUMBER;
|
||||
BEGIN
|
||||
v_index := INSTR (p_string, p_search);
|
||||
|
||||
IF v_index > 0
|
||||
THEN
|
||||
v_van := v_index + LENGTH (p_search);
|
||||
v_tot := INSTR (p_string, CHR (10), v_index + LENGTH (p_search));
|
||||
-- dbms_output.put_line ('van:' || to_char(v_van));
|
||||
-- dbms_output.put_line ('tot:' || to_char(v_tot));
|
||||
|
||||
-- als v_tot gelijk is aan 0 dan zitten we op het einde van de string. Geef
|
||||
-- dan alles maar terug tot het einde van de string (maar even op 1000 gezet.
|
||||
IF v_tot = 0
|
||||
THEN
|
||||
v_tot := 1000;
|
||||
END IF;
|
||||
|
||||
RETURN SUBSTR (p_string, v_van + 1, v_tot - v_van - 1);
|
||||
ELSE
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
END;
|
||||
|
||||
FUNCTION find_oud (p_string IN VARCHAR2, p_default IN VARCHAR2)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_dummy NUMBER;
|
||||
v_result VARCHAR2 (100);
|
||||
BEGIN
|
||||
IF p_string IS NOT NULL
|
||||
THEN
|
||||
v_result := TRIM (SUBSTR (p_string, 1, INSTR (p_string, ' --> ')));
|
||||
|
||||
IF v_result = '(leeg)'
|
||||
THEN
|
||||
v_result := NULL;
|
||||
END IF;
|
||||
|
||||
RETURN v_result;
|
||||
ELSE
|
||||
RETURN p_default;
|
||||
END IF;
|
||||
END;
|
||||
|
||||
FUNCTION find_nieuw (p_string IN VARCHAR2, p_default IN VARCHAR2)
|
||||
RETURN VARCHAR2
|
||||
AS
|
||||
v_dummy NUMBER;
|
||||
v_van NUMBER;
|
||||
v_tot NUMBER;
|
||||
v_token VARCHAR (10);
|
||||
v_result VARCHAR (100);
|
||||
BEGIN
|
||||
v_token := ' --> ';
|
||||
v_van := INSTR (p_string, v_token) + LENGTH (v_token);
|
||||
|
||||
IF v_van > 0
|
||||
THEN
|
||||
v_result := TRIM (SUBSTR (p_string, v_van));
|
||||
|
||||
IF v_result = '(gewist)' OR v_result = '(Leeg)'
|
||||
THEN
|
||||
v_result := NULL;
|
||||
END IF;
|
||||
|
||||
RETURN v_result;
|
||||
ELSE
|
||||
RETURN p_default;
|
||||
END IF;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
|
||||
/* de te factureren contracten */
|
||||
|
||||
CREATE OR REPLACE VIEW sggr_v_rap_cnt_periode_saas
|
||||
@@ -1756,6 +1851,141 @@ AS
|
||||
AND P.PRS_SRTPERSLID_KEY IN (3803, 2052, 3806, 2050, 3807)
|
||||
ORDER BY N.PRS_PERSLID_NAAM_FULL;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE sggr_export_daily_task (
|
||||
p_applname IN VARCHAR2,
|
||||
p_applrun IN VARCHAR2,
|
||||
p_filedir IN VARCHAR2,
|
||||
p_filename IN VARCHAR2
|
||||
)
|
||||
AS
|
||||
CURSOR c
|
||||
IS
|
||||
SELECT *
|
||||
FROM fac_tracking t, ins_deel d
|
||||
WHERE fac_tracking_refkey = d.ins_deel_key
|
||||
AND d.ins_srtdeel_key = 481 -- autos
|
||||
AND fac_srtnotificatie_key IN (96, 97) -- uitgifte (insout) en inname (insinn)
|
||||
ORDER BY ins_deel_key, fac_tracking_datum;
|
||||
|
||||
v_bestuurder VARCHAR2 (60);
|
||||
v_uitgifte DATE;
|
||||
v_inname DATE;
|
||||
v_reden VARCHAR2 (100);
|
||||
v_van VARCHAR2 (100);
|
||||
v_naar VARCHAR2 (100);
|
||||
v_km_uitgifte NUMBER (10);
|
||||
v_km_inname NUMBER (10);
|
||||
v_fac_tracking_uitgifte_key NUMBER (10);
|
||||
v_fac_tracking_inname_key NUMBER (10);
|
||||
v_dummy VARCHAR2 (1000);
|
||||
v_search VARCHAR2 (1000);
|
||||
BEGIN
|
||||
DELETE sggr_autorit_registratie;
|
||||
|
||||
FOR rec IN c
|
||||
LOOP
|
||||
BEGIN
|
||||
v_search := 'Reden van gebruik:';
|
||||
v_dummy := sggr.find_str (rec.fac_tracking_oms, v_search);
|
||||
v_reden := sggr.find_nieuw (v_dummy, v_reden);
|
||||
v_search := 'Van:';
|
||||
v_dummy := sggr.find_str (rec.fac_tracking_oms, v_search);
|
||||
v_van := sggr.find_nieuw (v_dummy, v_van);
|
||||
v_search := 'Naar:';
|
||||
v_dummy := sggr.find_str (rec.fac_tracking_oms, v_search);
|
||||
v_naar := sggr.find_nieuw (v_dummy, v_naar);
|
||||
v_search := 'Kilometerstand:';
|
||||
v_dummy := sggr.find_str (rec.fac_tracking_oms, v_search);
|
||||
IF v_dummy IS NULL
|
||||
THEN
|
||||
v_km_uitgifte := v_km_inname;
|
||||
ELSE
|
||||
v_km_uitgifte := sggr.find_oud (v_dummy, v_km_uitgifte);
|
||||
v_km_inname := sggr.find_nieuw (v_dummy, v_km_inname);
|
||||
END IF;
|
||||
v_search := 'is uitgegeven aan';
|
||||
v_dummy := sggr.find_str (rec.fac_tracking_oms, v_search);
|
||||
v_bestuurder := v_dummy;
|
||||
|
||||
|
||||
IF rec.fac_srtnotificatie_key = 96
|
||||
THEN
|
||||
-- Uitgifte
|
||||
v_uitgifte := rec.fac_tracking_datum;
|
||||
|
||||
INSERT INTO sggr_autorit_registratie (ins_deel_key,
|
||||
bestuurder,
|
||||
uitgifte,
|
||||
reden,
|
||||
van,
|
||||
naar,
|
||||
km_uitgifte,
|
||||
fac_tracking_uitgifte_key)
|
||||
VALUES (rec.fac_tracking_refkey,
|
||||
v_bestuurder,
|
||||
v_uitgifte,
|
||||
v_reden,
|
||||
v_van,
|
||||
v_naar,
|
||||
v_km_uitgifte,
|
||||
rec.fac_tracking_key);
|
||||
|
||||
v_fac_tracking_uitgifte_key := rec.fac_tracking_key;
|
||||
ELSE
|
||||
v_inname := rec.fac_tracking_datum;
|
||||
|
||||
UPDATE sggr_autorit_registratie
|
||||
SET inname = v_inname,
|
||||
reden = COALESCE (v_reden, reden),
|
||||
van = COALESCE (v_van, van),
|
||||
naar = COALESCE (v_naar, naar),
|
||||
km_uitgifte = COALESCE (v_km_uitgifte, km_uitgifte),
|
||||
km_inname = v_km_inname,
|
||||
fac_tracking_inname_key = rec.fac_tracking_key
|
||||
WHERE fac_tracking_uitgifte_key = v_fac_tracking_uitgifte_key;
|
||||
END IF;
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE VIEW SGGR_V_RAP_AUTO_REGISTRATIE
|
||||
(
|
||||
TIMESTAMP,
|
||||
MAAND,
|
||||
AUTO,
|
||||
BESTUURDER,
|
||||
FCLT_D_DATUM,
|
||||
UITGIFTE_DATUM,
|
||||
UITGIFTE_TIJD,
|
||||
INNAME_DATUM,
|
||||
INNAME_TIJD,
|
||||
REDEN,
|
||||
VAN,
|
||||
NAAR,
|
||||
KM_UITGIFTE,
|
||||
KM_INNAME,
|
||||
KM_VERSCHIL
|
||||
)
|
||||
AS
|
||||
SELECT TO_CHAR (uitgifte, 'yyyymmddhh24mi') timestamp,
|
||||
TO_CHAR (uitgifte, 'Month') maand,
|
||||
ins_deel_omschrijving auto,
|
||||
bestuurder,
|
||||
TO_CHAR (uitgifte, 'dd-mm-yyyy') filter,
|
||||
TO_CHAR (uitgifte, 'dd-mm-yyyy') uitgifte_datum,
|
||||
TO_CHAR (uitgifte, 'hh24:mi') uitgifte_tijd,
|
||||
TO_CHAR (inname, 'dd-mm-yyyy') inname_datum,
|
||||
TO_CHAR (inname, 'hh24:mi') inname_tijd,
|
||||
reden,
|
||||
van,
|
||||
naar,
|
||||
km_uitgifte,
|
||||
km_inname,
|
||||
km_inname - km_uitgifte km_verschil
|
||||
FROM sggr_autorit_registratie a, ins_deel d
|
||||
WHERE a.ins_deel_key = d.ins_deel_key;
|
||||
|
||||
COMMIT;
|
||||
|
||||
------ payload end ------
|
||||
|
||||
Reference in New Issue
Block a user