TWYN#52389 converteren oude data
svn path=/Customer/; revision=37382
This commit is contained in:
516
TWYN/twyn.sql
516
TWYN/twyn.sql
@@ -2893,6 +2893,522 @@ EXCEPTION
|
||||
END;
|
||||
/
|
||||
|
||||
--
|
||||
-- Eigen logfile voor BGT
|
||||
--
|
||||
CREATE OR REPLACE PROCEDURE bgtLog ( p_actie IN VARCHAR2
|
||||
, p_level IN VARCHAR2
|
||||
, p_msg IN VARCHAR2
|
||||
, p_disc_key IN NUMBER DEFAULT NULL
|
||||
, p_prj_key IN NUMBER DEFAULT NULL
|
||||
, p_rub_key IN NUMBER DEFAULT NULL
|
||||
, p_grp_key IN NUMBER DEFAULT NULL
|
||||
, p_srt_key IN NUMBER DEFAULT NULL
|
||||
, p_bgt_key IN NUMBER DEFAULT NULL
|
||||
, p_mut_key IN NUMBER DEFAULT NULL
|
||||
, p_opdr_key IN NUMBER DEFAULT NULL
|
||||
, p_fact_key IN NUMBER DEFAULT NULL
|
||||
, p_bedr_key IN NUMBER DEFAULT NULL
|
||||
, p_kpls_key IN NUMBER DEFAULT NULL
|
||||
, p_kgrp_key IN NUMBER DEFAULT NULL
|
||||
)
|
||||
AS
|
||||
v_volgnr NUMBER(10);
|
||||
BEGIN
|
||||
SELECT COALESCE(MAX(volgnr), 0) + 1
|
||||
INTO v_volgnr
|
||||
FROM twyn_bgtlog;
|
||||
--
|
||||
INSERT INTO twyn_bgtlog VALUES
|
||||
( v_volgnr
|
||||
, p_actie
|
||||
, p_level
|
||||
, SYSDATE
|
||||
, p_msg
|
||||
, p_disc_key, p_prj_key, p_rub_key, p_grp_key, p_srt_key
|
||||
, p_bgt_key, p_mut_key
|
||||
, p_opdr_key, p_fact_key, p_bedr_key
|
||||
, p_kpls_key, p_kgrp_key
|
||||
);
|
||||
-- COMMIT;
|
||||
END bgtLog;
|
||||
/
|
||||
|
||||
--
|
||||
--
|
||||
--
|
||||
CREATE OR REPLACE PROCEDURE twyn_delete_deelproject ( p_deelproject_key IN NUMBER
|
||||
, p_alleen_fin IN BOOLEAN DEFAULT FALSE
|
||||
)
|
||||
AS
|
||||
-- Verwijder het deelproject met bgt_project_key = n.
|
||||
-- Met parameter p_alleen_fin worden alleen de budget- en contractgegevens verwijderd.
|
||||
-- Default is het hele deelproject verwijderen, dus ook koststenplaatsen, kosten- rubriek, soortgrp en soort.
|
||||
v_delete_str VARCHAR2 (100) := 'DELETE prj=' || TO_CHAR(p_deelproject_key);
|
||||
|
||||
|
||||
PROCEDURE log_info( p_code IN VARCHAR2 DEFAULT NULL
|
||||
, p_msg IN VARCHAR2 DEFAULT NULL
|
||||
, p_prj_key IN NUMBER DEFAULT NULL
|
||||
, p_rub_key IN NUMBER DEFAULT NULL
|
||||
, p_grp_key IN NUMBER DEFAULT NULL
|
||||
, p_srt_key IN NUMBER DEFAULT NULL
|
||||
, p_bgt_key IN NUMBER DEFAULT NULL
|
||||
, p_mut_key IN NUMBER DEFAULT NULL
|
||||
, p_opdr_key IN NUMBER DEFAULT NULL
|
||||
, p_fact_key IN NUMBER DEFAULT NULL
|
||||
, p_bedr_key IN NUMBER DEFAULT NULL
|
||||
)
|
||||
AS
|
||||
v_ora_err_num NUMBER;
|
||||
v_ora_err_msg VARCHAR2(200);
|
||||
v_err_msg VARCHAR2(1000);
|
||||
v_msg VARCHAR2(2000);
|
||||
BEGIN
|
||||
IF (p_code IN ('W', 'E')) THEN
|
||||
v_ora_err_num := SQLCODE;
|
||||
v_ora_err_msg := SUBSTR (SQLERRM, 1, 200);
|
||||
v_msg := 'ORACLE (error ' || v_ora_err_num || '/' || v_ora_err_msg || ')';
|
||||
IF (p_msg IS NOT NULL) THEN
|
||||
v_msg := v_msg || ': ' || p_msg;
|
||||
END IF;
|
||||
ELSE
|
||||
v_msg := p_msg;
|
||||
END IF;
|
||||
bgtLog (v_delete_str, p_code, v_msg, NULL, p_prj_key, p_rub_key, p_grp_key, p_srt_key, p_bgt_key, p_mut_key, p_opdr_key, p_fact_key, p_bedr_key);
|
||||
END;
|
||||
|
||||
|
||||
PROCEDURE delete_contracten(p_bgt_project_key IN NUMBER)
|
||||
AS
|
||||
CURSOR c_project_opdr
|
||||
IS
|
||||
SELECT s.prs_kostensoort_key
|
||||
FROM bgt_project p
|
||||
, bgt_kostenrubriek r
|
||||
, prs_kostensoortgrp g
|
||||
, prs_kostensoort s
|
||||
WHERE p.bgt_project_key = r.bgt_project_key
|
||||
AND r.bgt_kostenrubriek_key = g.bgt_kostenrubriek_key
|
||||
AND g.prs_kostensoortgrp_key = s.prs_kostensoortgrp_key
|
||||
AND p.bgt_project_key = p_bgt_project_key;
|
||||
|
||||
CURSOR c_opdracht(p_kostensoort_key IN NUMBER)
|
||||
IS
|
||||
SELECT o.mld_uitvoerende_keys
|
||||
, o.mld_opdr_key
|
||||
FROM mld_opdr o
|
||||
WHERE o.prs_kostensoort_key = p_kostensoort_key;
|
||||
|
||||
iprj NUMBER;
|
||||
iopd NUMBER;
|
||||
ibdr NUMBER;
|
||||
|
||||
PROCEDURE delete_prs_bedrijf( p_project_key IN NUMBER
|
||||
, p_mld_opdr_key IN NUMBER
|
||||
, p_bedrijf_key IN NUMBER
|
||||
)
|
||||
AS
|
||||
i NUMBER;
|
||||
xprj NUMBER;
|
||||
opdr NUMBER;
|
||||
bedr NUMBER;
|
||||
v_aantal_projecten NUMBER;
|
||||
v_aantal_opdrachten NUMBER;
|
||||
BEGIN
|
||||
xprj := p_project_key;
|
||||
opdr := p_mld_opdr_key;
|
||||
bedr := p_bedrijf_key;
|
||||
SELECT COUNT(DISTINCT p.bgt_project_key) aantal_projecten
|
||||
, COUNT(o.mld_opdr_key) aantal_opdrachten
|
||||
INTO v_aantal_projecten
|
||||
, v_aantal_opdrachten
|
||||
FROM bgt_project p
|
||||
, bgt_kostenrubriek r
|
||||
, prs_kostensoortgrp g
|
||||
, prs_kostensoort s
|
||||
, mld_opdr o
|
||||
WHERE p.bgt_project_key = r.bgt_project_key
|
||||
AND r.bgt_kostenrubriek_key = g.bgt_kostenrubriek_key
|
||||
AND g.prs_kostensoortgrp_key = s.prs_kostensoortgrp_key
|
||||
AND s.prs_kostensoort_key = o.prs_kostensoort_key
|
||||
AND o.mld_uitvoerende_keys = p_bedrijf_key;
|
||||
--
|
||||
-- Om een bedrijf die alleen in het project gebruikt wordt te kunnen verwijderen
|
||||
-- mogen er geen referenties meer bestaan.
|
||||
BEGIN
|
||||
UPDATE mld_opdr
|
||||
SET mld_uitvoerende_keys = NULL
|
||||
WHERE mld_opdr_key = p_mld_opdr_key;
|
||||
--
|
||||
IF (v_aantal_projecten = 1 AND v_aantal_opdrachten = 1) THEN
|
||||
-- bedrijf wordt alleen in het huidige project
|
||||
-- en in de huidige contract gebruikt, dus kan verwijderd worden.
|
||||
DELETE
|
||||
FROM prs_bedrijf
|
||||
WHERE prs_bedrijf_key = p_bedrijf_key;
|
||||
--
|
||||
log_info('I', 'Bedrijf verwijderd'
|
||||
, xprj, NULL, NULL, NULL, NULL, NULL, opdr, NULL, bedr
|
||||
);
|
||||
END IF;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, xprj, NULL, NULL, NULL, NULL, NULL, opdr, NULL, bedr);
|
||||
-- xmsg, xprj, xrub, xgrp, xsrt, xbgt, xmut, opdr, fact, bedr
|
||||
END;
|
||||
END;
|
||||
|
||||
PROCEDURE delete_fin_factuur( p_project_key IN NUMBER
|
||||
, p_mld_opdr_key IN NUMBER)
|
||||
AS
|
||||
i NUMBER;
|
||||
xprj NUMBER;
|
||||
opdr NUMBER;
|
||||
BEGIN
|
||||
xprj := p_project_key;
|
||||
opdr := p_mld_opdr_key;
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM fin_factuur
|
||||
WHERE mld_opdr_key = p_mld_opdr_key;
|
||||
--
|
||||
i := sql%rowcount;
|
||||
log_info( 'I', 'Aantal facturen verwijderd: ' || TO_CHAR(i)
|
||||
, xprj, NULL, NULL, NULL, NULL, NULL, opdr
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, xprj, NULL, NULL, NULL, NULL, NULL, opdr);
|
||||
-- xmsg, xprj, xrub, xgrp, xsrt, xbgt, xmut, opdr, fact, bedr
|
||||
END;
|
||||
END;
|
||||
|
||||
PROCEDURE delete_fin_factuur_onbekend(p_project_key IN NUMBER)
|
||||
AS
|
||||
i NUMBER;
|
||||
BEGIN
|
||||
-- Factuur verwijst naar een kostensoort binnen het te verwijderen project,
|
||||
-- maar is niet via de mld_opdr verwijderd.
|
||||
DELETE
|
||||
FROM fin_factuur
|
||||
WHERE prs_kostensoort_key IN
|
||||
(SELECT s.prs_kostensoort_key
|
||||
FROM prs_kostensoort s
|
||||
, prs_kostensoortgrp g
|
||||
, bgt_kostenrubriek r
|
||||
WHERE s.prs_kostensoortgrp_key = g.prs_kostensoortgrp_key
|
||||
AND g.bgt_kostenrubriek_key = r.bgt_kostenrubriek_key
|
||||
AND r.bgt_project_key = p_project_key
|
||||
);
|
||||
--
|
||||
i := sql%rowcount;
|
||||
log_info( 'I', 'Aantal facturen alleen aan kostensoort gebonden verwijderd: ' || TO_CHAR(i)
|
||||
, p_project_key
|
||||
);
|
||||
END;
|
||||
|
||||
PROCEDURE delete_mld_opdr( p_project_key IN NUMBER
|
||||
, p_mld_opdr_key IN NUMBER)
|
||||
AS
|
||||
xprj NUMBER;
|
||||
opdr NUMBER;
|
||||
BEGIN
|
||||
xprj := p_project_key;
|
||||
opdr := p_mld_opdr_key;
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM mld_opdr
|
||||
WHERE mld_opdr_key = p_mld_opdr_key;
|
||||
--
|
||||
log_info('I', 'Opdracht verwijderd'
|
||||
, xprj, NULL, NULL, NULL, NULL, NULL, opdr
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, xprj, NULL, NULL, NULL, NULL, NULL, opdr);
|
||||
-- xmsg, xprj, xrub, xgrp, xsrt, xbgt, xmut, opdr, fact, bedr
|
||||
END;
|
||||
END;
|
||||
|
||||
BEGIN -- delete_contracten
|
||||
iprj := p_bgt_project_key;
|
||||
log_info('I', 'Bedrijven, facturen en contracten:');
|
||||
BEGIN
|
||||
FOR l_prj IN c_project_opdr
|
||||
LOOP
|
||||
FOR l_opdr IN c_opdracht(l_prj.prs_kostensoort_key)
|
||||
LOOP
|
||||
iopd := l_opdr.mld_opdr_key;
|
||||
ibdr := l_opdr.mld_uitvoerende_keys;
|
||||
delete_prs_bedrijf (p_bgt_project_key, l_opdr.mld_opdr_key, l_opdr.mld_uitvoerende_keys);
|
||||
delete_fin_factuur (p_bgt_project_key, l_opdr.mld_opdr_key);
|
||||
delete_mld_opdr (p_bgt_project_key, l_opdr.mld_opdr_key);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
delete_fin_factuur_onbekend(p_bgt_project_key);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, iprj, NULL, NULL, NULL, NULL, NULL, iopd, NULL, ibdr);
|
||||
-- xmsg, iprj, irub, igrp, isrt, ibgt, imut, iopd, ifac, ibdr
|
||||
END;
|
||||
END; -- delete_contracten
|
||||
|
||||
|
||||
PROCEDURE delete_budgetten(p_bgt_project_key IN NUMBER)
|
||||
AS
|
||||
CURSOR c_project_bud
|
||||
IS
|
||||
SELECT r.bgt_kostenrubriek_key
|
||||
, g.prs_kostensoortgrp_key
|
||||
, s.prs_kostensoort_key
|
||||
FROM bgt_project p
|
||||
, bgt_kostenrubriek r
|
||||
, prs_kostensoortgrp g
|
||||
, prs_kostensoort s
|
||||
WHERE p.bgt_project_key = r.bgt_project_key
|
||||
AND r.bgt_kostenrubriek_key = g.bgt_kostenrubriek_key(+)
|
||||
AND g.prs_kostensoortgrp_key = s.prs_kostensoortgrp_key(+)
|
||||
AND p.bgt_project_key = p_bgt_project_key;
|
||||
|
||||
iprj NUMBER;
|
||||
irub NUMBER;
|
||||
igrp NUMBER;
|
||||
isrt NUMBER;
|
||||
v_budget_key NUMBER;
|
||||
|
||||
|
||||
FUNCTION get_budget_key( p_prj_key IN NUMBER
|
||||
, p_rub_key IN NUMBER
|
||||
, p_grp_key IN NUMBER
|
||||
, p_srt_key IN NUMBER
|
||||
) RETURN NUMBER
|
||||
AS
|
||||
v_bgt_key NUMBER;
|
||||
BEGIN
|
||||
BEGIN
|
||||
SELECT bgt_budget_key
|
||||
INTO v_bgt_key
|
||||
FROM bgt_budget
|
||||
WHERE bgt_project_key = p_prj_key
|
||||
AND ( (bgt_kostenrubriek_key = p_rub_key AND p_srt_key IS NULL AND p_grp_key IS NULL AND p_rub_key IS NOT NULL)
|
||||
OR (prs_kostensoortgrp_key = p_grp_key AND p_srt_key IS NULL AND p_grp_key IS NOT NULL)
|
||||
OR (prs_kostensoort_key = p_srt_key AND p_srt_key IS NOT NULL)
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN v_bgt_key := -1;
|
||||
END;
|
||||
RETURN v_bgt_key;
|
||||
END;
|
||||
|
||||
PROCEDURE delete_mutaties( p_project_key IN NUMBER
|
||||
, p_budget_key IN NUMBER
|
||||
)
|
||||
AS
|
||||
i NUMBER;
|
||||
xprj NUMBER;
|
||||
xbgt NUMBER;
|
||||
BEGIN
|
||||
xprj := p_project_key;
|
||||
xbgt := p_budget_key;
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM bgt_budgetmutatie
|
||||
WHERE bgt_budget_key_van = p_budget_key
|
||||
OR bgt_budget_key_naar = p_budget_key;
|
||||
--
|
||||
i := sql%rowcount;
|
||||
log_info('I', 'Aantal budgetmutaties verwijderd: ' || TO_CHAR(i)
|
||||
, xprj, NULL, NULL, NULL, xbgt
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, xprj, NULL, NULL, NULL, xbgt);
|
||||
-- xmsg, xprj, xrub, xgrp, xsrt, xbgt, xmut, opdr, fact, bedr
|
||||
END;
|
||||
END;
|
||||
|
||||
PROCEDURE delete_budget( p_project_key IN NUMBER
|
||||
, p_budget_key IN NUMBER
|
||||
)
|
||||
AS
|
||||
xprj NUMBER;
|
||||
xbgt NUMBER;
|
||||
BEGIN
|
||||
xprj := p_project_key;
|
||||
xbgt := p_budget_key;
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM bgt_budget
|
||||
WHERE bgt_budget_key = p_budget_key;
|
||||
--
|
||||
log_info('I', 'Budget verwijderd'
|
||||
, xprj, NULL, NULL, NULL, xbgt
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, xprj, NULL, NULL, NULL, xbgt);
|
||||
-- xmsg, xprj, xrub, xgrp, xsrt, xbgt, xmut, opdr, fact, bedr
|
||||
END;
|
||||
END;
|
||||
|
||||
BEGIN -- delete_budgetten
|
||||
log_info('I', 'Budgetmutaties en budgetten:');
|
||||
FOR l_prj IN c_project_bud
|
||||
LOOP
|
||||
iprj := p_bgt_project_key;
|
||||
irub := l_prj.bgt_kostenrubriek_key;
|
||||
igrp := l_prj.prs_kostensoortgrp_key;
|
||||
isrt := l_prj.prs_kostensoort_key;
|
||||
BEGIN
|
||||
v_budget_key := get_budget_key(iprj, irub, igrp, isrt);
|
||||
IF (v_budget_key > -1) THEN
|
||||
delete_mutaties(iprj, v_budget_key);
|
||||
delete_budget (iprj, v_budget_key);
|
||||
END IF;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, iprj, irub, igrp, isrt, v_budget_key);
|
||||
-- xmsg, iprj, irub, igrp, isrt, ibgt, imut, iopd, ifac, ibdr
|
||||
END;
|
||||
END LOOP;
|
||||
END; -- delete_budgetten
|
||||
|
||||
PROCEDURE delete_kostenplaatsen(p_bgt_project_key IN NUMBER)
|
||||
AS
|
||||
CURSOR c_kostenplaats(p_kpgrp_key In NUMBER)
|
||||
IS
|
||||
SELECT prs_kostenplaats_key
|
||||
FROM prs_kostenplaats
|
||||
WHERE prs_kostenplaatsgrp_key = p_kpgrp_key;
|
||||
|
||||
iprj NUMBER;
|
||||
iopd NUMBER;
|
||||
ibdr NUMBER;
|
||||
v_kpgrp_key NUMBER;
|
||||
i NUMBER;
|
||||
BEGIN -- delete_kostenplaatsen
|
||||
iprj := p_bgt_project_key;
|
||||
log_info('I', 'Kostenplaatsen en kostenplaatsgroep:');
|
||||
-- Eerst even wat referenties verwijderen.
|
||||
UPDATE bgt_project
|
||||
SET prs_kostenplaats_key = NULL
|
||||
WHERE bgt_project_key = p_bgt_project_key;
|
||||
--
|
||||
UPDATE prs_kostensoort
|
||||
SET prs_kostenplaats_key = NULL
|
||||
WHERE prs_kostensoort_key IN
|
||||
(SELECT s.prs_kostensoort_key
|
||||
FROM prs_kostensoort s
|
||||
, prs_kostensoortgrp g
|
||||
, bgt_kostenrubriek r
|
||||
WHERE s.prs_kostensoortgrp_key = g.prs_kostensoortgrp_key
|
||||
AND g.bgt_kostenrubriek_key = r.bgt_kostenrubriek_key
|
||||
AND r.bgt_project_key = p_bgt_project_key
|
||||
);
|
||||
--
|
||||
BEGIN
|
||||
SELECT g.prs_kostenplaatsgrp_key
|
||||
INTO v_kpgrp_key
|
||||
FROM prs_kostenplaatsgrp g
|
||||
WHERE g.bgt_project_key = p_bgt_project_key;
|
||||
--
|
||||
-- Foutieve verwijzingen verwijderen.
|
||||
-- (vanuit een ander deelproject wordt naar een kostenplaats verwezen die hier verwijderd wordt.)
|
||||
UPDATE mld_opdr
|
||||
SET prs_kostenplaats_key = NULL
|
||||
WHERE prs_kostenplaats_key IN
|
||||
(SELECT kp.prs_kostenplaats_key
|
||||
FROM prs_kostenplaats kp
|
||||
WHERE kp.prs_kostenplaatsgrp_key = v_kpgrp_key
|
||||
);
|
||||
--
|
||||
UPDATE bgt_budget
|
||||
SET prs_kostenplaats_key = NULL
|
||||
WHERE prs_kostenplaats_key IN
|
||||
(SELECT kp.prs_kostenplaats_key
|
||||
FROM prs_kostenplaats kp
|
||||
WHERE kp.prs_kostenplaatsgrp_key = v_kpgrp_key
|
||||
);
|
||||
--
|
||||
-- kostenplaatsen van dit project verwijderen
|
||||
DELETE
|
||||
FROM prs_kostenplaats
|
||||
WHERE prs_kostenplaatsgrp_key = v_kpgrp_key;
|
||||
--
|
||||
i := sql%rowcount;
|
||||
log_info('I', 'Aantal kostenplaatsen verwijderd: ' || TO_CHAR(i)
|
||||
, iprj
|
||||
);
|
||||
-- kostenplaatsgroep van dit project verwijderen
|
||||
DELETE
|
||||
FROM prs_kostenplaatsgrp
|
||||
WHERE prs_kostenplaatsgrp_key = v_kpgrp_key;
|
||||
log_info('I', 'Kostenplaatsgroep verwijderd: ' || TO_CHAR(v_kpgrp_key)
|
||||
, iprj
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN log_info('I', 'Geen kostenplaatsgroep aanwezig.');
|
||||
WHEN OTHERS THEN log_info('W', NULL, iprj, NULL, NULL, NULL, NULL);
|
||||
-- xmsg, iprj, irub, igrp, isrt, ibgt, imut, iopd, ifac, ibdr
|
||||
|
||||
END;
|
||||
END; -- delete_kostenplaatsen
|
||||
|
||||
PROCEDURE delete_deelproject(p_bgt_project_key IN NUMBER)
|
||||
AS
|
||||
i NUMBER;
|
||||
BEGIN -- delete_deelproject
|
||||
log_info('I', 'Kostensoort, kostensoortgroep, kostenrubriek en project:');
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM prs_kostensoort
|
||||
WHERE prs_kostensoortgrp_key IN
|
||||
(SELECT g.prs_kostensoortgrp_key
|
||||
FROM bgt_kostenrubriek r
|
||||
, prs_kostensoortgrp g
|
||||
WHERE g.bgt_kostenrubriek_key = r.bgt_kostenrubriek_key
|
||||
AND r.bgt_project_key = p_bgt_project_key
|
||||
);
|
||||
i := sql%rowcount;
|
||||
log_info('I', 'Aantal kostensoorten verwijderd: ' || TO_CHAR(i));
|
||||
--
|
||||
DELETE
|
||||
FROM prs_kostensoortgrp
|
||||
WHERE bgt_kostenrubriek_key IN
|
||||
(SELECT r.bgt_kostenrubriek_key
|
||||
FROM bgt_kostenrubriek r
|
||||
WHERE r.bgt_project_key = p_bgt_project_key
|
||||
);
|
||||
i := sql%rowcount;
|
||||
log_info('I', 'Aantal kostensoortgroepen verwijderd: ' || TO_CHAR(i));
|
||||
--
|
||||
DELETE
|
||||
FROM bgt_kostenrubriek
|
||||
WHERE bgt_project_key = p_bgt_project_key;
|
||||
i := sql%rowcount;
|
||||
log_info('I', 'Aantal kostenrubrieken verwijderd: ' || TO_CHAR(i));
|
||||
--
|
||||
DELETE
|
||||
FROM bgt_project
|
||||
WHERE bgt_project_key = p_bgt_project_key;
|
||||
--
|
||||
log_info('I', 'Deelproject verwijderd', p_bgt_project_key);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN log_info('W', NULL, p_bgt_project_key);
|
||||
END;
|
||||
END; -- delete_deelproject
|
||||
|
||||
BEGIN
|
||||
log_info('I', 'START');
|
||||
delete_contracten(p_deelproject_key);
|
||||
delete_budgetten(p_deelproject_key);
|
||||
IF (NOT p_alleen_fin) THEN
|
||||
delete_kostenplaatsen(p_deelproject_key);
|
||||
delete_deelproject(p_deelproject_key);
|
||||
END IF;
|
||||
log_info('I', 'EINDE');
|
||||
END;
|
||||
/
|
||||
--
|
||||
--
|
||||
--
|
||||
|
||||
|
||||
|
||||
--=============================================================================
|
||||
-- RAPPORTAGES
|
||||
-------------------------------------------------------------------------------
|
||||
|
||||
@@ -177,6 +177,27 @@ CREATE TABLE twyn_imp_factuur
|
||||
prs_kostensoort_code VARCHAR2(5)
|
||||
);
|
||||
|
||||
CREATE TABLE twyn_bgtlog
|
||||
(
|
||||
volgnr NUMBER(10),
|
||||
actie VARCHAR2(20),
|
||||
loglevel VARCHAR2(3),
|
||||
datum DATE,
|
||||
msg VARCHAR2(2000),
|
||||
disc_key NUMBER(10) DEFAULT NULL,
|
||||
prj_key NUMBER(10) DEFAULT NULL,
|
||||
rub_key NUMBER(10) DEFAULT NULL,
|
||||
grp_key NUMBER(10) DEFAULT NULL,
|
||||
srt_key NUMBER(10) DEFAULT NULL,
|
||||
bgt_key NUMBER(10) DEFAULT NULL,
|
||||
mut_key NUMBER(10) DEFAULT NULL,
|
||||
opdr_key NUMBER(10) DEFAULT NULL,
|
||||
fact_key NUMBER(10) DEFAULT NULL,
|
||||
bedr_key NUMBER(10) DEFAULT NULL,
|
||||
kpls_key NUMBER(10) DEFAULT NULL,
|
||||
kgrp_key NUMBER(10) DEFAULT NULL
|
||||
);
|
||||
|
||||
INSERT INTO fac_menu (fac_menu_volgnr, fac_menu_altgroep, fac_menuitems_key)
|
||||
SELECT 6910, 0, fac_menuitems_key FROM fac_menuitems WHERE fac_menuitems_label = 'lcl_menu_bgt_account';
|
||||
|
||||
|
||||
Reference in New Issue
Block a user