UBRH#57120 -- Views voor rapportage op de workflows
svn path=/Customer/trunk/; revision=41846
This commit is contained in:
576
UBRH/ubrh.sql
576
UBRH/ubrh.sql
@@ -511,40 +511,562 @@ AS
|
||||
AND m.mld_melding_datum >=
|
||||
TO_DATE ('01-01-2010', 'DD-MM-YYYY')) x;
|
||||
|
||||
-- Hieronder de views voor de definitieve rapportage voor Contactcentrum - bewaking Flows
|
||||
-- Twee hulpviews
|
||||
-- Twee basisviews - Hoofd + Detail
|
||||
|
||||
-- Hulpview 1 workflows - Route weergave
|
||||
CREATE OR REPLACE VIEW UBRH_V_WORKFLOW_1
|
||||
(
|
||||
MLD_MELDING_START_KEY,
|
||||
TRAJECT_ROUTE
|
||||
)
|
||||
AS
|
||||
SELECT m.mld_melding_start_key,
|
||||
LISTAGG (
|
||||
md.ins_discipline_omschrijving
|
||||
|| '('
|
||||
|| TO_CHAR (m.mld_melding_key)
|
||||
|| ')',
|
||||
' / ')
|
||||
WITHIN GROUP (ORDER BY m.mld_melding_key)
|
||||
AS Route
|
||||
FROM mld_melding m, mld_stdmelding sm, mld_discipline md
|
||||
WHERE m.mld_stdmelding_key = sm.mld_stdmelding_key
|
||||
AND sm.mld_ins_discipline_key = md.ins_discipline_key
|
||||
AND m.mld_melding_datum > SYSDATE - 19
|
||||
AND m.mld_melding_start_key IS NOT NULL
|
||||
AND md.ins_srtdiscipline_key IN (21, 22) -- 21, 22 is info en inkoopaanvraag. 23 is ADR (nog even erbuiten laten...)
|
||||
GROUP BY m.mld_melding_start_key;
|
||||
|
||||
-- Hulpview 2 workflows - Alle informatievelden / kenmerkvelden die in flow gevuld worden
|
||||
CREATE OR REPLACE VIEW UBRH_V_WORKFLOW_2
|
||||
(
|
||||
MLD_MELDING_START_KEY,
|
||||
TRAJECT_TYPE,
|
||||
MLD_MELDING_KEY,
|
||||
MLD_STDMELINDG_KEY,
|
||||
MLD_STDMELDING_OMSCHRIJVING,
|
||||
MLD_MELDING_STATUS,
|
||||
BESTEMD_VOORTEAM,
|
||||
SOORT_TRAJECT,
|
||||
SOORT_TRAJECT_HERZIEN,
|
||||
CONTROLESTAPPEN,
|
||||
WORKFLOW_AFBREKEN,
|
||||
AANGEVRAAGD_VOOR,
|
||||
UITERSTE_DATUM_CONT,
|
||||
KLANTCONTACT_GEHAD,
|
||||
KLANTCONTACT_DATUM,
|
||||
NUMMER_INKOOPAANVRAAGFORM,
|
||||
CONTRACTNR_SYNERGY,
|
||||
ONDERHANDELINGSNR_DIGIINK,
|
||||
ORDERNR_DIGIINK,
|
||||
DATUM_CONTRACTVERSTUURD,
|
||||
DATUM_CONTRACTRETOUR
|
||||
)
|
||||
AS
|
||||
SELECT m.mld_melding_start_key,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21 THEN 'Inkooptraject'
|
||||
WHEN md.ins_srtdiscipline_key = 22 THEN 'Informatietraject'
|
||||
ELSE ''
|
||||
END)
|
||||
AS TrajectType,
|
||||
m.mld_melding_key,
|
||||
sm.mld_stdmelding_key,
|
||||
sm.mld_stdmelding_omschrijving,
|
||||
m.mld_melding_status,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT fu.fac_usrdata_omschr
|
||||
FROM mld_kenmerkmelding mkm,
|
||||
mld_kenmerk k,
|
||||
fac_usrdata fu
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND mkm.mld_kenmerkmelding_waarde =
|
||||
fu.fac_usrdata_key
|
||||
AND k.mld_srtkenmerk_key = 85)
|
||||
WHEN md.ins_srtdiscipline_key = 22
|
||||
THEN
|
||||
(SELECT fu.fac_usrdata_omschr
|
||||
FROM mld_kenmerkmelding mkm,
|
||||
mld_kenmerk k,
|
||||
fac_usrdata fu
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND mkm.mld_kenmerkmelding_waarde =
|
||||
fu.fac_usrdata_key
|
||||
AND k.mld_srtkenmerk_key = 66)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS BestemdVoorTeam, -- 'Bestemd voor uitvoeringsteam (INK / INF)'
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT fu.fac_usrdata_omschr
|
||||
FROM mld_kenmerkmelding mkm,
|
||||
mld_kenmerk k,
|
||||
fac_usrdata fu
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND mkm.mld_kenmerkmelding_waarde =
|
||||
fu.fac_usrdata_key
|
||||
AND k.mld_srtkenmerk_key = 86)
|
||||
WHEN md.ins_srtdiscipline_key = 22
|
||||
THEN
|
||||
(SELECT fu.fac_usrdata_omschr
|
||||
FROM mld_kenmerkmelding mkm,
|
||||
mld_kenmerk k,
|
||||
fac_usrdata fu
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND mkm.mld_kenmerkmelding_waarde =
|
||||
fu.fac_usrdata_key
|
||||
AND k.mld_srtkenmerk_key = 67)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS SoortTrajectOfVraag, -- 'Soort inkooptraject / Soort informatievraag'
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 161)
|
||||
WHEN md.ins_srtdiscipline_key = 22
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 74)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS SoortTraject_Herzien, -- 'Soort inkoop/informatietraject (herzien)'
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT fu.fac_usrdata_omschr
|
||||
FROM mld_kenmerkmelding mkm,
|
||||
mld_kenmerk k,
|
||||
fac_usrdata fu
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND mkm.mld_kenmerkmelding_waarde =
|
||||
fu.fac_usrdata_key
|
||||
AND k.mld_srtkenmerk_key = 87)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS ControleStappen, -- 'Controlestappen Workflow'
|
||||
(SELECT fu.fac_usrdata_omschr
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k, fac_usrdata fu
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND mkm.mld_kenmerkmelding_waarde = fu.fac_usrdata_key
|
||||
AND k.mld_srtkenmerk_key = 62)
|
||||
AS WorkflowAfbreken, -- 'Workflow stoppen'
|
||||
(SELECT afd.prs_afdeling_keuzelijst
|
||||
FROM mld_kenmerkmelding mkm,
|
||||
mld_kenmerk k,
|
||||
UBRH_V_AFDELINGKIEZEN afd
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 68
|
||||
AND fac.safe_to_number (mkm.mld_kenmerkmelding_waarde) =
|
||||
afd.prs_afdeling_key)
|
||||
AS VoorWieAangevraagd, -- 'Voor wie aangevraagd'
|
||||
(SELECT TO_DATE (mkm.mld_kenmerkmelding_waarde, 'dd-mm-yyyy')
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 69)
|
||||
AS UitersteDatumContactKlant,
|
||||
(CASE
|
||||
WHEN (SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 100) =
|
||||
1
|
||||
THEN
|
||||
'Ja'
|
||||
ELSE
|
||||
'Nee'
|
||||
END)
|
||||
AS KlantcontactGehad,
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 101)
|
||||
AS Klantcontact_Datum,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 88)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS NummerInkoopaanvraagformulier,
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 65)
|
||||
AS Contractnr_Synergynr,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 90)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS Onderhandelingsnr_DigiInk,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 181)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS Ordernr_DigiInk,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 104)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS Datum_ContractVerstuurd,
|
||||
(CASE
|
||||
WHEN md.ins_srtdiscipline_key = 21
|
||||
THEN
|
||||
(SELECT mkm.mld_kenmerkmelding_waarde
|
||||
FROM mld_kenmerkmelding mkm, mld_kenmerk k
|
||||
WHERE mkm.mld_melding_key = m.mld_melding_key
|
||||
AND mkm.mld_kenmerk_key = k.mld_kenmerk_key
|
||||
AND k.mld_srtkenmerk_key = 105)
|
||||
ELSE
|
||||
'nvt'
|
||||
END)
|
||||
AS Datum_ContractRetour
|
||||
FROM mld_melding m,
|
||||
mld_stdmelding sm,
|
||||
mld_discipline md,
|
||||
( SELECT MAX (mm.mld_melding_key) max_key, mm.mld_melding_start_key
|
||||
FROM mld_melding mm
|
||||
GROUP BY mm.mld_melding_start_key) sub
|
||||
WHERE m.mld_stdmelding_key = sm.mld_stdmelding_key
|
||||
AND sm.mld_ins_discipline_key = md.ins_discipline_key
|
||||
-- AND m.mld_melding_datum > TO_DATE (sysdate-19)
|
||||
AND m.mld_melding_start_key IS NOT NULL
|
||||
AND md.ins_srtdiscipline_key IN (21, 22)
|
||||
AND sm.mld_stdmelding_key NOT IN (124) -- Uitsluiten DigiInkoop ivm parallel
|
||||
AND m.mld_melding_start_key = sub.mld_melding_start_key
|
||||
AND m.mld_melding_key = sub.max_key
|
||||
AND m.mld_melding_start_key > 54051
|
||||
ORDER BY m.mld_melding_start_key;
|
||||
|
||||
-- Basisview Workflows - De hoofdview met per traject 1 totaalregel
|
||||
CREATE OR REPLACE VIEW UBRH_V_WORKFLOW_HOOFD
|
||||
(
|
||||
TRAJECT_NR,
|
||||
TRAJECT_TYPE,
|
||||
DATUM_INVOER,
|
||||
INGEVOERD_DOOR,
|
||||
AANVRAGER,
|
||||
DEPARTEMENT_KP,
|
||||
AANGEVRAAGD_VOOR,
|
||||
ONDERWERP,
|
||||
OMSCHRIJVING,
|
||||
BESTEMD_VOORTEAM,
|
||||
SOORT_TRAJECT,
|
||||
CONTROLESTAPPEN,
|
||||
KLANTCONT_UITERLIJK,
|
||||
KLANTCONT_GEHAD,
|
||||
KLANTCONT_DATUM,
|
||||
CONTROLE_1,
|
||||
CONTROLE_2,
|
||||
TRAJECT_STATUS,
|
||||
TRAJECT_ROUTE,
|
||||
TRAJECT_STREEDATUMGEREED,
|
||||
TRAJECT_DATUMGEREED,
|
||||
DOORLOOPTIJD_WERKDAGEN
|
||||
)
|
||||
AS
|
||||
SELECT m.mld_melding_key
|
||||
AS Traject_Nummer,
|
||||
sd.ins_srtdiscipline_omschrijving
|
||||
AS Type_aanvraag,
|
||||
m.mld_melding_datum
|
||||
AS Datum_Invoer,
|
||||
(SELECT pp.prs_perslid_naam
|
||||
FROM fac_tracking ft, prs_perslid pp
|
||||
WHERE m.mld_melding_key = ft.fac_tracking_refkey
|
||||
AND ft.fac_srtnotificatie_key = 49 -- MLDNEW
|
||||
AND ft.prs_perslid_key = pp.prs_perslid_key)
|
||||
AS IngevoerdDoor,
|
||||
(SELECT pp.prs_perslid_naam
|
||||
FROM prs_perslid pp
|
||||
WHERE pp.prs_perslid_key = m.prs_perslid_key)
|
||||
AS Aanvrager,
|
||||
(SELECT pk.prs_kostenplaats_omschrijving
|
||||
FROM prs_kostenplaats pk
|
||||
WHERE m.prs_kostenplaats_key = pk.prs_kostenplaats_key)
|
||||
AS Departement_KP,
|
||||
w2.aangevraagd_voor
|
||||
AS AangevraagdVoor,
|
||||
m.mld_melding_onderwerp
|
||||
AS Onderwerp,
|
||||
m.mld_melding_omschrijving
|
||||
AS Omschrijving,
|
||||
w2.bestemd_voorteam
|
||||
AS BestemdVoorTeam,
|
||||
w2.soort_traject
|
||||
AS SoortTrajectVraag,
|
||||
w2.controlestappen
|
||||
AS ControleStappen,
|
||||
w2.uiterste_datum_cont
|
||||
AS UiterlijkeDatumKlantcontact,
|
||||
w2.klantcontact_gehad
|
||||
AS KlantcontactGehad,
|
||||
w2.klantcontact_datum
|
||||
AS KlantcontactDatum,
|
||||
(CASE
|
||||
WHEN w2.klantcontact_gehad = 'Nee'
|
||||
AND w2.uiterste_datum_cont IS NOT NULL
|
||||
AND (w2.uiterste_datum_cont) > TRUNC (SYSDATE)
|
||||
THEN
|
||||
'Nog binnen termijn'
|
||||
WHEN w2.klantcontact_gehad = 'Nee'
|
||||
AND w2.uiterste_datum_cont IS NOT NULL
|
||||
AND (w2.uiterste_datum_cont) = TRUNC (SYSDATE)
|
||||
THEN
|
||||
'Vandaag doen'
|
||||
WHEN w2.klantcontact_gehad = 'Nee'
|
||||
AND w2.uiterste_datum_cont IS NOT NULL
|
||||
AND (w2.uiterste_datum_cont) < TRUNC (SYSDATE)
|
||||
THEN
|
||||
'Te laat'
|
||||
ELSE
|
||||
''
|
||||
END)
|
||||
AS Controle_Doorlooptijd_1,
|
||||
(CASE
|
||||
WHEN w2.klantcontact_gehad = 'Ja'
|
||||
AND (w2.uiterste_datum_cont) >= (w2.klantcontact_datum)
|
||||
THEN
|
||||
'Doel gehaald'
|
||||
WHEN w2.klantcontact_gehad = 'Ja'
|
||||
AND (w2.uiterste_datum_cont) < (w2.klantcontact_datum)
|
||||
THEN
|
||||
'Doel NIET gehaald'
|
||||
ELSE
|
||||
''
|
||||
END)
|
||||
AS Controle_Doorlooptijd_2,
|
||||
(CASE
|
||||
WHEN m.mld_melding_status = 4
|
||||
AND w2.workflow_afbreken = 'Nee'
|
||||
THEN
|
||||
'Loopt'
|
||||
WHEN m.mld_melding_status = 4
|
||||
AND w2.workflow_afbreken = 'Ja - Afgebroken'
|
||||
THEN
|
||||
'Loopt! - Workflow stoppen staat op Afgebroken. Laatste melding in route nog gereed melden om traject ook echt af te breken'
|
||||
WHEN m.mld_melding_status = 5
|
||||
AND w2.workflow_afbreken = 'Nee'
|
||||
THEN
|
||||
'Gereed'
|
||||
WHEN m.mld_melding_status = 5
|
||||
AND w2.workflow_afbreken = 'Ja - Afgebroken'
|
||||
THEN
|
||||
'Afgebroken'
|
||||
ELSE
|
||||
'Check veld Workflow stoppen!'
|
||||
END)
|
||||
AS Status,
|
||||
w1.traject_route
|
||||
AS RouteTraject,
|
||||
(m.mld_melding_einddatum)
|
||||
AS StreefdatumGereed,
|
||||
(SELECT ft.fac_tracking_datum
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey = m.mld_melding_start_key
|
||||
AND ft.fac_srtnotificatie_key = 44 -- MLDAFM
|
||||
)
|
||||
AS Afmelddatum,
|
||||
(CASE
|
||||
WHEN m.mld_melding_status = 4
|
||||
THEN
|
||||
fac.count_Work_Days (m.mld_melding_datum, SYSDATE)
|
||||
WHEN m.mld_melding_status = 5
|
||||
THEN
|
||||
fac.count_Work_Days (
|
||||
m.mld_melding_datum,
|
||||
(SELECT ft.fac_tracking_datum
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey =
|
||||
m.mld_melding_start_key
|
||||
AND ft.fac_srtnotificatie_key = 44)) -- MLDAFM
|
||||
ELSE
|
||||
0
|
||||
END)
|
||||
AS Doorlooptijd_Werkdagen_TRAJECT
|
||||
FROM mld_melding m,
|
||||
mld_stdmelding sm,
|
||||
mld_discipline md,
|
||||
ins_srtdiscipline sd,
|
||||
UBRH_V_WORKFLOW_1 w1,
|
||||
UBRH_V_WORKFLOW_2 w2
|
||||
WHERE m.mld_melding_key = m.mld_melding_start_key
|
||||
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
|
||||
AND sm.mld_ins_discipline_key = md.ins_discipline_key
|
||||
AND md.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
||||
AND m.mld_melding_start_key = w1.mld_melding_start_key
|
||||
AND m.mld_melding_start_key = w2.mld_melding_start_key
|
||||
AND m.mld_melding_start_key > 54051
|
||||
AND m.mld_melding_start_key IS NOT NULL
|
||||
AND md.ins_srtdiscipline_key IN (21, 22) -- 21, 22 is info en inkoopaanvraag. 23 is ADR
|
||||
;
|
||||
|
||||
-- Basisview Workflows - De detailview met per traject alle aangemaakte meldingen
|
||||
CREATE OR REPLACE VIEW UBRH_V_WORKFLOW_DETAIL
|
||||
(
|
||||
TRAJECT_NR,
|
||||
TRAJECT_TYPE,
|
||||
ONDERWERP,
|
||||
MELDING_NR,
|
||||
MELDING_OMS,
|
||||
MELDING_AANMAAKDATUM,
|
||||
STATUS,
|
||||
DATUM_ACCEPTATIE,
|
||||
BEHANDELAAR,
|
||||
BEHANDELAAR_DATUM,
|
||||
DATUM_GEREED,
|
||||
DOORLOOPTIJD_WERKDAGEN
|
||||
)
|
||||
AS
|
||||
SELECT m.mld_melding_start_key,
|
||||
md.ins_discipline_omschrijving,
|
||||
m.mld_melding_onderwerp
|
||||
AS Onderwerp,
|
||||
m.mld_melding_key,
|
||||
sm.mld_stdmelding_omschrijving,
|
||||
m.mld_melding_datum
|
||||
AS Aanmaakdatum,
|
||||
(CASE
|
||||
WHEN m.mld_melding_status < 4 THEN 'Nog accepteren'
|
||||
WHEN m.mld_melding_status = 4 THEN 'Loopt'
|
||||
WHEN m.mld_melding_status > 4 THEN 'Gereed'
|
||||
ELSE 'Onbekend'
|
||||
END)
|
||||
AS Status,
|
||||
(SELECT ft.fac_tracking_datum
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey = m.mld_melding_key
|
||||
AND ft.fac_srtnotificatie_key = 43 -- MLDACP
|
||||
)
|
||||
AS Acceptatiedatum,
|
||||
(SELECT pp.prs_perslid_naam
|
||||
FROM prs_perslid pp
|
||||
WHERE m.mld_melding_behandelaar_key = pp.prs_perslid_key)
|
||||
AS Behandelaar,
|
||||
(SELECT MAX (ft.fac_tracking_datum)
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey = m.mld_melding_key
|
||||
AND ft.fac_srtnotificatie_key = 57 -- MLDBEH
|
||||
)
|
||||
AS Behandelaar_Datum, -- LAATSTE EBHANDELAARSDATUM
|
||||
(SELECT ft.fac_tracking_datum
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey = m.mld_melding_key
|
||||
AND ft.fac_srtnotificatie_key = 44 -- MLDAFM
|
||||
)
|
||||
AS Afmelddatum,
|
||||
(CASE
|
||||
WHEN m.mld_melding_status = 4
|
||||
THEN
|
||||
fac.count_Work_Days (m.mld_melding_datum, SYSDATE)
|
||||
WHEN m.mld_melding_status = 5
|
||||
THEN
|
||||
fac.count_Work_Days (
|
||||
m.mld_melding_datum,
|
||||
(SELECT ft.fac_tracking_datum
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey =
|
||||
m.mld_melding_key
|
||||
AND ft.fac_srtnotificatie_key = 44)) -- MLDAFM
|
||||
ELSE
|
||||
0
|
||||
END)
|
||||
AS Doorlooptijd_Werkdagen_ACTIE
|
||||
FROM mld_melding m, mld_stdmelding sm, mld_discipline md
|
||||
WHERE m.mld_stdmelding_key = sm.mld_stdmelding_key
|
||||
AND sm.mld_ins_discipline_key = md.ins_discipline_key
|
||||
AND m.mld_melding_start_key > 54051
|
||||
AND m.mld_melding_start_key IS NOT NULL
|
||||
AND md.ins_srtdiscipline_key IN (21, 22) -- 21, 22 is info en inkoopaanvraag. 23 is ADR (nog even erbuiten laten...)
|
||||
ORDER BY m.mld_melding_start_key, m.mld_melding_key ASC;
|
||||
|
||||
|
||||
-- View om bij de meldingen de Afdeling te kunnen kiezen vanuit 1e niveau Ministerie en daaronder de echte afdeling (laagste niveau)
|
||||
|
||||
CREATE OR REPLACE VIEW ubrh_v_afdelingkiezen
|
||||
CREATE OR REPLACE VIEW UBRH_V_AFDELINGKIEZEN
|
||||
(
|
||||
PRS_AFDELING_KEY,
|
||||
PRS_AFDELING_OMSCHRIJVING,
|
||||
PRS_DEPARTEMENT_KEY,
|
||||
PRS_DEPARTEMENT_OMSCHRIJVING,
|
||||
PRS_DEPARTEMENT_CODE,
|
||||
PRS_AFDELING_KEUZELIJST
|
||||
PRS_AFDELING_KEY,
|
||||
PRS_AFDELING_OMSCHRIJVING,
|
||||
PRS_DEPARTEMENT_KEY,
|
||||
PRS_DEPARTEMENT_OMSCHRIJVING,
|
||||
PRS_DEPARTEMENT_CODE,
|
||||
PRS_AFDELING_KEUZELIJST
|
||||
)
|
||||
AS
|
||||
SELECT b.prs_afdeling_key AS Key_EigenAfdeling,
|
||||
(SELECT a.prs_afdeling_omschrijving
|
||||
FROM prs_afdeling a
|
||||
WHERE a.prs_afdeling_key = b.prs_afdeling_key)
|
||||
AS EigenAfdelingsNaam,
|
||||
b.prs_afdeling_key1 AS Key_Departement,
|
||||
a.prs_afdeling_omschrijving AS Naam_Departement,
|
||||
a.prs_afdeling_naam AS Code_Departement,
|
||||
a.prs_afdeling_naam
|
||||
|| ' / '
|
||||
|| (SELECT a.prs_afdeling_omschrijving
|
||||
FROM prs_afdeling a
|
||||
WHERE a.prs_afdeling_key = b.prs_afdeling_key)
|
||||
AS Naam_Keuzelijst
|
||||
FROM prs_v_afdeling_boom b, prs_afdeling a
|
||||
WHERE b.prs_afdeling_key1 = a.prs_afdeling_key
|
||||
AND b.prs_afdeling_key2 IS NOT NULL
|
||||
AND a.prs_afdeling_verwijder IS NULL
|
||||
AND a.prs_afdeling_aanmaak > TO_DATE ('01-12-2018', 'DD-MM-YYYY')
|
||||
ORDER BY Key_EigenAfdeling ASC;
|
||||
SELECT b.prs_afdeling_key
|
||||
AS Key_EigenAfdeling,
|
||||
(SELECT a.prs_afdeling_omschrijving
|
||||
FROM prs_afdeling a
|
||||
WHERE a.prs_afdeling_key = b.prs_afdeling_key)
|
||||
AS EigenAfdelingsNaam,
|
||||
b.prs_afdeling_key1
|
||||
AS Key_Departement,
|
||||
a.prs_afdeling_omschrijving
|
||||
AS Naam_Departement,
|
||||
a.prs_afdeling_naam
|
||||
AS Code_Departement,
|
||||
a.prs_afdeling_naam
|
||||
|| ' / '
|
||||
|| (SELECT a.prs_afdeling_omschrijving
|
||||
FROM prs_afdeling a
|
||||
WHERE a.prs_afdeling_key = b.prs_afdeling_key)
|
||||
AS Naam_Keuzelijst
|
||||
FROM prs_v_afdeling_boom b, prs_afdeling a
|
||||
WHERE b.prs_afdeling_key1 = a.prs_afdeling_key
|
||||
AND a.prs_afdeling_verwijder IS NULL
|
||||
ORDER BY Naam_Keuzelijst ASC;
|
||||
|
||||
|
||||
-- View voor kennisbank, de verantwoordelijke mensen voor vastlegging en onderhoud.
|
||||
|
||||
Reference in New Issue
Block a user