summaryrefslogtreecommitdiffstats
path: root/schema/pgsql/schema.sql
blob: 9027fac52d8a2a0dd0df06d0d6b19f07c85145b7 (plain)
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
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894
1895
1896
1897
1898
1899
1900
1901
1902
1903
1904
1905
1906
1907
1908
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
1924
1925
1926
1927
1928
1929
1930
1931
1932
1933
1934
1935
1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
1954
1955
1956
1957
1958
1959
1960
1961
1962
1963
1964
1965
1966
1967
1968
1969
1970
1971
1972
1973
1974
1975
1976
1977
1978
1979
1980
1981
1982
1983
1984
1985
1986
1987
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
-- Icinga DB | (c) 2021 Icinga GmbH | GPLv2+

-- Postgres in Docker: ensure CITEXT columns are available during schema import. DB user is a superuser and can do this unconditionally.
-- Everything else: assert CITEXT columns are available during schema import. DB user isn't the superuser and can do this only if it's a no-op (`NOTICE:  extension "citext" already exists, skipping`), i.e. if CITEXT columns are already available.
CREATE EXTENSION IF NOT EXISTS citext;

CREATE DOMAIN bytea20 AS bytea CONSTRAINT exactly_20_bytes_long CHECK ( VALUE IS NULL OR octet_length(VALUE) = 20 );
CREATE DOMAIN bytea16 AS bytea CONSTRAINT exactly_16_bytes_long CHECK ( VALUE IS NULL OR octet_length(VALUE) = 16 );
CREATE DOMAIN bytea4 AS bytea CONSTRAINT exactly_4_bytes_long CHECK ( VALUE IS NULL OR octet_length(VALUE) = 4 );

CREATE DOMAIN biguint AS bigint CONSTRAINT positive CHECK ( VALUE IS NULL OR 0 <= VALUE );
CREATE DOMAIN uint AS bigint CONSTRAINT between_0_and_4294967295 CHECK ( VALUE IS NULL OR VALUE BETWEEN 0 AND 4294967295 );
CREATE DOMAIN smalluint AS int CONSTRAINT between_0_and_65535 CHECK ( VALUE IS NULL OR VALUE BETWEEN 0 AND 65535 );
CREATE DOMAIN tinyuint AS smallint CONSTRAINT between_0_and_255 CHECK ( VALUE IS NULL OR VALUE BETWEEN 0 AND 255 );

CREATE TYPE boolenum AS ENUM ( 'n', 'y' );
CREATE TYPE acked AS ENUM ( 'n', 'y', 'sticky' );
CREATE TYPE state_type AS ENUM ( 'hard', 'soft' );
CREATE TYPE checkable_type AS ENUM ( 'host', 'service' );
CREATE TYPE comment_type AS ENUM ( 'comment', 'ack' );
CREATE TYPE notification_type AS ENUM ( 'downtime_start', 'downtime_end', 'downtime_removed', 'custom', 'acknowledgement', 'problem', 'recovery', 'flapping_start', 'flapping_end' );

-- The enum values are ordered in a way that event_type provides a meaningful sort order for history entries with
-- the same event_time. state_change comes first as it can cause many of the other events like trigger downtimes,
-- remove acknowledgements and send notifications. Similarly, notification comes last as any other event can result
-- in a notification. End events sort before the corresponding start events as any ack/comment/downtime/flapping
-- period should last for more than a millisecond, therefore, the old period ends first and then the new one starts.
-- The remaining types are sorted by impact and cause: comments are informative, flapping is automatic and changes
-- mechanics, downtimes are semi-automatic, require user action (or configuration) and change mechanics, acks are pure
-- user actions and change mechanics.
CREATE TYPE history_type AS ENUM ( 'state_change', 'ack_clear', 'downtime_end', 'flapping_end', 'comment_remove', 'comment_add', 'flapping_start', 'downtime_start', 'ack_set', 'notification' );

CREATE OR REPLACE FUNCTION get_sla_ok_percent(
  in_host_id bytea20,
  in_service_id bytea20,
  in_start_time biguint,
  in_end_time biguint
)
RETURNS decimal(7, 4)
LANGUAGE plpgsql
STABLE
PARALLEL RESTRICTED
AS $$
DECLARE
  last_event_time biguint := in_start_time;
  last_hard_state tinyuint;
  active_downtimes uint := 0;
  problem_time biguint := 0;
  total_time biguint;
  row record;
BEGIN
  IF in_end_time <= in_start_time THEN
    RAISE 'end time must be greater than start time';
  END IF;

  total_time := in_end_time - in_start_time;

  -- Use the latest event at or before the beginning of the SLA interval as the initial state.
  SELECT hard_state INTO last_hard_state
  FROM sla_history_state s
  WHERE s.host_id = in_host_id
    AND ((in_service_id IS NULL AND s.service_id IS NULL) OR s.service_id = in_service_id)
    AND s.event_time <= in_start_time
  ORDER BY s.event_time DESC
  LIMIT 1;

  -- If this does not exist, use the previous state from the first event after the beginning of the SLA interval.
  IF last_hard_state IS NULL THEN
    SELECT previous_hard_state INTO last_hard_state
    FROM sla_history_state s
    WHERE s.host_id = in_host_id
      AND ((in_service_id IS NULL AND s.service_id IS NULL) OR s.service_id = in_service_id)
      AND s.event_time > in_start_time
    ORDER BY s.event_time ASC
    LIMIT 1;
  END IF;

  -- If this also does not exist, use the current host/service state.
  IF last_hard_state IS NULL THEN
    IF in_service_id IS NULL THEN
      SELECT hard_state INTO last_hard_state
      FROM host_state s
      WHERE s.host_id = in_host_id;
    ELSE
      SELECT hard_state INTO last_hard_state
      FROM service_state s
      WHERE s.host_id = in_host_id
        AND s.service_id = in_service_id;
    END IF;
  END IF;

  IF last_hard_state IS NULL THEN
    last_hard_state := 0;
  END IF;

  FOR row IN
    (
      -- all downtime_start events before the end of the SLA interval
      -- for downtimes that overlap the SLA interval in any way
      SELECT
        GREATEST(downtime_start, in_start_time) AS event_time,
        'downtime_start' AS event_type,
        1 AS event_prio,
        NULL::tinyuint AS hard_state,
        NULL::tinyuint AS previous_hard_state
      FROM sla_history_downtime d
      WHERE d.host_id = in_host_id
        AND ((in_service_id IS NULL AND d.service_id IS NULL) OR d.service_id = in_service_id)
        AND d.downtime_start < in_end_time
        AND d.downtime_end >= in_start_time
    ) UNION ALL (
      -- all downtime_end events before the end of the SLA interval
      -- for downtimes that overlap the SLA interval in any way
      SELECT
        downtime_end AS event_time,
        'downtime_end' AS event_type,
        2 AS event_prio,
        NULL::tinyuint AS hard_state,
        NULL::tinyuint AS previous_hard_state
      FROM sla_history_downtime d
      WHERE d.host_id = in_host_id
        AND ((in_service_id IS NULL AND d.service_id IS NULL) OR d.service_id = in_service_id)
        AND d.downtime_start < in_end_time
        AND d.downtime_end >= in_start_time
        AND d.downtime_end < in_end_time
    ) UNION ALL (
      -- all state events strictly in interval
      SELECT
        event_time,
        'state_change' AS event_type,
        0 AS event_prio,
        hard_state,
        previous_hard_state
      FROM sla_history_state s
      WHERE s.host_id = in_host_id
        AND ((in_service_id IS NULL AND s.service_id IS NULL) OR s.service_id = in_service_id)
        AND s.event_time > in_start_time
        AND s.event_time < in_end_time
    ) UNION ALL (
      -- end event to keep loop simple, values are not used
      SELECT
        in_end_time AS event_time,
        'end' AS event_type,
        3 AS event_prio,
        NULL::tinyuint AS hard_state,
        NULL::tinyuint AS previous_hard_state
    )
    ORDER BY event_time, event_prio
  LOOP
    IF row.previous_hard_state = 99 THEN
      total_time := total_time - (row.event_time - last_event_time);
    ELSEIF ((in_service_id IS NULL AND last_hard_state > 0) OR (in_service_id IS NOT NULL AND last_hard_state > 1))
      AND last_hard_state != 99
      AND active_downtimes = 0
    THEN
      problem_time := problem_time + row.event_time - last_event_time;
    END IF;

    last_event_time := row.event_time;
    IF row.event_type = 'state_change' THEN
      last_hard_state := row.hard_state;
    ELSEIF row.event_type = 'downtime_start' THEN
      active_downtimes := active_downtimes + 1;
    ELSEIF row.event_type = 'downtime_end' THEN
      active_downtimes := active_downtimes - 1;
    END IF;
  END LOOP;

  RETURN 100 * (total_time - problem_time) / total_time;
END;
$$;

/* At the moment Icinga DB Web doesn't know the column types,
   so it sends SQL queries with LIKE operators for all suggestions in the search bar,
   which fails for numeric and enum types on PostgreSQL.
   To support this, the LIKE operator (internally translated to ~~) is overloaded.
   Note that this is only a temporary solution until Icinga DB Web provides column type support.
 */
CREATE OR REPLACE FUNCTION anynonarrayliketext(anynonarray, text)
  RETURNS bool
  LANGUAGE plpgsql
  IMMUTABLE
  PARALLEL SAFE
  AS $$
    BEGIN
      RETURN $1::TEXT LIKE $2;
    END;
  $$;
CREATE OPERATOR ~~ (LEFTARG=anynonarray, RIGHTARG=text, PROCEDURE=anynonarrayliketext);

CREATE TABLE host (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,

  address varchar(255) NOT NULL,
  address6 varchar(255) NOT NULL,
  address_bin bytea4 DEFAULT NULL,
  address6_bin bytea16 DEFAULT NULL,

  checkcommand_name citext NOT NULL,
  checkcommand_id bytea20 NOT NULL,

  max_check_attempts uint NOT NULL,

  check_timeperiod_name citext NOT NULL,
  check_timeperiod_id bytea20 DEFAULT NULL,

  check_timeout uint DEFAULT NULL,
  check_interval uint NOT NULL,
  check_retry_interval uint NOT NULL,

  active_checks_enabled boolenum NOT NULL DEFAULT 'n',
  passive_checks_enabled boolenum NOT NULL DEFAULT 'n',
  event_handler_enabled boolenum NOT NULL DEFAULT 'n',
  notifications_enabled boolenum NOT NULL DEFAULT 'n',

  flapping_enabled boolenum NOT NULL DEFAULT 'n',
  flapping_threshold_low float NOT NULL,
  flapping_threshold_high float NOT NULL,

  perfdata_enabled boolenum NOT NULL DEFAULT 'n',

  eventcommand_name citext NOT NULL,
  eventcommand_id bytea20 DEFAULT NULL,

  is_volatile boolenum NOT NULL DEFAULT 'n',

  action_url_id bytea20 DEFAULT NULL,
  notes_url_id bytea20 DEFAULT NULL,
  notes text NOT NULL,
  icon_image_id bytea20 DEFAULT NULL,
  icon_image_alt varchar(32) NOT NULL,

  zone_name citext NOT NULL,
  zone_id bytea20 DEFAULT NULL,

  command_endpoint_name citext NOT NULL,
  command_endpoint_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_host PRIMARY KEY (id)
);

ALTER TABLE host ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN address_bin SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN address6_bin SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN checkcommand_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN check_timeperiod_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN eventcommand_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN action_url_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN notes_url_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN icon_image_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN zone_id SET STORAGE PLAIN;
ALTER TABLE host ALTER COLUMN command_endpoint_id SET STORAGE PLAIN;

CREATE INDEX idx_action_url_checksum ON host(action_url_id);
CREATE INDEX idx_notes_url_checksum ON host(notes_url_id);
CREATE INDEX idx_icon_image_checksum ON host(icon_image_id);
CREATE INDEX idx_host_display_name ON host(display_name);
CREATE INDEX idx_host_name_ci ON host(name_ci);
CREATE INDEX idx_host_name ON host(name);

COMMENT ON COLUMN host.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN host.environment_id IS 'environment.id';
COMMENT ON COLUMN host.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN host.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN host.checkcommand_name IS 'checkcommand.name';
COMMENT ON COLUMN host.checkcommand_id IS 'checkcommand.id';
COMMENT ON COLUMN host.check_timeperiod_name IS 'timeperiod.name';
COMMENT ON COLUMN host.check_timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN host.eventcommand_name IS 'eventcommand.name';
COMMENT ON COLUMN host.eventcommand_id IS 'eventcommand.id';
COMMENT ON COLUMN host.action_url_id IS 'action_url.id';
COMMENT ON COLUMN host.notes_url_id IS 'notes_url.id';
COMMENT ON COLUMN host.icon_image_id IS 'icon_image.id';
COMMENT ON COLUMN host.zone_name IS 'zone.name';
COMMENT ON COLUMN host.zone_id IS 'zone.id';
COMMENT ON COLUMN host.command_endpoint_name IS 'endpoint.name';
COMMENT ON COLUMN host.command_endpoint_id IS 'endpoint.id';

COMMENT ON INDEX idx_action_url_checksum IS 'cleanup';
COMMENT ON INDEX idx_notes_url_checksum IS 'cleanup';
COMMENT ON INDEX idx_icon_image_checksum IS 'cleanup';
COMMENT ON INDEX idx_host_display_name IS 'Host list filtered/ordered by display_name';
COMMENT ON INDEX idx_host_name_ci IS 'Host list filtered using quick search';
COMMENT ON INDEX idx_host_name IS 'Host list filtered/ordered by name; Host detail filter';

CREATE TABLE hostgroup (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_hostgroup PRIMARY KEY (id)
);

ALTER TABLE hostgroup ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE hostgroup ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE hostgroup ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE hostgroup ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE hostgroup ALTER COLUMN zone_id SET STORAGE PLAIN;

CREATE INDEX idx_hostgroup_display_name ON hostgroup(display_name);
CREATE INDEX idx_hostgroup_name_ci ON hostgroup(name_ci);
CREATE INDEX idx_hostgroup_name ON hostgroup(name);

COMMENT ON COLUMN hostgroup.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN hostgroup.environment_id IS 'environment.id';
COMMENT ON COLUMN hostgroup.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN hostgroup.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN hostgroup.zone_id IS 'zone.id';

COMMENT ON INDEX idx_hostgroup_display_name IS 'Hostgroup list filtered/ordered by display_name';
COMMENT ON INDEX idx_hostgroup_name_ci IS 'Hostgroup list filtered using quick search';
COMMENT ON INDEX idx_hostgroup_name IS 'Host/service/host group list filtered by host group name; Hostgroup detail filter';

CREATE TABLE hostgroup_member (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  host_id bytea20 NOT NULL,
  hostgroup_id bytea20 NOT NULL,

  CONSTRAINT pk_hostgroup_member PRIMARY KEY (id)
);

ALTER TABLE hostgroup_member ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE hostgroup_member ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE hostgroup_member ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE hostgroup_member ALTER COLUMN hostgroup_id SET STORAGE PLAIN;

CREATE INDEX idx_hostgroup_member_host_id ON hostgroup_member(host_id, hostgroup_id);
CREATE INDEX idx_hostgroup_member_hostgroup_id ON hostgroup_member(hostgroup_id, host_id);

COMMENT ON COLUMN hostgroup_member.id IS 'sha1(environment.id + host_id + hostgroup_id)';
COMMENT ON COLUMN hostgroup_member.environment_id IS 'environment.id';
COMMENT ON COLUMN hostgroup_member.host_id IS 'host.id';
COMMENT ON COLUMN hostgroup_member.hostgroup_id IS 'hostgroup.id';

CREATE TABLE host_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  host_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_host_customvar PRIMARY KEY (id)
);

ALTER TABLE host_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE host_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE host_customvar ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE host_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_host_customvar_host_id ON host_customvar(host_id, customvar_id);
CREATE INDEX idx_host_customvar_customvar_id ON host_customvar(customvar_id, host_id);

COMMENT ON COLUMN host_customvar.id IS 'sha1(environment.id + host_id + customvar_id)';
COMMENT ON COLUMN host_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN host_customvar.host_id IS 'host.id';
COMMENT ON COLUMN host_customvar.customvar_id IS 'customvar.id';

CREATE TABLE hostgroup_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  hostgroup_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_hostgroup_customvar PRIMARY KEY (id)
);

ALTER TABLE hostgroup_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE hostgroup_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE hostgroup_customvar ALTER COLUMN hostgroup_id SET STORAGE PLAIN;
ALTER TABLE hostgroup_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_hostgroup_customvar_hostgroup_id ON hostgroup_customvar(hostgroup_id, customvar_id);
CREATE INDEX idx_hostgroup_customvar_customvar_id ON hostgroup_customvar(customvar_id, hostgroup_id);

COMMENT ON COLUMN hostgroup_customvar.id IS 'sha1(environment.id + hostgroup_id + customvar_id)';
COMMENT ON COLUMN hostgroup_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN hostgroup_customvar.hostgroup_id IS 'hostgroup.id';
COMMENT ON COLUMN hostgroup_customvar.customvar_id IS 'customvar.id';

CREATE TABLE host_state (
  id bytea20 NOT NULL,
  host_id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  state_type state_type NOT NULL DEFAULT 'hard',
  soft_state tinyuint NOT NULL,
  hard_state tinyuint NOT NULL,
  previous_soft_state tinyuint NOT NULL,
  previous_hard_state tinyuint NOT NULL,
  check_attempt tinyuint NOT NULL,
  severity smalluint NOT NULL,

  output text DEFAULT NULL,
  long_output text DEFAULT NULL,
  performance_data text DEFAULT NULL,
  normalized_performance_data text DEFAULT NULL,

  check_commandline text DEFAULT NULL,

  is_problem boolenum NOT NULL DEFAULT 'n',
  is_handled boolenum NOT NULL DEFAULT 'n',
  is_reachable boolenum NOT NULL DEFAULT 'n',
  is_flapping boolenum NOT NULL DEFAULT 'n',
  is_overdue boolenum NOT NULL DEFAULT 'n',

  is_acknowledged acked NOT NULL DEFAULT 'n',
  acknowledgement_comment_id bytea20 DEFAULT NULL,
  last_comment_id bytea20 DEFAULT NULL,

  in_downtime boolenum NOT NULL DEFAULT 'n',

  execution_time uint DEFAULT NULL,
  latency uint DEFAULT NULL,
  check_timeout uint DEFAULT NULL,
  check_source text DEFAULT NULL,
  scheduling_source text DEFAULT NULL,

  last_update biguint DEFAULT NULL,
  last_state_change biguint NOT NULL,
  next_check biguint NOT NULL,
  next_update biguint NOT NULL,

  CONSTRAINT pk_host_state PRIMARY KEY (id)
);

ALTER TABLE host_state ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE host_state ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE host_state ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE host_state ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE host_state ALTER COLUMN acknowledgement_comment_id SET STORAGE PLAIN;
ALTER TABLE host_state ALTER COLUMN last_comment_id SET STORAGE PLAIN;

CREATE UNIQUE INDEX idx_host_state_host_id ON host_state(host_id);
CREATE INDEX idx_host_state_is_problem ON host_state(is_problem, severity);
CREATE INDEX idx_host_state_severity ON host_state(severity);
CREATE INDEX idx_host_state_soft_state ON host_state(soft_state, last_state_change);
CREATE INDEX idx_host_state_last_state_change ON host_state(last_state_change);

COMMENT ON COLUMN host_state.id IS 'host.id';
COMMENT ON COLUMN host_state.host_id IS 'host.id';
COMMENT ON COLUMN host_state.environment_id IS 'environment.id';
COMMENT ON COLUMN host_state.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN host_state.acknowledgement_comment_id IS 'comment.id';
COMMENT ON COLUMN host_state.last_comment_id IS 'comment.id';

COMMENT ON INDEX idx_host_state_is_problem IS 'Host list filtered by is_problem ordered by severity';
COMMENT ON INDEX idx_host_state_severity IS 'Host list filtered/ordered by severity';
COMMENT ON INDEX idx_host_state_soft_state IS 'Host list filtered/ordered by soft_state; recently recovered filter';
COMMENT ON INDEX idx_host_state_last_state_change IS 'Host list filtered/ordered by last_state_change';

CREATE TABLE service (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,
  host_id bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,

  checkcommand_name citext NOT NULL,
  checkcommand_id bytea20 NOT NULL,

  max_check_attempts uint NOT NULL,

  check_timeperiod_name citext NOT NULL,
  check_timeperiod_id bytea20 DEFAULT NULL,

  check_timeout uint DEFAULT NULL,
  check_interval uint NOT NULL,
  check_retry_interval uint NOT NULL,

  active_checks_enabled boolenum NOT NULL DEFAULT 'n',
  passive_checks_enabled boolenum NOT NULL DEFAULT 'n',
  event_handler_enabled boolenum NOT NULL DEFAULT 'n',
  notifications_enabled boolenum NOT NULL DEFAULT 'n',

  flapping_enabled boolenum NOT NULL DEFAULT 'n',
  flapping_threshold_low float NOT NULL,
  flapping_threshold_high float NOT NULL,

  perfdata_enabled boolenum NOT NULL DEFAULT 'n',

  eventcommand_name citext NOT NULL,
  eventcommand_id bytea20 DEFAULT NULL,

  is_volatile boolenum NOT NULL DEFAULT 'n',

  action_url_id bytea20 DEFAULT NULL,
  notes_url_id bytea20 DEFAULT NULL,
  notes text NOT NULL,
  icon_image_id bytea20 DEFAULT NULL,
  icon_image_alt varchar(32) NOT NULL,

  zone_name citext NOT NULL,
  zone_id bytea20 DEFAULT NULL,

  command_endpoint_name citext NOT NULL,
  command_endpoint_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_service PRIMARY KEY (id)
);

ALTER TABLE service ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN checkcommand_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN check_timeperiod_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN eventcommand_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN action_url_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN notes_url_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN icon_image_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN zone_id SET STORAGE PLAIN;
ALTER TABLE service ALTER COLUMN command_endpoint_id SET STORAGE PLAIN;

CREATE INDEX idx_service_display_name ON service(display_name);
CREATE INDEX idx_service_host_id ON service(host_id, display_name);
CREATE INDEX idx_service_name_ci ON service(name_ci);
CREATE INDEX idx_service_name ON service(name);

COMMENT ON COLUMN service.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN service.environment_id IS 'environment.id';
COMMENT ON COLUMN service.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN service.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN service.host_id IS 'sha1(host.id)';
COMMENT ON COLUMN service.checkcommand_name IS 'checkcommand.name';
COMMENT ON COLUMN service.checkcommand_id IS 'checkcommand.id';
COMMENT ON COLUMN service.check_timeperiod_name IS 'timeperiod.name';
COMMENT ON COLUMN service.check_timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN service.eventcommand_name IS 'eventcommand.name';
COMMENT ON COLUMN service.eventcommand_id IS 'eventcommand.id';
COMMENT ON COLUMN service.action_url_id IS 'action_url.id';
COMMENT ON COLUMN service.notes_url_id IS 'notes_url.id';
COMMENT ON COLUMN service.icon_image_id IS 'icon_image.id';
COMMENT ON COLUMN service.zone_name IS 'zone.name';
COMMENT ON COLUMN service.zone_id IS 'zone.id';
COMMENT ON COLUMN service.command_endpoint_name IS 'endpoint.name';
COMMENT ON COLUMN service.command_endpoint_id IS 'endpoint.id';

COMMENT ON INDEX idx_service_display_name IS 'Service list filtered/ordered by display_name';
COMMENT ON INDEX idx_service_host_id IS 'Service list filtered by host and ordered by display_name';
COMMENT ON INDEX idx_service_name_ci IS 'Service list filtered using quick search';
COMMENT ON INDEX idx_service_name IS 'Service list filtered/ordered by name; Service detail filter';

CREATE TABLE servicegroup (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_servicegroup PRIMARY KEY (id)
);

ALTER TABLE servicegroup ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE servicegroup ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE servicegroup ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE servicegroup ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE servicegroup ALTER COLUMN zone_id SET STORAGE PLAIN;

COMMENT ON COLUMN servicegroup.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN servicegroup.environment_id IS 'environment.id';
COMMENT ON COLUMN servicegroup.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN servicegroup.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN servicegroup.zone_id IS 'zone.id';

CREATE INDEX idx_servicegroup_display_name ON servicegroup(display_name);
CREATE INDEX idx_servicegroup_name_ci ON servicegroup(name_ci);
CREATE INDEX idx_servicegroup_name ON servicegroup(name);
COMMENT ON INDEX idx_servicegroup_display_name IS 'Servicegroup list filtered/ordered by display_name';
COMMENT ON INDEX idx_servicegroup_name_ci IS 'Servicegroup list filtered using quick search';
COMMENT ON INDEX idx_servicegroup_name IS 'Host/service/service group list filtered by service group name; Servicegroup detail filter';

CREATE TABLE servicegroup_member (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  service_id bytea20 NOT NULL,
  servicegroup_id bytea20 NOT NULL,

  CONSTRAINT pk_servicegroup_member PRIMARY KEY (id)
);

ALTER TABLE servicegroup_member ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE servicegroup_member ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE servicegroup_member ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE servicegroup_member ALTER COLUMN servicegroup_id SET STORAGE PLAIN;

CREATE INDEX idx_servicegroup_member_service_id ON servicegroup_member(service_id, servicegroup_id);
CREATE INDEX idx_servicegroup_member_servicegroup_id ON servicegroup_member(servicegroup_id, service_id);

COMMENT ON COLUMN servicegroup_member.id IS 'sha1(environment.id + servicegroup_id + service_id)';
COMMENT ON COLUMN servicegroup_member.environment_id IS 'environment.id';
COMMENT ON COLUMN servicegroup_member.service_id IS 'service.id';
COMMENT ON COLUMN servicegroup_member.servicegroup_id IS 'servicegroup.id';

CREATE TABLE service_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  service_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_service_customvar PRIMARY KEY (id)
);

ALTER TABLE service_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE service_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE service_customvar ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE service_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_service_customvar_service_id ON service_customvar(service_id, customvar_id);
CREATE INDEX idx_service_customvar_customvar_id ON service_customvar(customvar_id, service_id);

COMMENT ON COLUMN service_customvar.id IS 'sha1(environment.id + service_id + customvar_id)';
COMMENT ON COLUMN service_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN service_customvar.service_id IS 'service.id';
COMMENT ON COLUMN service_customvar.customvar_id IS 'customvar.id';

CREATE TABLE servicegroup_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  servicegroup_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_servicegroup_customvar PRIMARY KEY (id)
);

ALTER TABLE servicegroup_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE servicegroup_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE servicegroup_customvar ALTER COLUMN servicegroup_id SET STORAGE PLAIN;
ALTER TABLE servicegroup_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_servicegroup_customvar_servicegroup_id ON servicegroup_customvar(servicegroup_id, customvar_id);
CREATE INDEX idx_servicegroup_customvar_customvar_id ON servicegroup_customvar(customvar_id, servicegroup_id);

COMMENT ON COLUMN servicegroup_customvar.id IS 'sha1(environment.id + servicegroup_id + customvar_id)';
COMMENT ON COLUMN servicegroup_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN servicegroup_customvar.servicegroup_id IS 'servicegroup.id';
COMMENT ON COLUMN servicegroup_customvar.customvar_id IS 'customvar.id';

CREATE TABLE service_state (
  id bytea20 NOT NULL,
  host_id bytea20 NOT NULL,
  service_id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  state_type state_type NOT NULL DEFAULT 'hard',
  soft_state tinyuint NOT NULL,
  hard_state tinyuint NOT NULL,
  previous_soft_state tinyuint NOT NULL,
  previous_hard_state tinyuint NOT NULL,
  check_attempt tinyuint NOT NULL,
  severity smalluint NOT NULL,

  output text DEFAULT NULL,
  long_output text DEFAULT NULL,
  performance_data text DEFAULT NULL,
  normalized_performance_data text DEFAULT NULL,

  check_commandline text DEFAULT NULL,

  is_problem boolenum NOT NULL DEFAULT 'n',
  is_handled boolenum NOT NULL DEFAULT 'n',
  is_reachable boolenum NOT NULL DEFAULT 'n',
  is_flapping boolenum NOT NULL DEFAULT 'n',
  is_overdue boolenum NOT NULL DEFAULT 'n',

  is_acknowledged acked NOT NULL DEFAULT 'n',
  acknowledgement_comment_id bytea20 DEFAULT NULL,
  last_comment_id bytea20 DEFAULT NULL,

  in_downtime boolenum NOT NULL DEFAULT 'n',

  execution_time uint DEFAULT NULL,
  latency uint DEFAULT NULL,
  check_timeout uint DEFAULT NULL,
  check_source text DEFAULT NULL,
  scheduling_source text DEFAULT NULL,

  last_update biguint DEFAULT NULL,
  last_state_change biguint NOT NULL,
  next_check biguint NOT NULL,
  next_update biguint NOT NULL,

  CONSTRAINT pk_service_state PRIMARY KEY (id)
);

ALTER TABLE service_state ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE service_state ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE service_state ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE service_state ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE service_state ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE service_state ALTER COLUMN acknowledgement_comment_id SET STORAGE PLAIN;
ALTER TABLE service_state ALTER COLUMN last_comment_id SET STORAGE PLAIN;

CREATE UNIQUE INDEX idx_service_state_service_id ON service_state(service_id);
CREATE INDEX idx_service_state_is_problem ON service_state(is_problem, severity);
CREATE INDEX idx_service_state_severity ON service_state(severity);
CREATE INDEX idx_service_state_soft_state ON service_state(soft_state, last_state_change);
CREATE INDEX idx_service_state_last_state_change ON service_state(last_state_change);

COMMENT ON COLUMN service_state.id IS 'service.id';
COMMENT ON COLUMN service_state.host_id IS 'host.id';
COMMENT ON COLUMN service_state.service_id IS 'service.id';
COMMENT ON COLUMN service_state.environment_id IS 'environment.id';
COMMENT ON COLUMN service_state.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN service_state.acknowledgement_comment_id IS 'comment.id';
COMMENT ON COLUMN service_state.last_comment_id IS 'comment.id';

COMMENT ON INDEX idx_service_state_is_problem IS 'Service list filtered by is_problem ordered by severity';
COMMENT ON INDEX idx_service_state_severity IS 'Service list filtered/ordered by severity';
COMMENT ON INDEX idx_service_state_soft_state IS 'Service list filtered/ordered by soft_state; recently recovered filter';
COMMENT ON INDEX idx_service_state_last_state_change IS 'Service list filtered/ordered by last_state_change';

CREATE TABLE endpoint (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,

  zone_id bytea20 NOT NULL,

  CONSTRAINT pk_endpoint PRIMARY KEY (id)
);

ALTER TABLE endpoint ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE endpoint ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE endpoint ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE endpoint ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE endpoint ALTER COLUMN zone_id SET STORAGE PLAIN;

COMMENT ON COLUMN endpoint.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN endpoint.environment_id IS 'environment.id';
COMMENT ON COLUMN endpoint.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN endpoint.zone_id IS 'zone.id';

CREATE TABLE environment (
  id bytea20 NOT NULL,
  name varchar(255) NOT NULL,

  CONSTRAINT pk_environment PRIMARY KEY (id)
);

ALTER TABLE environment ALTER COLUMN id SET STORAGE PLAIN;

COMMENT ON COLUMN environment.id IS 'sha1(Icinga CA public key)';

CREATE TABLE icingadb_instance (
  id bytea16 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  heartbeat biguint NOT NULL,
  responsible boolenum NOT NULL DEFAULT 'n',

  icinga2_version varchar(255) NOT NULL,
  icinga2_start_time biguint NOT NULL,
  icinga2_notifications_enabled boolenum NOT NULL DEFAULT 'n',
  icinga2_active_service_checks_enabled boolenum NOT NULL DEFAULT 'n',
  icinga2_active_host_checks_enabled boolenum NOT NULL DEFAULT 'n',
  icinga2_event_handlers_enabled boolenum NOT NULL DEFAULT 'n',
  icinga2_flap_detection_enabled boolenum NOT NULL DEFAULT 'n',
  icinga2_performance_data_enabled boolenum NOT NULL DEFAULT 'n',

  CONSTRAINT pk_icingadb_instance PRIMARY KEY (id)
);

ALTER TABLE icingadb_instance ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE icingadb_instance ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE icingadb_instance ALTER COLUMN endpoint_id SET STORAGE PLAIN;

COMMENT ON COLUMN icingadb_instance.id IS 'UUIDv4';
COMMENT ON COLUMN icingadb_instance.environment_id IS 'environment.id';
COMMENT ON COLUMN icingadb_instance.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN icingadb_instance.heartbeat IS '*nix timestamp';

CREATE TABLE checkcommand (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  zone_id bytea20 DEFAULT NULL,

  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  command text NOT NULL,
  timeout uint NOT NULL,

  CONSTRAINT pk_checkcommand PRIMARY KEY (id)
);

ALTER TABLE checkcommand ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE checkcommand ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE checkcommand ALTER COLUMN zone_id SET STORAGE PLAIN;
ALTER TABLE checkcommand ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE checkcommand ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN checkcommand.id IS 'sha1(environment.id + type + name)';
COMMENT ON COLUMN checkcommand.environment_id IS 'env.id';
COMMENT ON COLUMN checkcommand.zone_id IS 'zone.id';
COMMENT ON COLUMN checkcommand.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN checkcommand.properties_checksum IS 'sha1(all properties)';

CREATE TABLE checkcommand_argument (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  checkcommand_id bytea20 NOT NULL,
  argument_key varchar(64) NOT NULL,

  properties_checksum bytea20 NOT NULL,

  argument_value text DEFAULT NULL,
  argument_order smallint DEFAULT NULL,
  description text DEFAULT NULL,
  argument_key_override citext DEFAULT NULL,
  repeat_key boolenum NOT NULL DEFAULT 'n',
  required boolenum NOT NULL DEFAULT 'n',
  set_if varchar(255) DEFAULT NULL,
  separator varchar(255) DEFAULT NULL,
  skip_key boolenum NOT NULL DEFAULT 'n',

  CONSTRAINT pk_checkcommand_argument PRIMARY KEY (id)
);

ALTER TABLE checkcommand_argument ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE checkcommand_argument ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE checkcommand_argument ALTER COLUMN checkcommand_id SET STORAGE PLAIN;
ALTER TABLE checkcommand_argument ALTER COLUMN argument_key SET STORAGE PLAIN;
ALTER TABLE checkcommand_argument ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN checkcommand_argument.id IS 'sha1(environment.id + checkcommand_id + argument_key)';
COMMENT ON COLUMN checkcommand_argument.environment_id IS 'env.id';
COMMENT ON COLUMN checkcommand_argument.checkcommand_id IS 'checkcommand.id';
COMMENT ON COLUMN checkcommand_argument.properties_checksum IS 'sha1(all properties)';

CREATE TABLE checkcommand_envvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  checkcommand_id bytea20 NOT NULL,
  envvar_key varchar(64) NOT NULL,

  properties_checksum bytea20 NOT NULL,

  envvar_value text NOT NULL,

  CONSTRAINT pk_checkcommand_envvar PRIMARY KEY (id)
);

ALTER TABLE checkcommand_envvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE checkcommand_envvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE checkcommand_envvar ALTER COLUMN checkcommand_id SET STORAGE PLAIN;
ALTER TABLE checkcommand_envvar ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN checkcommand_envvar.id IS 'sha1(environment.id + checkcommand_id + envvar_key)';
COMMENT ON COLUMN checkcommand_envvar.environment_id IS 'env.id';
COMMENT ON COLUMN checkcommand_envvar.checkcommand_id IS 'checkcommand.id';
COMMENT ON COLUMN checkcommand_envvar.properties_checksum IS 'sha1(all properties)';

CREATE TABLE checkcommand_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,

  checkcommand_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_checkcommand_customvar PRIMARY KEY (id)
);

ALTER TABLE checkcommand_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE checkcommand_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE checkcommand_customvar ALTER COLUMN checkcommand_id SET STORAGE PLAIN;
ALTER TABLE checkcommand_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_checkcommand_customvar_checkcommand_id ON checkcommand_customvar(checkcommand_id, customvar_id);
CREATE INDEX idx_checkcommand_customvar_customvar_id ON checkcommand_customvar(customvar_id, checkcommand_id);

COMMENT ON COLUMN checkcommand_customvar.id IS 'sha1(environment.id + checkcommand_id + customvar_id)';
COMMENT ON COLUMN checkcommand_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN checkcommand_customvar.checkcommand_id IS 'checkcommand.id';
COMMENT ON COLUMN checkcommand_customvar.customvar_id IS 'customvar.id';

CREATE TABLE eventcommand (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  zone_id bytea20 DEFAULT NULL,

  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  command text NOT NULL,
  timeout smalluint NOT NULL,

  CONSTRAINT pk_eventcommand PRIMARY KEY (id)
);

ALTER TABLE eventcommand ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE eventcommand ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE eventcommand ALTER COLUMN zone_id SET STORAGE PLAIN;
ALTER TABLE eventcommand ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE eventcommand ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN eventcommand.id IS 'sha1(environment.id + type + name)';
COMMENT ON COLUMN eventcommand.environment_id IS 'env.id';
COMMENT ON COLUMN eventcommand.zone_id IS 'zone.id';
COMMENT ON COLUMN eventcommand.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN eventcommand.properties_checksum IS 'sha1(all properties)';

CREATE TABLE eventcommand_argument (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  eventcommand_id bytea20 NOT NULL,
  argument_key varchar(64) NOT NULL,

  properties_checksum bytea20 NOT NULL,

  argument_value text DEFAULT NULL,
  argument_order smallint DEFAULT NULL,
  description text DEFAULT NULL,
  argument_key_override citext DEFAULT NULL,
  repeat_key boolenum NOT NULL DEFAULT 'n',
  required boolenum NOT NULL DEFAULT 'n',
  set_if varchar(255) DEFAULT NULL,
  separator varchar(255) DEFAULT NULL,
  skip_key boolenum NOT NULL DEFAULT 'n',

  CONSTRAINT pk_eventcommand_argument PRIMARY KEY (id)
);

ALTER TABLE eventcommand_argument ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE eventcommand_argument ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE eventcommand_argument ALTER COLUMN eventcommand_id SET STORAGE PLAIN;
ALTER TABLE eventcommand_argument ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN eventcommand_argument.id IS 'sha1(environment.id + eventcommand_id + argument_key)';
COMMENT ON COLUMN eventcommand_argument.environment_id IS 'env.id';
COMMENT ON COLUMN eventcommand_argument.eventcommand_id IS 'eventcommand.id';
COMMENT ON COLUMN eventcommand_argument.properties_checksum IS 'sha1(all properties)';

CREATE TABLE eventcommand_envvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  eventcommand_id bytea20 NOT NULL,
  envvar_key varchar(64) NOT NULL,

  properties_checksum bytea20 NOT NULL,

  envvar_value text NOT NULL,

  CONSTRAINT pk_eventcommand_envvar PRIMARY KEY (id)
);

ALTER TABLE eventcommand_envvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE eventcommand_envvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE eventcommand_envvar ALTER COLUMN eventcommand_id SET STORAGE PLAIN;
ALTER TABLE eventcommand_envvar ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN eventcommand_envvar.id IS 'sha1(environment.id + eventcommand_id + envvar_key)';
COMMENT ON COLUMN eventcommand_envvar.environment_id IS 'env.id';
COMMENT ON COLUMN eventcommand_envvar.eventcommand_id IS 'eventcommand.id';
COMMENT ON COLUMN eventcommand_envvar.properties_checksum IS 'sha1(all properties)';

CREATE TABLE eventcommand_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  eventcommand_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_eventcommand_customvar PRIMARY KEY (id)
);

ALTER TABLE eventcommand_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE eventcommand_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE eventcommand_customvar ALTER COLUMN eventcommand_id SET STORAGE PLAIN;
ALTER TABLE eventcommand_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_eventcommand_customvar_eventcommand_id ON eventcommand_customvar(eventcommand_id, customvar_id);
CREATE INDEX idx_eventcommand_customvar_customvar_id ON eventcommand_customvar(customvar_id, eventcommand_id);

COMMENT ON COLUMN eventcommand_customvar.id IS 'sha1(environment.id + eventcommand_id + customvar_id)';
COMMENT ON COLUMN eventcommand_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN eventcommand_customvar.eventcommand_id IS 'eventcommand.id';
COMMENT ON COLUMN eventcommand_customvar.customvar_id IS 'customvar.id';

CREATE TABLE notificationcommand (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  zone_id bytea20 DEFAULT NULL,

  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  command text NOT NULL,
  timeout smalluint NOT NULL,

  CONSTRAINT pk_notificationcommand PRIMARY KEY (id)
);

ALTER TABLE notificationcommand ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notificationcommand ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand ALTER COLUMN zone_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE notificationcommand ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN notificationcommand.id IS 'sha1(environment.id + type + name)';
COMMENT ON COLUMN notificationcommand.environment_id IS 'env.id';
COMMENT ON COLUMN notificationcommand.zone_id IS 'zone.id';
COMMENT ON COLUMN notificationcommand.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN notificationcommand.properties_checksum IS 'sha1(all properties)';

CREATE TABLE notificationcommand_argument (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notificationcommand_id bytea20 NOT NULL,
  argument_key varchar(64) NOT NULL,

  properties_checksum bytea20 NOT NULL,

  argument_value text DEFAULT NULL,
  argument_order smallint DEFAULT NULL,
  description text DEFAULT NULL,
  argument_key_override citext DEFAULT NULL,
  repeat_key boolenum NOT NULL DEFAULT 'n',
  required boolenum NOT NULL DEFAULT 'n',
  set_if varchar(255) DEFAULT NULL,
  separator varchar(255) DEFAULT NULL,
  skip_key boolenum NOT NULL DEFAULT 'n',

  CONSTRAINT pk_notificationcommand_argument PRIMARY KEY (id)
);

ALTER TABLE notificationcommand_argument ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_argument ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_argument ALTER COLUMN notificationcommand_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_argument ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN notificationcommand_argument.id IS 'sha1(environment.id + notificationcommand_id + argument_key)';
COMMENT ON COLUMN notificationcommand_argument.environment_id IS 'env.id';
COMMENT ON COLUMN notificationcommand_argument.notificationcommand_id IS 'notificationcommand.id';
COMMENT ON COLUMN notificationcommand_argument.properties_checksum IS 'sha1(all properties)';

CREATE TABLE notificationcommand_envvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notificationcommand_id bytea20 NOT NULL,
  envvar_key varchar(64) NOT NULL,

  properties_checksum bytea20 NOT NULL,

  envvar_value text NOT NULL,

  CONSTRAINT pk_notificationcommand_envvar PRIMARY KEY (id)
);

ALTER TABLE notificationcommand_envvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_envvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_envvar ALTER COLUMN notificationcommand_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_envvar ALTER COLUMN properties_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN notificationcommand_envvar.id IS 'sha1(environment.id + notificationcommand_id + envvar_key)';
COMMENT ON COLUMN notificationcommand_envvar.environment_id IS 'env.id';
COMMENT ON COLUMN notificationcommand_envvar.notificationcommand_id IS 'notificationcommand.id';
COMMENT ON COLUMN notificationcommand_envvar.properties_checksum IS 'sha1(all properties)';

CREATE TABLE notificationcommand_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notificationcommand_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_notificationcommand_customvar PRIMARY KEY (id)
);

ALTER TABLE notificationcommand_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_customvar ALTER COLUMN notificationcommand_id SET STORAGE PLAIN;
ALTER TABLE notificationcommand_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_notificationcommand_customvar_notificationcommand_id ON notificationcommand_customvar(notificationcommand_id, customvar_id);
CREATE INDEX idx_notificationcommand_customvar_customvar_id ON notificationcommand_customvar(customvar_id, notificationcommand_id);

COMMENT ON COLUMN notificationcommand_customvar.id IS 'sha1(environment.id + notificationcommand_id + customvar_id)';
COMMENT ON COLUMN notificationcommand_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN notificationcommand_customvar.notificationcommand_id IS 'notificationcommand.id';
COMMENT ON COLUMN notificationcommand_customvar.customvar_id IS 'customvar.id';

CREATE TABLE comment (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,

  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,
  name varchar(548) NOT NULL,

  author citext NOT NULL,
  text text NOT NULL,
  entry_type comment_type NOT NULL DEFAULT 'comment',
  entry_time biguint NOT NULL,
  is_persistent boolenum NOT NULL DEFAULT 'n',
  is_sticky boolenum NOT NULL DEFAULT 'n',
  expire_time biguint DEFAULT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_comment PRIMARY KEY (id)
);

ALTER TABLE comment ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE comment ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE comment ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE comment ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE comment ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE comment ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE comment ALTER COLUMN zone_id SET STORAGE PLAIN;

CREATE INDEX idx_comment_name ON comment(name);
CREATE INDEX idx_comment_entry_time ON comment(entry_time);
CREATE INDEX idx_comment_author ON comment(author);
CREATE INDEX idx_comment_expire_time ON comment(expire_time);

COMMENT ON COLUMN comment.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN comment.environment_id IS 'environment.id';
COMMENT ON COLUMN comment.host_id IS 'host.id';
COMMENT ON COLUMN comment.service_id IS 'service.id';
COMMENT ON COLUMN comment.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN comment.name IS '255+1+255+1+36, i.e. "host.name!service.name!UUID"';
COMMENT ON COLUMN comment.zone_id IS 'zone.id';

COMMENT ON INDEX idx_comment_name IS 'Comment detail filter';
COMMENT ON INDEX idx_comment_entry_time IS 'Comment list fileted/ordered by entry_time';
COMMENT ON INDEX idx_comment_author IS 'Comment list filtered/ordered by author';
COMMENT ON INDEX idx_comment_expire_time IS 'Comment list filtered/ordered by expire_time';

CREATE TABLE downtime (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,

  triggered_by_id bytea20 DEFAULT NULL,
  parent_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,
  name varchar(548) NOT NULL,

  author citext NOT NULL,
  comment text NOT NULL,
  entry_time biguint NOT NULL,
  scheduled_start_time biguint NOT NULL,
  scheduled_end_time biguint NOT NULL,
  scheduled_duration biguint NOT NULL,
  is_flexible boolenum NOT NULL DEFAULT 'n',
  flexible_duration biguint NOT NULL,

  is_in_effect boolenum NOT NULL DEFAULT 'n',
  start_time biguint DEFAULT NULL,
  end_time biguint DEFAULT NULL,
  duration biguint NOT NULL,
  scheduled_by varchar(767) DEFAULT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_downtime PRIMARY KEY (id)
);

ALTER TABLE downtime ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN triggered_by_id SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN parent_id SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE downtime ALTER COLUMN zone_id SET STORAGE PLAIN;

CREATE INDEX idx_downtime_is_in_effect ON downtime(is_in_effect, start_time);
CREATE INDEX idx_downtime_name ON downtime(name);
CREATE INDEX idx_downtime_entry_time ON downtime(entry_time);
CREATE INDEX idx_downtime_start_time ON downtime(start_time);
CREATE INDEX idx_downtime_end_time ON downtime(end_time);
CREATE INDEX idx_downtime_scheduled_start_time ON downtime(scheduled_start_time);
CREATE INDEX idx_downtime_scheduled_end_time ON downtime(scheduled_end_time);
CREATE INDEX idx_downtime_author ON downtime(author);
CREATE INDEX idx_downtime_duration ON downtime(duration);

COMMENT ON COLUMN downtime.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN downtime.environment_id IS 'environment.id';
COMMENT ON COLUMN downtime.triggered_by_id IS 'The ID of the downtime that triggered this downtime. This is set when creating downtimes on a host or service higher up in the dependency chain using the "child_option" "DowntimeTriggeredChildren" and can also be set manually via the API.';
COMMENT ON COLUMN downtime.parent_id IS 'For service downtimes, the ID of the host downtime that created this downtime by using the "all_services" flag of the schedule-downtime API.';
COMMENT ON COLUMN downtime.host_id IS 'host.id';
COMMENT ON COLUMN downtime.service_id IS 'service.id';
COMMENT ON COLUMN downtime.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN downtime.name IS '255+1+255+1+36, i.e. "host.name!service.name!UUID"';
COMMENT ON COLUMN downtime.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN downtime.start_time IS 'Time when the host went into a problem state during the downtimes timeframe';
COMMENT ON COLUMN downtime.end_time IS 'Problem state assumed: scheduled_end_time if fixed, start_time + flexible_duration otherwise';
COMMENT ON COLUMN downtime.duration IS 'Duration of the downtime: When the downtime is flexible, this is the same as flexible_duration otherwise scheduled_duration';
COMMENT ON COLUMN downtime.scheduled_by IS 'Name of the ScheduledDowntime which created this Downtime. 255+1+255+1+255, i.e. "host.name!service.name!scheduled-downtime-name"';
COMMENT ON COLUMN downtime.zone_id IS 'zone.id';

COMMENT ON INDEX idx_downtime_is_in_effect IS 'Downtime list filtered/ordered by severity';
COMMENT ON INDEX idx_downtime_name IS 'Downtime detail filter';
COMMENT ON INDEX idx_downtime_entry_time IS 'Downtime list filtered/ordered by entry_time';
COMMENT ON INDEX idx_downtime_start_time IS 'Downtime list filtered/ordered by start_time';
COMMENT ON INDEX idx_downtime_end_time IS 'Downtime list filtered/ordered by end_time';
COMMENT ON INDEX idx_downtime_scheduled_start_time IS 'Downtime list filtered/ordered by scheduled_start_time';
COMMENT ON INDEX idx_downtime_scheduled_end_time IS 'Downtime list filtered/ordered by scheduled_end_time';
COMMENT ON INDEX idx_downtime_author IS 'Downtime list filtered/ordered by author';
COMMENT ON INDEX idx_downtime_duration IS 'Downtime list filtered/ordered by duration';

CREATE TABLE notification (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(767) NOT NULL,
  name_ci citext NOT NULL,

  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,
  notificationcommand_id bytea20 NOT NULL,

  times_begin uint DEFAULT NULL,
  times_end uint DEFAULT NULL,
  notification_interval uint NOT NULL,
  timeperiod_id bytea20 DEFAULT NULL,

  states tinyuint NOT NULL,
  types smalluint NOT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_notification PRIMARY KEY (id)
);

ALTER TABLE notification ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN notificationcommand_id SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN timeperiod_id SET STORAGE PLAIN;
ALTER TABLE notification ALTER COLUMN zone_id SET STORAGE PLAIN;

CREATE INDEX idx_notification_host_id ON notification(host_id);
CREATE INDEX idx_notification_service_id ON notification(service_id);

COMMENT ON COLUMN notification.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN notification.environment_id IS 'environment.id';
COMMENT ON COLUMN notification.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN notification.name IS '255+1+255+1+255, i.e. "host.name!service.name!notification.name"';
COMMENT ON COLUMN notification.host_id IS 'host.id';
COMMENT ON COLUMN notification.service_id IS 'service.id';
COMMENT ON COLUMN notification.notificationcommand_id IS 'command.id';
COMMENT ON COLUMN notification.timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN notification.zone_id IS 'zone.id';

CREATE TABLE notification_user (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notification_id bytea20 NOT NULL,
  user_id bytea20 NOT NULL,

  CONSTRAINT pk_notification_user PRIMARY KEY (id)
);

ALTER TABLE notification_user ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notification_user ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notification_user ALTER COLUMN notification_id SET STORAGE PLAIN;
ALTER TABLE notification_user ALTER COLUMN user_id SET STORAGE PLAIN;

CREATE INDEX idx_notification_user_user_id ON notification_user(user_id, notification_id);
CREATE INDEX idx_notification_user_notification_id ON notification_user(notification_id, user_id);

COMMENT ON COLUMN notification_user.id IS 'sha1(environment.id + notification_id + user_id)';
COMMENT ON COLUMN notification_user.environment_id IS 'environment.id';
COMMENT ON COLUMN notification_user.notification_id IS 'notification.id';
COMMENT ON COLUMN notification_user.user_id IS 'user.id';

CREATE TABLE notification_usergroup (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notification_id bytea20 NOT NULL,
  usergroup_id bytea20 NOT NULL,

  CONSTRAINT pk_notification_usergroup PRIMARY KEY (id)
);

ALTER TABLE notification_usergroup ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notification_usergroup ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notification_usergroup ALTER COLUMN notification_id SET STORAGE PLAIN;
ALTER TABLE notification_usergroup ALTER COLUMN usergroup_id SET STORAGE PLAIN;

CREATE INDEX idx_notification_usergroup_usergroup_id ON notification_usergroup(usergroup_id, notification_id);
CREATE INDEX idx_notification_usergroup_notification_id ON notification_usergroup(notification_id, usergroup_id);

COMMENT ON COLUMN notification_usergroup.id IS 'sha1(environment.id + notification_id + usergroup_id)';
COMMENT ON COLUMN notification_usergroup.environment_id IS 'environment.id';
COMMENT ON COLUMN notification_usergroup.notification_id IS 'notification.id';
COMMENT ON COLUMN notification_usergroup.usergroup_id IS 'usergroup.id';

CREATE TABLE notification_recipient (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notification_id bytea20 NOT NULL,
  user_id bytea20 NULL,
  usergroup_id bytea20 NULL,

  CONSTRAINT pk_notification_recipient PRIMARY KEY (id)
);

ALTER TABLE notification_recipient ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notification_recipient ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notification_recipient ALTER COLUMN notification_id SET STORAGE PLAIN;
ALTER TABLE notification_recipient ALTER COLUMN user_id SET STORAGE PLAIN;
ALTER TABLE notification_recipient ALTER COLUMN usergroup_id SET STORAGE PLAIN;

CREATE INDEX idx_notification_recipient_user_id ON notification_recipient(user_id, notification_id);
CREATE INDEX idx_notification_recipient_notification_id_user ON notification_recipient(notification_id, user_id);
CREATE INDEX idx_notification_recipient_usergroup_id ON notification_recipient(usergroup_id, notification_id);
CREATE INDEX idx_notification_recipient_notification_id_usergroup ON notification_recipient(notification_id, usergroup_id);

COMMENT ON COLUMN notification_recipient.id IS 'sha1(environment.id + notification_id + (user_id | usergroup_id))';
COMMENT ON COLUMN notification_recipient.environment_id IS 'environment.id';
COMMENT ON COLUMN notification_recipient.notification_id IS 'notification.id';
COMMENT ON COLUMN notification_recipient.user_id IS 'user.id';
COMMENT ON COLUMN notification_recipient.usergroup_id IS 'usergroup.id';

CREATE TABLE notification_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notification_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_notification_customvar PRIMARY KEY (id)
);

ALTER TABLE notification_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notification_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notification_customvar ALTER COLUMN notification_id SET STORAGE PLAIN;
ALTER TABLE notification_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_notification_customvar_notification_id ON notification_customvar(notification_id, customvar_id);
CREATE INDEX idx_notification_customvar_customvar_id ON notification_customvar(customvar_id, notification_id);

COMMENT ON COLUMN notification_customvar.id IS 'sha1(environment.id + notification_id + customvar_id)';
COMMENT ON COLUMN notification_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN notification_customvar.notification_id IS 'notification.id';
COMMENT ON COLUMN notification_customvar.customvar_id IS 'customvar.id';

CREATE TABLE icon_image (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  icon_image citext NOT NULL,

  CONSTRAINT pk_icon_image PRIMARY KEY (id)
);

ALTER TABLE icon_image ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE icon_image ALTER COLUMN environment_id SET STORAGE PLAIN;

CREATE INDEX idx_icon_image ON icon_image(icon_image);

COMMENT ON COLUMN icon_image.id IS 'sha1(environment.id + icon_image)';
COMMENT ON COLUMN icon_image.environment_id IS 'environment.id';

CREATE TABLE action_url (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  action_url citext NOT NULL,

  CONSTRAINT pk_action_url PRIMARY KEY (id)
);

ALTER TABLE action_url ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE action_url ALTER COLUMN environment_id SET STORAGE PLAIN;

CREATE INDEX idx_action_url ON action_url(action_url);

COMMENT ON COLUMN action_url.id IS 'sha1(environment.id + action_url)';
COMMENT ON COLUMN action_url.environment_id IS 'environment.id';

CREATE TABLE notes_url (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notes_url citext NOT NULL,

  CONSTRAINT pk_notes_url PRIMARY KEY (id)
);

ALTER TABLE notes_url ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notes_url ALTER COLUMN environment_id SET STORAGE PLAIN;

CREATE INDEX idx_notes_url ON notes_url(notes_url);

COMMENT ON COLUMN notes_url.id IS 'sha1(environment.id + notes_url)';
COMMENT ON COLUMN notes_url.environment_id IS 'environment.id';

CREATE TABLE timeperiod (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,

  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,
  prefer_includes boolenum NOT NULL DEFAULT 'n',

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_timeperiod PRIMARY KEY (id)
);

ALTER TABLE timeperiod ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE timeperiod ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE timeperiod ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE timeperiod ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE timeperiod ALTER COLUMN zone_id SET STORAGE PLAIN;

COMMENT ON COLUMN timeperiod.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN timeperiod.environment_id IS 'env.id';
COMMENT ON COLUMN timeperiod.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN timeperiod.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN timeperiod.zone_id IS 'zone.id';

CREATE TABLE timeperiod_range (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  timeperiod_id bytea20 NOT NULL,
  range_key citext NOT NULL,

  range_value varchar(255) NOT NULL,

  CONSTRAINT pk_timeperiod_range PRIMARY KEY (id)
);

ALTER TABLE timeperiod_range ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE timeperiod_range ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_range ALTER COLUMN timeperiod_id SET STORAGE PLAIN;

COMMENT ON COLUMN timeperiod_range.id IS 'sha1(environment.id + range_id + timeperiod_id)';
COMMENT ON COLUMN timeperiod_range.environment_id IS 'env.id';
COMMENT ON COLUMN timeperiod_range.timeperiod_id IS 'timeperiod.id';

CREATE TABLE timeperiod_override_include (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  timeperiod_id bytea20 NOT NULL,
  override_id bytea20 NOT NULL,

  CONSTRAINT pk_timeperiod_override_include PRIMARY KEY (id)
);

ALTER TABLE timeperiod_override_include ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE timeperiod_override_include ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_override_include ALTER COLUMN timeperiod_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_override_include ALTER COLUMN override_id SET STORAGE PLAIN;

COMMENT ON COLUMN timeperiod_override_include.id IS 'sha1(environment.id + include_id + timeperiod_id)';
COMMENT ON COLUMN timeperiod_override_include.environment_id IS 'env.id';
COMMENT ON COLUMN timeperiod_override_include.timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN timeperiod_override_include.override_id IS 'timeperiod.id';

CREATE TABLE timeperiod_override_exclude (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  timeperiod_id bytea20 NOT NULL,
  override_id bytea20 NOT NULL,

  CONSTRAINT pk_timeperiod_override_exclude PRIMARY KEY (id)
);

ALTER TABLE timeperiod_override_exclude ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE timeperiod_override_exclude ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_override_exclude ALTER COLUMN timeperiod_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_override_exclude ALTER COLUMN override_id SET STORAGE PLAIN;

COMMENT ON COLUMN timeperiod_override_exclude.id IS 'sha1(environment.id + exclude_id + timeperiod_id)';
COMMENT ON COLUMN timeperiod_override_exclude.environment_id IS 'env.id';
COMMENT ON COLUMN timeperiod_override_exclude.timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN timeperiod_override_exclude.override_id IS 'timeperiod.id';

CREATE TABLE timeperiod_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  timeperiod_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_timeperiod_customvar PRIMARY KEY (id)
);

ALTER TABLE timeperiod_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE timeperiod_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_customvar ALTER COLUMN timeperiod_id SET STORAGE PLAIN;
ALTER TABLE timeperiod_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_timeperiod_customvar_timeperiod_id ON timeperiod_customvar(timeperiod_id, customvar_id);
CREATE INDEX idx_timeperiod_customvar_customvar_id ON timeperiod_customvar(customvar_id, timeperiod_id);

COMMENT ON COLUMN timeperiod_customvar.id IS 'sha1(environment.id + timeperiod_id + customvar_id)';
COMMENT ON COLUMN timeperiod_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN timeperiod_customvar.timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN timeperiod_customvar.customvar_id IS 'customvar.id';

CREATE TABLE customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,

  name citext NOT NULL,
  value text NOT NULL,

  CONSTRAINT pk_customvar PRIMARY KEY (id)
);

ALTER TABLE customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE customvar ALTER COLUMN name_checksum SET STORAGE PLAIN;

COMMENT ON COLUMN customvar.id IS 'sha1(environment.id + name + value)';
COMMENT ON COLUMN customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN customvar.name_checksum IS 'sha1(name)';

CREATE TABLE customvar_flat (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,
  flatname_checksum bytea20 NOT NULL,

  flatname citext NOT NULL,
  flatvalue text DEFAULT NULL,

  CONSTRAINT pk_customvar_flat PRIMARY KEY (id)
);

ALTER TABLE customvar_flat ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE customvar_flat ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE customvar_flat ALTER COLUMN customvar_id SET STORAGE PLAIN;
ALTER TABLE customvar_flat ALTER COLUMN flatname_checksum SET STORAGE PLAIN;

CREATE INDEX idx_customvar_flat_customvar_id ON customvar_flat(customvar_id);
CREATE INDEX idx_customvar_flat_flatname_flatvalue ON customvar_flat(flatname, flatvalue);

COMMENT ON COLUMN customvar_flat.id IS 'sha1(environment.id + flatname + flatvalue)';
COMMENT ON COLUMN customvar_flat.environment_id IS 'environment.id';
COMMENT ON COLUMN customvar_flat.customvar_id IS 'sha1(customvar.id)';
COMMENT ON COLUMN customvar_flat.flatname_checksum IS 'sha1(flatname after conversion)';
COMMENT ON COLUMN customvar_flat.flatname IS 'Path converted with `.` and `[ ]`';

COMMENT ON INDEX idx_customvar_flat_flatname_flatvalue IS 'Lists filtered by custom variable';

CREATE TABLE "user" (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,

  email varchar(255) NOT NULL,
  pager varchar(255) NOT NULL,

  notifications_enabled boolenum NOT NULL DEFAULT 'n',

  timeperiod_id bytea20 DEFAULT NULL,

  states tinyuint NOT NULL,
  types smalluint NOT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_user PRIMARY KEY (id)
);

ALTER TABLE "user" ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE "user" ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE "user" ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE "user" ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE "user" ALTER COLUMN timeperiod_id SET STORAGE PLAIN;
ALTER TABLE "user" ALTER COLUMN zone_id SET STORAGE PLAIN;

CREATE INDEX idx_user_display_name ON "user"(display_name);
CREATE INDEX idx_user_name_ci ON "user"(name_ci);
CREATE INDEX idx_user_name ON "user"(name);

COMMENT ON COLUMN "user".id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN "user".environment_id IS 'environment.id';
COMMENT ON COLUMN "user".name_checksum IS 'sha1(name)';
COMMENT ON COLUMN "user".properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN "user".timeperiod_id IS 'timeperiod.id';
COMMENT ON COLUMN "user".zone_id IS 'zone.id';

COMMENT ON INDEX idx_user_display_name IS 'User list filtered/ordered by display_name';
COMMENT ON INDEX idx_user_name_ci IS 'User list filtered using quick search';
COMMENT ON INDEX idx_user_name IS 'User list filtered/ordered by name; User detail filter';

CREATE TABLE usergroup (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,
  display_name citext NOT NULL,

  zone_id bytea20 DEFAULT NULL,

  CONSTRAINT pk_usergroup PRIMARY KEY (id)
);

ALTER TABLE usergroup ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE usergroup ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE usergroup ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE usergroup ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE usergroup ALTER COLUMN zone_id SET STORAGE PLAIN;

CREATE INDEX idx_usergroup_display_name ON usergroup(display_name);
CREATE INDEX idx_usergroup_name_ci ON usergroup(name_ci);
CREATE INDEX idx_usergroup_name ON usergroup(name);

COMMENT ON COLUMN usergroup.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN usergroup.environment_id IS 'environment.id';
COMMENT ON COLUMN usergroup.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN usergroup.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN usergroup.zone_id IS 'zone.id';

COMMENT ON INDEX idx_usergroup_display_name IS 'Usergroup list filtered/ordered by display_name';
COMMENT ON INDEX idx_usergroup_name_ci IS 'Usergroup list filtered using quick search';
COMMENT ON INDEX idx_usergroup_name IS 'Usergroup list filtered/ordered by name; User detail filter';

CREATE TABLE usergroup_member (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  user_id bytea20 NOT NULL,
  usergroup_id bytea20 NOT NULL,

  CONSTRAINT pk_usergroup_member PRIMARY KEY (id)
);

ALTER TABLE usergroup_member ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE usergroup_member ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE usergroup_member ALTER COLUMN user_id SET STORAGE PLAIN;
ALTER TABLE usergroup_member ALTER COLUMN usergroup_id SET STORAGE PLAIN;

CREATE INDEX idx_usergroup_member_user_id ON usergroup_member(user_id, usergroup_id);
CREATE INDEX idx_usergroup_member_usergroup_id ON usergroup_member(usergroup_id, user_id);

COMMENT ON COLUMN usergroup_member.id IS 'sha1(environment.id + usergroup_id + user_id)';
COMMENT ON COLUMN usergroup_member.environment_id IS 'environment.id';
COMMENT ON COLUMN usergroup_member.user_id IS 'user.id';
COMMENT ON COLUMN usergroup_member.usergroup_id IS 'usergroup.id';

CREATE TABLE user_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  user_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_user_customvar PRIMARY KEY (id)
);

ALTER TABLE user_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE user_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE user_customvar ALTER COLUMN user_id SET STORAGE PLAIN;
ALTER TABLE user_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_user_customvar_user_id ON user_customvar(user_id, customvar_id);
CREATE INDEX idx_user_customvar_customvar_id ON user_customvar(customvar_id, user_id);

COMMENT ON COLUMN user_customvar.id IS 'sha1(environment.id + user_id + customvar_id)';
COMMENT ON COLUMN user_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN user_customvar.user_id IS 'user.id';
COMMENT ON COLUMN user_customvar.customvar_id IS 'customvar.id';

CREATE TABLE usergroup_customvar (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  usergroup_id bytea20 NOT NULL,
  customvar_id bytea20 NOT NULL,

  CONSTRAINT pk_usergroup_customvar PRIMARY KEY (id)
);

ALTER TABLE usergroup_customvar ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE usergroup_customvar ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE usergroup_customvar ALTER COLUMN usergroup_id SET STORAGE PLAIN;
ALTER TABLE usergroup_customvar ALTER COLUMN customvar_id SET STORAGE PLAIN;

CREATE INDEX idx_usergroup_customvar_usergroup_id ON usergroup_customvar(usergroup_id, customvar_id);
CREATE INDEX idx_usergroup_customvar_customvar_id ON usergroup_customvar(customvar_id, usergroup_id);

COMMENT ON COLUMN usergroup_customvar.id IS 'sha1(environment.id + usergroup_id + customvar_id)';
COMMENT ON COLUMN usergroup_customvar.environment_id IS 'environment.id';
COMMENT ON COLUMN usergroup_customvar.usergroup_id IS 'usergroup.id';
COMMENT ON COLUMN usergroup_customvar.customvar_id IS 'customvar.id';

CREATE TABLE zone (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  name_checksum bytea20 NOT NULL,
  properties_checksum bytea20 NOT NULL,

  name varchar(255) NOT NULL,
  name_ci citext NOT NULL,

  is_global boolenum NOT NULL DEFAULT 'n',
  parent_id bytea20 DEFAULT NULL,

  depth tinyuint NOT NULL,

  CONSTRAINT pk_zone PRIMARY KEY (id)
);

ALTER TABLE zone ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE zone ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE zone ALTER COLUMN name_checksum SET STORAGE PLAIN;
ALTER TABLE zone ALTER COLUMN properties_checksum SET STORAGE PLAIN;
ALTER TABLE zone ALTER COLUMN parent_id SET STORAGE PLAIN;

CREATE UNIQUE INDEX idx_environment_id_id ON zone(environment_id, id);
CREATE INDEX idx_zone_parent_id ON zone(parent_id);

COMMENT ON COLUMN zone.id IS 'sha1(environment.id + name)';
COMMENT ON COLUMN zone.environment_id IS 'environment.id';
COMMENT ON COLUMN zone.name_checksum IS 'sha1(name)';
COMMENT ON COLUMN zone.properties_checksum IS 'sha1(all properties)';
COMMENT ON COLUMN zone.parent_id IS 'zone.id';

CREATE TABLE notification_history (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,
  notification_id bytea20 NOT NULL,

  type notification_type NOT NULL DEFAULT 'downtime_start',
  send_time biguint NOT NULL,
  state tinyuint NOT NULL,
  previous_hard_state tinyuint NOT NULL,
  author text NOT NULL,
  "text" text NOT NULL,
  users_notified smalluint NOT NULL,

  CONSTRAINT pk_notification_history PRIMARY KEY (id)
);

ALTER TABLE notification_history ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE notification_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE notification_history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE notification_history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE notification_history ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE notification_history ALTER COLUMN notification_id SET STORAGE PLAIN;

CREATE INDEX idx_notification_history_send_time ON notification_history(send_time DESC);
CREATE INDEX idx_notification_history_env_send_time ON notification_history(environment_id, send_time);

COMMENT ON COLUMN notification_history.id IS 'sha1(environment.name + notification.name + type + send_time)';
COMMENT ON COLUMN notification_history.environment_id IS 'environment.id';
COMMENT ON COLUMN notification_history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN notification_history.host_id IS 'host.id';
COMMENT ON COLUMN notification_history.service_id IS 'service.id';
COMMENT ON COLUMN notification_history.notification_id IS 'notification.id';

COMMENT ON INDEX idx_notification_history_send_time IS 'Notification list filtered/ordered by send_time';
COMMENT ON INDEX idx_notification_history_env_send_time IS 'Filter for history retention';

CREATE TABLE user_notification_history (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  notification_history_id bytea20 NOT NULL,
  user_id bytea20 NOT NULL,

  CONSTRAINT pk_user_notification_history PRIMARY KEY (id),

  CONSTRAINT fk_user_notification_history_notification_history FOREIGN KEY (notification_history_id) REFERENCES notification_history (id) ON DELETE CASCADE
);

ALTER TABLE user_notification_history ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE user_notification_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE user_notification_history ALTER COLUMN notification_history_id SET STORAGE PLAIN;
ALTER TABLE user_notification_history ALTER COLUMN user_id SET STORAGE PLAIN;

COMMENT ON COLUMN user_notification_history.id IS 'sha1(notification_history_id + user_id)';
COMMENT ON COLUMN user_notification_history.environment_id IS 'environment.id';
COMMENT ON COLUMN user_notification_history.notification_history_id IS 'UUID notification_history.id';
COMMENT ON COLUMN user_notification_history.user_id IS 'user.id';

CREATE TABLE state_history (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  event_time biguint NOT NULL,
  state_type state_type NOT NULL DEFAULT 'hard',
  soft_state tinyuint NOT NULL,
  hard_state tinyuint NOT NULL,
  previous_soft_state tinyuint NOT NULL,
  previous_hard_state tinyuint NOT NULL,
  check_attempt tinyuint NOT NULL,
  output text DEFAULT NULL,
  long_output text DEFAULT NULL,
  max_check_attempts uint NOT NULL,
  check_source text DEFAULT NULL,
  scheduling_source text DEFAULT NULL,

  CONSTRAINT pk_state_history PRIMARY KEY (id)
);

ALTER TABLE state_history ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE state_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE state_history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE state_history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE state_history ALTER COLUMN service_id SET STORAGE PLAIN;

CREATE INDEX idx_state_history_env_event_time ON state_history(environment_id, event_time);

COMMENT ON COLUMN state_history.id IS 'sha1(environment.name + host|service.name + event_time)';
COMMENT ON COLUMN state_history.environment_id IS 'environment.id';
COMMENT ON COLUMN state_history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN state_history.host_id IS 'host.id';
COMMENT ON COLUMN state_history.service_id IS 'service.id';

COMMENT ON INDEX idx_state_history_env_event_time IS 'Filter for history retention';

CREATE TABLE downtime_history (
  downtime_id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  triggered_by_id bytea20 DEFAULT NULL,
  parent_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  entry_time biguint NOT NULL,
  author citext NOT NULL,
  cancelled_by citext DEFAULT NULL,
  comment text NOT NULL,
  is_flexible boolenum NOT NULL DEFAULT 'n',
  flexible_duration biguint NOT NULL,
  scheduled_start_time biguint NOT NULL,
  scheduled_end_time biguint NOT NULL,
  start_time biguint NOT NULL,
  end_time biguint NOT NULL,
  scheduled_by varchar(767) DEFAULT NULL,
  has_been_cancelled boolenum NOT NULL DEFAULT 'n',
  trigger_time biguint NOT NULL,
  cancel_time biguint DEFAULT NULL,

  CONSTRAINT pk_downtime_history PRIMARY KEY (downtime_id)
);

ALTER TABLE downtime_history ALTER COLUMN downtime_id SET STORAGE PLAIN;
ALTER TABLE downtime_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE downtime_history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE downtime_history ALTER COLUMN triggered_by_id SET STORAGE PLAIN;
ALTER TABLE downtime_history ALTER COLUMN parent_id SET STORAGE PLAIN;
ALTER TABLE downtime_history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE downtime_history ALTER COLUMN service_id SET STORAGE PLAIN;

CREATE INDEX idx_downtime_history_env_end_time ON downtime_history(environment_id, end_time);

COMMENT ON COLUMN downtime_history.downtime_id IS 'downtime.id';
COMMENT ON COLUMN downtime_history.environment_id IS 'environment.id';
COMMENT ON COLUMN downtime_history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN downtime_history.triggered_by_id IS 'The ID of the downtime that triggered this downtime. This is set when creating downtimes on a host or service higher up in the dependency chain using the "child_option" "DowntimeTriggeredChildren" and can also be set manually via the API.';
COMMENT ON COLUMN downtime_history.parent_id IS 'For service downtimes, the ID of the host downtime that created this downtime by using the "all_services" flag of the schedule-downtime API.';
COMMENT ON COLUMN downtime_history.host_id IS 'host.id';
COMMENT ON COLUMN downtime_history.service_id IS 'service.id';
COMMENT ON COLUMN downtime_history.start_time IS 'Time when the host went into a problem state during the downtimes timeframe';
COMMENT ON COLUMN downtime_history.end_time IS 'Problem state assumed: scheduled_end_time if fixed, start_time + duration otherwise';
COMMENT ON COLUMN downtime_history.scheduled_by IS 'Name of the ScheduledDowntime which created this Downtime. 255+1+255+1+255, i.e. "host.name!service.name!scheduled-downtime-name"';

COMMENT ON INDEX idx_downtime_history_env_end_time IS 'Filter for history retention';

CREATE TABLE comment_history (
  comment_id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  entry_time biguint NOT NULL,
  author citext NOT NULL,
  removed_by citext DEFAULT NULL,
  comment text NOT NULL,
  entry_type comment_type NOT NULL DEFAULT 'comment',
  is_persistent boolenum NOT NULL DEFAULT 'n',
  is_sticky boolenum NOT NULL DEFAULT 'n',
  expire_time biguint DEFAULT NULL,
  remove_time biguint DEFAULT NULL,
  has_been_removed boolenum NOT NULL DEFAULT 'n',

  CONSTRAINT pk_comment_history PRIMARY KEY (comment_id)
);

ALTER TABLE comment_history ALTER COLUMN comment_id SET STORAGE PLAIN;
ALTER TABLE comment_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE comment_history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE comment_history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE comment_history ALTER COLUMN service_id SET STORAGE PLAIN;

CREATE INDEX idx_comment_history_env_remove_time ON comment_history(environment_id, remove_time);

COMMENT ON COLUMN comment_history.comment_id IS 'comment.id';
COMMENT ON COLUMN comment_history.environment_id IS 'environment.id';
COMMENT ON COLUMN comment_history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN comment_history.host_id IS 'host.id';
COMMENT ON COLUMN comment_history.service_id IS 'service.id';

COMMENT ON INDEX idx_comment_history_env_remove_time IS 'Filter for history retention';

CREATE TABLE flapping_history (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  start_time biguint NOT NULL,
  end_time biguint DEFAULT NULL,
  percent_state_change_start float DEFAULT NULL,
  percent_state_change_end float DEFAULT NULL,
  flapping_threshold_low float NOT NULL,
  flapping_threshold_high float NOT NULL,

  CONSTRAINT pk_flapping_history PRIMARY KEY (id)
);

ALTER TABLE flapping_history ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE flapping_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE flapping_history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE flapping_history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE flapping_history ALTER COLUMN service_id SET STORAGE PLAIN;

CREATE INDEX idx_flapping_history_env_end_time ON flapping_history(environment_id, end_time);

COMMENT ON COLUMN flapping_history.id IS 'sha1(environment.id + "Host"|"Service" + host|service.name + start_time)';
COMMENT ON COLUMN flapping_history.environment_id IS 'environment.id';
COMMENT ON COLUMN flapping_history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN flapping_history.host_id IS 'host.id';
COMMENT ON COLUMN flapping_history.service_id IS 'service.id';

COMMENT ON INDEX idx_flapping_history_env_end_time IS 'Filter for history retention';

CREATE TABLE acknowledgement_history (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  set_time biguint NOT NULL,
  clear_time biguint DEFAULT NULL,
  author citext DEFAULT NULL,
  cleared_by citext DEFAULT NULL,
  comment text DEFAULT NULL,
  expire_time biguint DEFAULT NULL,
  is_sticky boolenum DEFAULT NULL,
  is_persistent boolenum DEFAULT NULL,

  CONSTRAINT pk_acknowledgement_history PRIMARY KEY (id)
);

ALTER TABLE acknowledgement_history ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE acknowledgement_history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE acknowledgement_history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE acknowledgement_history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE acknowledgement_history ALTER COLUMN service_id SET STORAGE PLAIN;

CREATE INDEX idx_acknowledgement_history_env_clear_time ON acknowledgement_history(environment_id, clear_time);

COMMENT ON COLUMN acknowledgement_history.id IS 'sha1(environment.id + "Host"|"Service" + host|service.name + set_time)';
COMMENT ON COLUMN acknowledgement_history.environment_id IS 'environment.id';
COMMENT ON COLUMN acknowledgement_history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN acknowledgement_history.host_id IS 'host.id';
COMMENT ON COLUMN acknowledgement_history.service_id IS 'service.id';
COMMENT ON COLUMN acknowledgement_history.author IS 'NULL if ack_set event happened before Icinga DB history recording';
COMMENT ON COLUMN acknowledgement_history.comment IS 'NULL if ack_set event happened before Icinga DB history recording';
COMMENT ON COLUMN acknowledgement_history.is_sticky IS 'NULL if ack_set event happened before Icinga DB history recording';
COMMENT ON COLUMN acknowledgement_history.is_persistent IS 'NULL if ack_set event happened before Icinga DB history recording';

COMMENT ON INDEX idx_acknowledgement_history_env_clear_time IS 'Filter for history retention';

CREATE TABLE history (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL DEFAULT 'host',
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,
  notification_history_id bytea20 DEFAULT NULL,
  state_history_id bytea20 DEFAULT NULL,
  downtime_history_id bytea20 DEFAULT NULL,
  comment_history_id bytea20 DEFAULT NULL,
  flapping_history_id bytea20 DEFAULT NULL,
  acknowledgement_history_id bytea20 DEFAULT NULL,

  event_type history_type NOT NULL DEFAULT 'state_change',
  event_time biguint NOT NULL,

  CONSTRAINT pk_history PRIMARY KEY (id),

  CONSTRAINT fk_history_acknowledgement_history FOREIGN KEY (acknowledgement_history_id) REFERENCES acknowledgement_history (id) ON DELETE CASCADE,
  CONSTRAINT fk_history_comment_history FOREIGN KEY (comment_history_id) REFERENCES comment_history (comment_id) ON DELETE CASCADE,
  CONSTRAINT fk_history_downtime_history FOREIGN KEY (downtime_history_id) REFERENCES downtime_history (downtime_id) ON DELETE CASCADE,
  CONSTRAINT fk_history_flapping_history FOREIGN KEY (flapping_history_id) REFERENCES flapping_history (id) ON DELETE CASCADE,
  CONSTRAINT fk_history_notification_history FOREIGN KEY (notification_history_id) REFERENCES notification_history (id) ON DELETE CASCADE,
  CONSTRAINT fk_history_state_history FOREIGN KEY (state_history_id) REFERENCES state_history (id) ON DELETE CASCADE
);

ALTER TABLE history ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN notification_history_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN state_history_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN downtime_history_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN comment_history_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN flapping_history_id SET STORAGE PLAIN;
ALTER TABLE history ALTER COLUMN acknowledgement_history_id SET STORAGE PLAIN;

CREATE INDEX idx_history_event_time ON history(event_time);
CREATE INDEX idx_history_acknowledgement ON history(acknowledgement_history_id);
CREATE INDEX idx_history_comment ON history(comment_history_id);
CREATE INDEX idx_history_downtime ON history(downtime_history_id);
CREATE INDEX idx_history_flapping ON history(flapping_history_id);
CREATE INDEX idx_history_notification ON history(notification_history_id);
CREATE INDEX idx_history_state ON history(state_history_id);
CREATE INDEX idx_history_host_service_id ON history(host_id, service_id, event_time);

COMMENT ON COLUMN history.id IS 'sha1(environment.name + event_type + x...) given that sha1(environment.name + x...) = *_history_id';
COMMENT ON COLUMN history.environment_id IS 'environment.id';
COMMENT ON COLUMN history.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN history.host_id IS 'host.id';
COMMENT ON COLUMN history.service_id IS 'service.id';
COMMENT ON COLUMN history.notification_history_id IS 'notification_history.id';
COMMENT ON COLUMN history.state_history_id IS 'state_history.id';
COMMENT ON COLUMN history.downtime_history_id IS 'downtime_history.downtime_id';
COMMENT ON COLUMN history.comment_history_id IS 'comment_history.comment_id';
COMMENT ON COLUMN history.flapping_history_id IS 'flapping_history.id';
COMMENT ON COLUMN history.acknowledgement_history_id IS 'acknowledgement_history.id';

COMMENT ON INDEX idx_history_event_time IS 'History filtered/ordered by event_time';
COMMENT ON INDEX idx_history_host_service_id IS 'Host/service history detail filter';

CREATE TABLE sla_history_state (
  id bytea20 NOT NULL,
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL,
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  event_time biguint NOT NULL,
  hard_state tinyuint NOT NULL,
  previous_hard_state tinyuint NOT NULL,

  CONSTRAINT pk_sla_history_state PRIMARY KEY (id)
);

ALTER TABLE sla_history_state ALTER COLUMN id SET STORAGE PLAIN;
ALTER TABLE sla_history_state ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE sla_history_state ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE sla_history_state ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE sla_history_state ALTER COLUMN service_id SET STORAGE PLAIN;

CREATE INDEX idx_sla_history_state_event ON sla_history_state(host_id, service_id, event_time);
CREATE INDEX idx_sla_history_state_env_event_time ON sla_history_state (environment_id, event_time);

COMMENT ON COLUMN sla_history_state.id IS 'state_history.id (may reference already deleted rows)';
COMMENT ON COLUMN sla_history_state.environment_id IS 'environment.id';
COMMENT ON COLUMN sla_history_state.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN sla_history_state.host_id IS 'host.id';
COMMENT ON COLUMN sla_history_state.service_id IS 'service.id';
COMMENT ON COLUMN sla_history_state.event_time IS 'unix timestamp the event occurred';
COMMENT ON COLUMN sla_history_state.hard_state IS 'hard state after this event';
COMMENT ON COLUMN sla_history_state.previous_hard_state IS 'hard state before this event';

COMMENT ON INDEX idx_sla_history_state_event IS 'Filter for calculating the sla reports';
COMMENT ON INDEX idx_sla_history_state_env_event_time IS 'Filter for history retention';

CREATE TABLE sla_history_downtime (
  environment_id bytea20 NOT NULL,
  endpoint_id bytea20 DEFAULT NULL,
  object_type checkable_type NOT NULL,
  host_id bytea20 NOT NULL,
  service_id bytea20 DEFAULT NULL,

  downtime_id bytea20 NOT NULL,
  downtime_start biguint NOT NULL,
  downtime_end biguint NOT NULL,

  CONSTRAINT pk_sla_history_downtime PRIMARY KEY (downtime_id)
);

ALTER TABLE sla_history_downtime ALTER COLUMN environment_id SET STORAGE PLAIN;
ALTER TABLE sla_history_downtime ALTER COLUMN endpoint_id SET STORAGE PLAIN;
ALTER TABLE sla_history_downtime ALTER COLUMN host_id SET STORAGE PLAIN;
ALTER TABLE sla_history_downtime ALTER COLUMN service_id SET STORAGE PLAIN;
ALTER TABLE sla_history_downtime ALTER COLUMN downtime_id SET STORAGE PLAIN;

CREATE INDEX idx_sla_history_downtime_event ON sla_history_downtime(host_id, service_id, downtime_start, downtime_end);
CREATE INDEX idx_sla_history_downtime_env_downtime_end ON sla_history_downtime (environment_id, downtime_end);

COMMENT ON INDEX idx_sla_history_downtime_event IS 'Filter for calculating the sla reports';
COMMENT ON INDEX idx_sla_history_downtime_env_downtime_end IS 'Filter for sla history retention';

COMMENT ON COLUMN sla_history_downtime.environment_id IS 'environment.id';
COMMENT ON COLUMN sla_history_downtime.endpoint_id IS 'endpoint.id';
COMMENT ON COLUMN sla_history_downtime.host_id IS 'host.id';
COMMENT ON COLUMN sla_history_downtime.service_id IS 'service.id';
COMMENT ON COLUMN sla_history_downtime.downtime_id IS 'downtime.id (may reference already deleted rows)';
COMMENT ON COLUMN sla_history_downtime.downtime_start IS 'start time of the downtime';
COMMENT ON COLUMN sla_history_downtime.downtime_end IS 'end time of the downtime';

CREATE SEQUENCE icingadb_schema_id_seq;

CREATE TABLE icingadb_schema (
  id uint NOT NULL DEFAULT nextval('icingadb_schema_id_seq'),
  version smalluint NOT NULL,
  timestamp biguint NOT NULL,

  CONSTRAINT pk_icingadb_schema PRIMARY KEY (id)
);

ALTER SEQUENCE icingadb_schema_id_seq OWNED BY icingadb_schema.id;

INSERT INTO icingadb_schema (version, timestamp)
  VALUES (2, extract(epoch from now()) * 1000);