This repository has been archived by the owner on Jun 15, 2021. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathperformance-vervallen-percelen.txt
59 lines (43 loc) · 2.29 KB
/
performance-vervallen-percelen.txt
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
-- systeem: desktop, 32GB RAM, quad-core 2.8GHz CPU, SSD, postgres 10.9
show shared_buffers;
-- 5GB
-- oudste archief onrrnd. zaak:
SELECT min(datum_einde_geldh) FROM public.kad_onrrnd_zk_archief;
-- 2017-11-01
-- origineel
DEALLOCATE ALL;
DISCARD PLANS;
DISCARD TEMP;
SELECT DISTINCT ON (arch.koz_identif) arch.koz_identif, arch.eind_geldigheid, arch.gemeentecode, arch.sectie, arch.perceelnummer, arch.deelperceelnummer, arch.appartementsindex
FROM mb_kad_onrrnd_zk_archief arch
WHERE '[2019-01-01,2019-06-17]'::DATERANGE @> arch.eind_geldigheid::date
AND arch.koz_identif NOT IN (SELECT kad_identif FROM kad_onrrnd_zk)
ORDER BY arch.koz_identif, arch.eind_geldigheid::date DESC;
-- resultaat (2019-01-01-nu): 11225 rows in 3.6 sec. (PG 9.6: timeout)
-- resultaat (2018-01-01-nu): 37298 rows in 5.2 sec.
-- resultaat (2017-01-01-nu): 42789 rows in 5.6 sec.
-- variant met NOT EXISTS
DEALLOCATE ALL;
DISCARD PLANS;
DISCARD TEMP;
SELECT DISTINCT ON (arch.koz_identif) arch.koz_identif, arch.eind_geldigheid, arch.gemeentecode, arch.sectie, arch.perceelnummer, arch.deelperceelnummer, arch.appartementsindex
FROM mb_kad_onrrnd_zk_archief arch
WHERE '[2019-01-01,2019-06-17]'::DATERANGE @> arch.eind_geldigheid::date
AND NOT EXISTS (SELECT kad_identif FROM kad_onrrnd_zk koz WHERE koz.kad_identif = arch.koz_identif )
ORDER BY arch.koz_identif, arch.eind_geldigheid::date DESC;
-- resultaat (2019-01-01-nu): 11225 rows in 1.4 sec. (PG 9.6: 1.9 sec)
-- resultaat (2018-01-01-nu): 37298 rows in 4.4 sec. (PG 9.6: 4.7 sec)
-- resultaat (2017-01-01-nu): 42789 rows in 4.9 sec. (PG 9.6: 5.6 sec)
-- variant met LEFT OUTER JOIN
DEALLOCATE ALL;
DISCARD PLANS;
DISCARD TEMP;
SELECT DISTINCT ON (arch.koz_identif) arch.koz_identif, arch.eind_geldigheid, arch.gemeentecode, arch.sectie, arch.perceelnummer, arch.deelperceelnummer, arch.appartementsindex
FROM mb_kad_onrrnd_zk_archief arch
LEFT OUTER JOIN kad_onrrnd_zk koz ON arch.koz_identif = koz.kad_identif
WHERE '[2019-01-01,2019-06-17]'::DATERANGE @> arch.eind_geldigheid::date
AND koz.kad_identif IS NULL
ORDER BY arch.koz_identif, arch.eind_geldigheid::date DESC;
-- resultaat (2019-01-01-nu): 11225 rows in 1.5 sec. (PG 9.6: 1.8 sec)
-- resultaat (2018-01-01-nu): 37298 rows in 4.3 sec. (PG 9.6: 4.9 sec)
-- resultaat (2017-01-01-nu): 42789 rows in 4.9 sec. (PG 9.6: 5.6 sec)