Skip to content

Commit

Permalink
pas view v_bd_app_re_all_kad_perceel aan om te filteren tegen actue…
Browse files Browse the repository at this point in the history
…le appartementsrechten

en voeg upgrade scripts toe
  • Loading branch information
mprins committed Sep 18, 2017
1 parent ecac1ae commit 6a58bd1
Show file tree
Hide file tree
Showing 6 changed files with 71 additions and 6 deletions.
6 changes: 5 additions & 1 deletion datamodel/extra_scripts/oracle/105_appartements_rechten.sql
Original file line number Diff line number Diff line change
Expand Up @@ -78,11 +78,15 @@ CREATE OR REPLACE VIEW v_bd_app_re_3_kad_perceel AS
GROUP BY vaa.app_re_identif, vap.perceel_identif;

CREATE OR REPLACE VIEW v_bd_app_re_all_kad_perceel AS
select to_char(re.sc_kad_identif) as app_re_identif, rar.perceel_identif from (
select * from v_bd_app_re_kad_perceel
union
select * from v_bd_app_re_2_kad_perceel
union
select * from v_bd_app_re_3_kad_perceel;
select * from v_bd_app_re_3_kad_perceel
) rar
left join app_re re
on to_char(re.sc_kad_identif) = rar.app_re_identif;

-- view om appartementsrechten bij percelen op te zoeken
CREATE OR REPLACE VIEW v_bd_app_re_bij_perceel AS
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -8,8 +8,9 @@ CREATE OR REPLACE VIEW v_bd_app_re_app_re AS
WHERE (b2.omschrijving = 'betrokkenBij Ondersplitsing' OR b2.omschrijving = 'ontstaanUit HoofdSplitsing') AND b1.omschrijving = 'ontstaanUit Ondersplitsing'
GROUP BY b1.ref_id, b2.ref_id;

-- recursieve query om alle appartementsrechten te vinden bij percelen
-- recursieve query om alle actuele appartementsrechten te vinden bij percelen
CREATE OR REPLACE VIEW v_bd_app_re_all_kad_perceel AS

with recursive related_app_re (app_re_identif, perceel_identif) as (
SELECT b1.ref_id AS app_re_identif,
b2.ref_id AS perceel_identif
Expand All @@ -29,8 +30,10 @@ union
)

select
rar.*
from related_app_re rar;
app_re.sc_kad_identif::varchar(50) as app_re_identif, rar.perceel_identif
from related_app_re rar
left join app_re
on app_re.sc_kad_identif::text = rar.app_re_identif;


-- Haalt alle percelen ids op met 1 of meer app_re (dient als basis voor de view voor de kaart)
Expand Down
11 changes: 9 additions & 2 deletions datamodel/extra_scripts/sqlserver/105_appartements_rechten.sql
Original file line number Diff line number Diff line change
Expand Up @@ -98,12 +98,19 @@ CREATE VIEW v_bd_app_re_3_kad_perceel AS
GO

CREATE VIEW v_bd_app_re_all_kad_perceel AS

SELECT
CAST(re.sc_kad_identif AS VARCHAR(50)) AS app_re_identif,
rar.perceel_identif
from (
select * from v_bd_app_re_kad_perceel
union
select * from v_bd_app_re_2_kad_perceel
union
select * from v_bd_app_re_3_kad_perceel;
select * from v_bd_app_re_3_kad_perceel
) rar
left join app_re re
on re.sc_kad_identif = rar.app_re_identif;


-- view om appartementsrechten bij percelen op te zoeken
GO
Expand Down
12 changes: 12 additions & 0 deletions datamodel/upgrade_scripts/1.4.5-1.5.0/oracle/rsgb.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,18 @@
-- upgrade Oracle RSGB datamodel van 1.4.5 naar 1.5.0
--

-- pas view v_bd_app_re_all_kad_perceel aan om te filteren tegen actuele appartementsrechten issue#331
CREATE OR REPLACE VIEW v_bd_app_re_all_kad_perceel AS
select to_char(re.sc_kad_identif) as app_re_identif, rar.perceel_identif from (
select * from v_bd_app_re_kad_perceel
union
select * from v_bd_app_re_2_kad_perceel
union
select * from v_bd_app_re_3_kad_perceel
) rar
left join app_re re
on to_char(re.sc_kad_identif) = rar.app_re_identif;


-- onderstaande dienen als laatste stappen van een upgrade uitgevoerd
INSERT INTO brmo_metadata (naam,waarde) SELECT 'upgrade_1.4.5_naar_1.5.0','vorige versie was '||waarde FROM brmo_metadata WHERE naam='brmoversie';
Expand Down
23 changes: 23 additions & 0 deletions datamodel/upgrade_scripts/1.4.5-1.5.0/postgresql/rsgb.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,29 @@
-- upgrade PostgreSQL RSGB datamodel van 1.4.5 naar 1.5.0
--

-- pas view v_bd_app_re_all_kad_perceel aan om te filteren tegen actuele appartementsrechten issue#331
CREATE OR REPLACE VIEW v_bd_app_re_all_kad_perceel AS
WITH recursive related_app_re (
app_re_identif, perceel_identif
) AS (
SELECT b1.ref_id AS app_re_identif, b2.ref_id AS perceel_identif
FROM brondocument b1
JOIN brondocument b2
ON b2.identificatie = b1.identificatie
WHERE b2.omschrijving = 'betrokkenBij HoofdSplitsing'
AND (b1.omschrijving = 'ontstaanUit HoofdSplitsing' OR b1.omschrijving = 'ontstaanUit Ondersplitsing')
GROUP BY b1.ref_id, b2.ref_id
UNION
SELECT vaa.app_re_identif, vap.perceel_identif
FROM v_bd_app_re_app_re vaa
JOIN related_app_re vap
ON vaa.parent_app_re_identif = vap.app_re_identif
GROUP BY vaa.app_re_identif, vap.perceel_identif
)
SELECT app_re.sc_kad_identif::VARCHAR(50) AS app_re_identif, rar.perceel_identif
FROM related_app_re rar
LEFT JOIN app_re
ON app_re.sc_kad_identif::text = rar.app_re_identif;

-- onderstaande dienen als laatste stappen van een upgrade uitgevoerd
INSERT INTO brmo_metadata (naam,waarde) SELECT 'upgrade_1.4.5_naar_1.5.0','vorige versie was '||waarde FROM brmo_metadata WHERE naam='brmoversie';
Expand Down
16 changes: 16 additions & 0 deletions datamodel/upgrade_scripts/1.4.5-1.5.0/sqlserver/rsgb.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,22 @@
-- upgrade SQLserver RSGB datamodel van 1.4.5 naar 1.5.0
--

-- pas view v_bd_app_re_all_kad_perceel aan om te filteren tegen actuele appartementsrechten issue#331
ALTER VIEW v_bd_app_re_all_kad_perceel AS
SELECT
CAST(re.sc_kad_identif AS VARCHAR(50)) AS app_re_identif,
rar.perceel_identif
FROM
(
SELECT * FROM v_bd_app_re_kad_perceel
UNION
SELECT * FROM v_bd_app_re_2_kad_perceel
UNION
SELECT * FROM v_bd_app_re_3_kad_perceel
) rar
LEFT JOIN app_re re
ON re.sc_kad_identif = rar.app_re_identif;


-- onderstaande dienen als laatste stappen van een upgrade uitgevoerd
INSERT INTO brmo_metadata (naam,waarde) SELECT 'upgrade_1.4.5_naar_1.5.0','vorige versie was '||waarde FROM brmo_metadata WHERE naam='brmoversie';
Expand Down

0 comments on commit 6a58bd1

Please sign in to comment.