File: update.go

package info (click to toggle)
incus 6.0.5-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 24,392 kB
  • sloc: sh: 16,313; ansic: 3,121; python: 457; makefile: 337; ruby: 51; sql: 50; lisp: 6
file content (4711 lines) | stat: -rw-r--r-- 160,653 bytes parent folder | download
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
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
2235
2236
2237
2238
2239
2240
2241
2242
2243
2244
2245
2246
2247
2248
2249
2250
2251
2252
2253
2254
2255
2256
2257
2258
2259
2260
2261
2262
2263
2264
2265
2266
2267
2268
2269
2270
2271
2272
2273
2274
2275
2276
2277
2278
2279
2280
2281
2282
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303
2304
2305
2306
2307
2308
2309
2310
2311
2312
2313
2314
2315
2316
2317
2318
2319
2320
2321
2322
2323
2324
2325
2326
2327
2328
2329
2330
2331
2332
2333
2334
2335
2336
2337
2338
2339
2340
2341
2342
2343
2344
2345
2346
2347
2348
2349
2350
2351
2352
2353
2354
2355
2356
2357
2358
2359
2360
2361
2362
2363
2364
2365
2366
2367
2368
2369
2370
2371
2372
2373
2374
2375
2376
2377
2378
2379
2380
2381
2382
2383
2384
2385
2386
2387
2388
2389
2390
2391
2392
2393
2394
2395
2396
2397
2398
2399
2400
2401
2402
2403
2404
2405
2406
2407
2408
2409
2410
2411
2412
2413
2414
2415
2416
2417
2418
2419
2420
2421
2422
2423
2424
2425
2426
2427
2428
2429
2430
2431
2432
2433
2434
2435
2436
2437
2438
2439
2440
2441
2442
2443
2444
2445
2446
2447
2448
2449
2450
2451
2452
2453
2454
2455
2456
2457
2458
2459
2460
2461
2462
2463
2464
2465
2466
2467
2468
2469
2470
2471
2472
2473
2474
2475
2476
2477
2478
2479
2480
2481
2482
2483
2484
2485
2486
2487
2488
2489
2490
2491
2492
2493
2494
2495
2496
2497
2498
2499
2500
2501
2502
2503
2504
2505
2506
2507
2508
2509
2510
2511
2512
2513
2514
2515
2516
2517
2518
2519
2520
2521
2522
2523
2524
2525
2526
2527
2528
2529
2530
2531
2532
2533
2534
2535
2536
2537
2538
2539
2540
2541
2542
2543
2544
2545
2546
2547
2548
2549
2550
2551
2552
2553
2554
2555
2556
2557
2558
2559
2560
2561
2562
2563
2564
2565
2566
2567
2568
2569
2570
2571
2572
2573
2574
2575
2576
2577
2578
2579
2580
2581
2582
2583
2584
2585
2586
2587
2588
2589
2590
2591
2592
2593
2594
2595
2596
2597
2598
2599
2600
2601
2602
2603
2604
2605
2606
2607
2608
2609
2610
2611
2612
2613
2614
2615
2616
2617
2618
2619
2620
2621
2622
2623
2624
2625
2626
2627
2628
2629
2630
2631
2632
2633
2634
2635
2636
2637
2638
2639
2640
2641
2642
2643
2644
2645
2646
2647
2648
2649
2650
2651
2652
2653
2654
2655
2656
2657
2658
2659
2660
2661
2662
2663
2664
2665
2666
2667
2668
2669
2670
2671
2672
2673
2674
2675
2676
2677
2678
2679
2680
2681
2682
2683
2684
2685
2686
2687
2688
2689
2690
2691
2692
2693
2694
2695
2696
2697
2698
2699
2700
2701
2702
2703
2704
2705
2706
2707
2708
2709
2710
2711
2712
2713
2714
2715
2716
2717
2718
2719
2720
2721
2722
2723
2724
2725
2726
2727
2728
2729
2730
2731
2732
2733
2734
2735
2736
2737
2738
2739
2740
2741
2742
2743
2744
2745
2746
2747
2748
2749
2750
2751
2752
2753
2754
2755
2756
2757
2758
2759
2760
2761
2762
2763
2764
2765
2766
2767
2768
2769
2770
2771
2772
2773
2774
2775
2776
2777
2778
2779
2780
2781
2782
2783
2784
2785
2786
2787
2788
2789
2790
2791
2792
2793
2794
2795
2796
2797
2798
2799
2800
2801
2802
2803
2804
2805
2806
2807
2808
2809
2810
2811
2812
2813
2814
2815
2816
2817
2818
2819
2820
2821
2822
2823
2824
2825
2826
2827
2828
2829
2830
2831
2832
2833
2834
2835
2836
2837
2838
2839
2840
2841
2842
2843
2844
2845
2846
2847
2848
2849
2850
2851
2852
2853
2854
2855
2856
2857
2858
2859
2860
2861
2862
2863
2864
2865
2866
2867
2868
2869
2870
2871
2872
2873
2874
2875
2876
2877
2878
2879
2880
2881
2882
2883
2884
2885
2886
2887
2888
2889
2890
2891
2892
2893
2894
2895
2896
2897
2898
2899
2900
2901
2902
2903
2904
2905
2906
2907
2908
2909
2910
2911
2912
2913
2914
2915
2916
2917
2918
2919
2920
2921
2922
2923
2924
2925
2926
2927
2928
2929
2930
2931
2932
2933
2934
2935
2936
2937
2938
2939
2940
2941
2942
2943
2944
2945
2946
2947
2948
2949
2950
2951
2952
2953
2954
2955
2956
2957
2958
2959
2960
2961
2962
2963
2964
2965
2966
2967
2968
2969
2970
2971
2972
2973
2974
2975
2976
2977
2978
2979
2980
2981
2982
2983
2984
2985
2986
2987
2988
2989
2990
2991
2992
2993
2994
2995
2996
2997
2998
2999
3000
3001
3002
3003
3004
3005
3006
3007
3008
3009
3010
3011
3012
3013
3014
3015
3016
3017
3018
3019
3020
3021
3022
3023
3024
3025
3026
3027
3028
3029
3030
3031
3032
3033
3034
3035
3036
3037
3038
3039
3040
3041
3042
3043
3044
3045
3046
3047
3048
3049
3050
3051
3052
3053
3054
3055
3056
3057
3058
3059
3060
3061
3062
3063
3064
3065
3066
3067
3068
3069
3070
3071
3072
3073
3074
3075
3076
3077
3078
3079
3080
3081
3082
3083
3084
3085
3086
3087
3088
3089
3090
3091
3092
3093
3094
3095
3096
3097
3098
3099
3100
3101
3102
3103
3104
3105
3106
3107
3108
3109
3110
3111
3112
3113
3114
3115
3116
3117
3118
3119
3120
3121
3122
3123
3124
3125
3126
3127
3128
3129
3130
3131
3132
3133
3134
3135
3136
3137
3138
3139
3140
3141
3142
3143
3144
3145
3146
3147
3148
3149
3150
3151
3152
3153
3154
3155
3156
3157
3158
3159
3160
3161
3162
3163
3164
3165
3166
3167
3168
3169
3170
3171
3172
3173
3174
3175
3176
3177
3178
3179
3180
3181
3182
3183
3184
3185
3186
3187
3188
3189
3190
3191
3192
3193
3194
3195
3196
3197
3198
3199
3200
3201
3202
3203
3204
3205
3206
3207
3208
3209
3210
3211
3212
3213
3214
3215
3216
3217
3218
3219
3220
3221
3222
3223
3224
3225
3226
3227
3228
3229
3230
3231
3232
3233
3234
3235
3236
3237
3238
3239
3240
3241
3242
3243
3244
3245
3246
3247
3248
3249
3250
3251
3252
3253
3254
3255
3256
3257
3258
3259
3260
3261
3262
3263
3264
3265
3266
3267
3268
3269
3270
3271
3272
3273
3274
3275
3276
3277
3278
3279
3280
3281
3282
3283
3284
3285
3286
3287
3288
3289
3290
3291
3292
3293
3294
3295
3296
3297
3298
3299
3300
3301
3302
3303
3304
3305
3306
3307
3308
3309
3310
3311
3312
3313
3314
3315
3316
3317
3318
3319
3320
3321
3322
3323
3324
3325
3326
3327
3328
3329
3330
3331
3332
3333
3334
3335
3336
3337
3338
3339
3340
3341
3342
3343
3344
3345
3346
3347
3348
3349
3350
3351
3352
3353
3354
3355
3356
3357
3358
3359
3360
3361
3362
3363
3364
3365
3366
3367
3368
3369
3370
3371
3372
3373
3374
3375
3376
3377
3378
3379
3380
3381
3382
3383
3384
3385
3386
3387
3388
3389
3390
3391
3392
3393
3394
3395
3396
3397
3398
3399
3400
3401
3402
3403
3404
3405
3406
3407
3408
3409
3410
3411
3412
3413
3414
3415
3416
3417
3418
3419
3420
3421
3422
3423
3424
3425
3426
3427
3428
3429
3430
3431
3432
3433
3434
3435
3436
3437
3438
3439
3440
3441
3442
3443
3444
3445
3446
3447
3448
3449
3450
3451
3452
3453
3454
3455
3456
3457
3458
3459
3460
3461
3462
3463
3464
3465
3466
3467
3468
3469
3470
3471
3472
3473
3474
3475
3476
3477
3478
3479
3480
3481
3482
3483
3484
3485
3486
3487
3488
3489
3490
3491
3492
3493
3494
3495
3496
3497
3498
3499
3500
3501
3502
3503
3504
3505
3506
3507
3508
3509
3510
3511
3512
3513
3514
3515
3516
3517
3518
3519
3520
3521
3522
3523
3524
3525
3526
3527
3528
3529
3530
3531
3532
3533
3534
3535
3536
3537
3538
3539
3540
3541
3542
3543
3544
3545
3546
3547
3548
3549
3550
3551
3552
3553
3554
3555
3556
3557
3558
3559
3560
3561
3562
3563
3564
3565
3566
3567
3568
3569
3570
3571
3572
3573
3574
3575
3576
3577
3578
3579
3580
3581
3582
3583
3584
3585
3586
3587
3588
3589
3590
3591
3592
3593
3594
3595
3596
3597
3598
3599
3600
3601
3602
3603
3604
3605
3606
3607
3608
3609
3610
3611
3612
3613
3614
3615
3616
3617
3618
3619
3620
3621
3622
3623
3624
3625
3626
3627
3628
3629
3630
3631
3632
3633
3634
3635
3636
3637
3638
3639
3640
3641
3642
3643
3644
3645
3646
3647
3648
3649
3650
3651
3652
3653
3654
3655
3656
3657
3658
3659
3660
3661
3662
3663
3664
3665
3666
3667
3668
3669
3670
3671
3672
3673
3674
3675
3676
3677
3678
3679
3680
3681
3682
3683
3684
3685
3686
3687
3688
3689
3690
3691
3692
3693
3694
3695
3696
3697
3698
3699
3700
3701
3702
3703
3704
3705
3706
3707
3708
3709
3710
3711
3712
3713
3714
3715
3716
3717
3718
3719
3720
3721
3722
3723
3724
3725
3726
3727
3728
3729
3730
3731
3732
3733
3734
3735
3736
3737
3738
3739
3740
3741
3742
3743
3744
3745
3746
3747
3748
3749
3750
3751
3752
3753
3754
3755
3756
3757
3758
3759
3760
3761
3762
3763
3764
3765
3766
3767
3768
3769
3770
3771
3772
3773
3774
3775
3776
3777
3778
3779
3780
3781
3782
3783
3784
3785
3786
3787
3788
3789
3790
3791
3792
3793
3794
3795
3796
3797
3798
3799
3800
3801
3802
3803
3804
3805
3806
3807
3808
3809
3810
3811
3812
3813
3814
3815
3816
3817
3818
3819
3820
3821
3822
3823
3824
3825
3826
3827
3828
3829
3830
3831
3832
3833
3834
3835
3836
3837
3838
3839
3840
3841
3842
3843
3844
3845
3846
3847
3848
3849
3850
3851
3852
3853
3854
3855
3856
3857
3858
3859
3860
3861
3862
3863
3864
3865
3866
3867
3868
3869
3870
3871
3872
3873
3874
3875
3876
3877
3878
3879
3880
3881
3882
3883
3884
3885
3886
3887
3888
3889
3890
3891
3892
3893
3894
3895
3896
3897
3898
3899
3900
3901
3902
3903
3904
3905
3906
3907
3908
3909
3910
3911
3912
3913
3914
3915
3916
3917
3918
3919
3920
3921
3922
3923
3924
3925
3926
3927
3928
3929
3930
3931
3932
3933
3934
3935
3936
3937
3938
3939
3940
3941
3942
3943
3944
3945
3946
3947
3948
3949
3950
3951
3952
3953
3954
3955
3956
3957
3958
3959
3960
3961
3962
3963
3964
3965
3966
3967
3968
3969
3970
3971
3972
3973
3974
3975
3976
3977
3978
3979
3980
3981
3982
3983
3984
3985
3986
3987
3988
3989
3990
3991
3992
3993
3994
3995
3996
3997
3998
3999
4000
4001
4002
4003
4004
4005
4006
4007
4008
4009
4010
4011
4012
4013
4014
4015
4016
4017
4018
4019
4020
4021
4022
4023
4024
4025
4026
4027
4028
4029
4030
4031
4032
4033
4034
4035
4036
4037
4038
4039
4040
4041
4042
4043
4044
4045
4046
4047
4048
4049
4050
4051
4052
4053
4054
4055
4056
4057
4058
4059
4060
4061
4062
4063
4064
4065
4066
4067
4068
4069
4070
4071
4072
4073
4074
4075
4076
4077
4078
4079
4080
4081
4082
4083
4084
4085
4086
4087
4088
4089
4090
4091
4092
4093
4094
4095
4096
4097
4098
4099
4100
4101
4102
4103
4104
4105
4106
4107
4108
4109
4110
4111
4112
4113
4114
4115
4116
4117
4118
4119
4120
4121
4122
4123
4124
4125
4126
4127
4128
4129
4130
4131
4132
4133
4134
4135
4136
4137
4138
4139
4140
4141
4142
4143
4144
4145
4146
4147
4148
4149
4150
4151
4152
4153
4154
4155
4156
4157
4158
4159
4160
4161
4162
4163
4164
4165
4166
4167
4168
4169
4170
4171
4172
4173
4174
4175
4176
4177
4178
4179
4180
4181
4182
4183
4184
4185
4186
4187
4188
4189
4190
4191
4192
4193
4194
4195
4196
4197
4198
4199
4200
4201
4202
4203
4204
4205
4206
4207
4208
4209
4210
4211
4212
4213
4214
4215
4216
4217
4218
4219
4220
4221
4222
4223
4224
4225
4226
4227
4228
4229
4230
4231
4232
4233
4234
4235
4236
4237
4238
4239
4240
4241
4242
4243
4244
4245
4246
4247
4248
4249
4250
4251
4252
4253
4254
4255
4256
4257
4258
4259
4260
4261
4262
4263
4264
4265
4266
4267
4268
4269
4270
4271
4272
4273
4274
4275
4276
4277
4278
4279
4280
4281
4282
4283
4284
4285
4286
4287
4288
4289
4290
4291
4292
4293
4294
4295
4296
4297
4298
4299
4300
4301
4302
4303
4304
4305
4306
4307
4308
4309
4310
4311
4312
4313
4314
4315
4316
4317
4318
4319
4320
4321
4322
4323
4324
4325
4326
4327
4328
4329
4330
4331
4332
4333
4334
4335
4336
4337
4338
4339
4340
4341
4342
4343
4344
4345
4346
4347
4348
4349
4350
4351
4352
4353
4354
4355
4356
4357
4358
4359
4360
4361
4362
4363
4364
4365
4366
4367
4368
4369
4370
4371
4372
4373
4374
4375
4376
4377
4378
4379
4380
4381
4382
4383
4384
4385
4386
4387
4388
4389
4390
4391
4392
4393
4394
4395
4396
4397
4398
4399
4400
4401
4402
4403
4404
4405
4406
4407
4408
4409
4410
4411
4412
4413
4414
4415
4416
4417
4418
4419
4420
4421
4422
4423
4424
4425
4426
4427
4428
4429
4430
4431
4432
4433
4434
4435
4436
4437
4438
4439
4440
4441
4442
4443
4444
4445
4446
4447
4448
4449
4450
4451
4452
4453
4454
4455
4456
4457
4458
4459
4460
4461
4462
4463
4464
4465
4466
4467
4468
4469
4470
4471
4472
4473
4474
4475
4476
4477
4478
4479
4480
4481
4482
4483
4484
4485
4486
4487
4488
4489
4490
4491
4492
4493
4494
4495
4496
4497
4498
4499
4500
4501
4502
4503
4504
4505
4506
4507
4508
4509
4510
4511
4512
4513
4514
4515
4516
4517
4518
4519
4520
4521
4522
4523
4524
4525
4526
4527
4528
4529
4530
4531
4532
4533
4534
4535
4536
4537
4538
4539
4540
4541
4542
4543
4544
4545
4546
4547
4548
4549
4550
4551
4552
4553
4554
4555
4556
4557
4558
4559
4560
4561
4562
4563
4564
4565
4566
4567
4568
4569
4570
4571
4572
4573
4574
4575
4576
4577
4578
4579
4580
4581
4582
4583
4584
4585
4586
4587
4588
4589
4590
4591
4592
4593
4594
4595
4596
4597
4598
4599
4600
4601
4602
4603
4604
4605
4606
4607
4608
4609
4610
4611
4612
4613
4614
4615
4616
4617
4618
4619
4620
4621
4622
4623
4624
4625
4626
4627
4628
4629
4630
4631
4632
4633
4634
4635
4636
4637
4638
4639
4640
4641
4642
4643
4644
4645
4646
4647
4648
4649
4650
4651
4652
4653
4654
4655
4656
4657
4658
4659
4660
4661
4662
4663
4664
4665
4666
4667
4668
4669
4670
4671
4672
4673
4674
4675
4676
4677
4678
4679
4680
4681
4682
4683
4684
4685
4686
4687
4688
4689
4690
4691
4692
4693
4694
4695
4696
4697
4698
4699
4700
4701
4702
4703
4704
4705
4706
4707
4708
4709
4710
4711
package cluster

import (
	"context"
	"database/sql"
	"fmt"
	"strconv"
	"strings"
	"time"

	internalInstance "github.com/lxc/incus/v6/internal/instance"
	"github.com/lxc/incus/v6/internal/server/db/query"
	"github.com/lxc/incus/v6/internal/server/db/schema"
	"github.com/lxc/incus/v6/shared/logger"
	"github.com/lxc/incus/v6/shared/osarch"
)

// Schema for the cluster database.
func Schema() *schema.Schema {
	schema := schema.NewFromMap(updates)
	schema.Fresh(freshSchema)
	return schema
}

// FreshSchema returns the fresh schema definition of the global database.
func FreshSchema() string {
	return freshSchema
}

// SchemaDotGo refreshes the schema.go file in this package, using the updates
// defined here.
func SchemaDotGo() error {
	return schema.DotGo(updates, "schema")
}

// SchemaVersion is the current version of the cluster database schema.
var SchemaVersion = len(updates)

var updates = map[int]schema.Update{
	1:  updateFromV0,
	2:  updateFromV1,
	3:  updateFromV2,
	4:  updateFromV3,
	5:  updateFromV4,
	6:  updateFromV5,
	7:  updateFromV6,
	8:  updateFromV7,
	9:  updateFromV8,
	10: updateFromV9,
	11: updateFromV10,
	12: updateFromV11,
	13: updateFromV12,
	14: updateFromV13,
	15: updateFromV14,
	16: updateFromV15,
	17: updateFromV16,
	18: updateFromV17,
	19: updateFromV18,
	20: updateFromV19,
	21: updateFromV20,
	22: updateFromV21,
	23: updateFromV22,
	24: updateFromV23,
	25: updateFromV24,
	26: updateFromV25,
	27: updateFromV26,
	28: updateFromV27,
	29: updateFromV28,
	30: updateFromV29,
	31: updateFromV30,
	32: updateFromV31,
	33: updateFromV32,
	34: updateFromV33,
	35: updateFromV34,
	36: updateFromV35,
	37: updateFromV36,
	38: updateFromV37,
	39: updateFromV38,
	40: updateFromV39,
	41: updateFromV40,
	42: updateFromV41,
	43: updateFromV42,
	44: updateFromV43,
	45: updateFromV44,
	46: updateFromV45,
	47: updateFromV46,
	48: updateFromV47,
	49: updateFromV48,
	50: updateFromV49,
	51: updateFromV50,
	52: updateFromV51,
	53: updateFromV52,
	54: updateFromV53,
	55: updateFromV54,
	56: updateFromV55,
	57: updateFromV56,
	58: updateFromV57,
	59: updateFromV58,
	60: updateFromV59,
	61: updateFromV60,
	62: updateFromV61,
	63: updateFromV62,
	64: updateFromV63,
	65: updateFromV64,
	66: updateFromV65,
	67: updateFromV66,
	68: updateFromV67,
	69: updateFromV68,
	70: updateFromV69,
	71: updateFromV70,
	72: updateFromV71,
	73: updateFromV72,
}

// updateFromV72 removes the openfga.store.model_id server config key.
func updateFromV72(ctx context.Context, tx *sql.Tx) error {
	q := `DELETE FROM config WHERE key='openfga.store.model_id';`
	_, err := tx.Exec(q)
	if err != nil {
		return fmt.Errorf("Failed adding network integration support: %w", err)
	}

	return nil
}

// updateFromV71 adds network integration support.
func updateFromV71(ctx context.Context, tx *sql.Tx) error {
	q := `
CREATE TABLE networks_integrations (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    type INTEGER NOT NULL,
    UNIQUE (name)
);

CREATE TABLE networks_integrations_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_integration_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_integration_id, key),
    FOREIGN KEY (network_integration_id) REFERENCES networks_integrations (id) ON DELETE CASCADE
);

ALTER TABLE networks_peers ADD COLUMN type INTEGER NOT NULL DEFAULT 0;
ALTER TABLE networks_peers ADD COLUMN target_network_integration_id INTEGER DEFAULT NULL REFERENCES networks_integrations (id) ON DELETE CASCADE;
CREATE UNIQUE INDEX networks_peers_unique_network_id_target_network_integration_id ON "networks_peers" (network_id, target_network_integration_id);
`
	_, err := tx.Exec(q)
	if err != nil {
		return fmt.Errorf("Failed adding network integration support: %w", err)
	}

	return nil
}

func updateFromV70(ctx context.Context, tx *sql.Tx) error {
	q := `
CREATE TABLE "storage_buckets_backups" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_bucket_id INTEGER NOT NULL,
    name VARCHAR(255) NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    FOREIGN KEY (storage_bucket_id) REFERENCES "storage_buckets" (id) ON DELETE CASCADE,
    UNIQUE (storage_bucket_id, name)
);
`
	_, err := tx.Exec(q)
	if err != nil {
		return fmt.Errorf("Failed adding storage bucket backup table: %w", err)
	}

	return nil
}

// updateFromV69 adds description column to certificate.
func updateFromV69(ctx context.Context, tx *sql.Tx) error {
	q := `
	ALTER TABLE certificates ADD COLUMN description TEXT NOT NULL DEFAULT "";
	`
	_, err := tx.Exec(q)
	if err != nil {
		return fmt.Errorf("Failed adding description column to certificate: %w", err)
	}

	return nil
}

// updateFromV68 fixes unique index for record name to make it zone specific.
func updateFromV68(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE networks_zones_records_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    entries TEXT NOT NULL,
    UNIQUE (network_zone_id, name),
    FOREIGN KEY (network_zone_id) REFERENCES networks_zones (id) ON DELETE CASCADE
);

CREATE TABLE networks_zones_records_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_record_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_zone_record_id, key),
    FOREIGN KEY (network_zone_record_id) REFERENCES networks_zones_records_new (id) ON DELETE CASCADE
);

INSERT INTO "networks_zones_records_new" SELECT * FROM "networks_zones_records";
INSERT INTO "networks_zones_records_config_new" SELECT * FROM "networks_zones_records_config";

DROP TABLE "networks_zones_records";
ALTER TABLE "networks_zones_records_new" RENAME TO "networks_zones_records";

DROP TABLE "networks_zones_records_config";
ALTER TABLE "networks_zones_records_config_new" RENAME TO "networks_zones_records_config";
`)
	if err != nil {
		return fmt.Errorf("Failed altering network_zones_records schema: %w", err)
	}

	return nil
}

// updateFromV67 adds features.networks.zones=true to any project that has features.networks=true.
func updateFromV67(ctx context.Context, tx *sql.Tx) error {
	// Find projects that have features.networks=true.
	rows, err := tx.QueryContext(ctx, `
SELECT
    projects.id
FROM projects
JOIN
    projects_config ON projects_config.project_id = projects.id
    AND projects_config.key = "features.networks"
    AND projects_config.value = "true"
	`)
	if err != nil {
		return fmt.Errorf("Failed finding projects with features.networks=true: %w", err)
	}

	defer func() { _ = rows.Close() }()

	var projectIDs []int64
	for rows.Next() {
		var projectID int64

		err := rows.Scan(&projectID)
		if err != nil {
			return fmt.Errorf("Failed scanning project ID row: %w", err)
		}

		projectIDs = append(projectIDs, projectID)
	}

	_ = rows.Close()

	// Add features.networks.zones=true to any project that has features.networks=true.
	for _, projectID := range projectIDs {
		_, err = tx.Exec(`INSERT OR REPLACE INTO projects_config (project_id,key,value) VALUES(?,?,?);`, projectID, "features.networks.zones", "true")
		if err != nil {
			return fmt.Errorf("Failed adding features.networks.zones=true to project ID %q: %w", projectID, err)
		}

		logger.Info("Added features.networks.zones=true on project with features.networks=true", logger.Ctx{"projectID": projectID})
	}

	return nil
}

// updateFromV66 adds creation_date column to storage_volumes and storage_volumes_snapshots tables.
func updateFromV66(ctx context.Context, tx *sql.Tx) error {
	q := `
ALTER TABLE storage_volumes ADD COLUMN creation_date DATETIME NOT NULL DEFAULT "0001-01-01T00:00:00Z";
ALTER TABLE storage_volumes_snapshots ADD COLUMN creation_date DATETIME NOT NULL DEFAULT "0001-01-01T00:00:00Z";
DROP VIEW storage_volumes_all;
CREATE VIEW storage_volumes_all (
    id,
    name,
    storage_pool_id,
    node_id,
    type,
    description,
    project_id,
    content_type,
    creation_date) AS
        SELECT id,
            name,
            storage_pool_id,
            node_id,
            type,
            description,
            project_id,
            content_type,
            creation_date
        FROM storage_volumes UNION
            SELECT storage_volumes_snapshots.id,
                printf('%s/%s', storage_volumes.name, storage_volumes_snapshots.name),
                storage_volumes.storage_pool_id,
                storage_volumes.node_id,
                storage_volumes.type,
                storage_volumes_snapshots.description,
                storage_volumes.project_id,
                storage_volumes.content_type,
                storage_volumes_snapshots.creation_date
            FROM storage_volumes
            JOIN storage_volumes_snapshots ON storage_volumes.id = storage_volumes_snapshots.storage_volume_id;
`
	_, err := tx.Exec(q)
	if err != nil {
		return fmt.Errorf("Failed adding creation_date column to storage volumes: %w", err)
	}

	return nil
}

// updateFromV65 fixes typo in cephobject.radosgw.endpoint* settings.
func updateFromV65(ctx context.Context, tx *sql.Tx) error {
	q := `
UPDATE storage_pools_config
    SET key = REPLACE(key, "cephobject.radosgsw.endpoint", "cephobject.radosgw.endpoint")
    WHERE key IN ("cephobject.radosgsw.endpoint", "cephobject.radosgsw.endpoint_cert_file")
	`
	_, err := tx.Exec(q)
	if err != nil {
		return fmt.Errorf("Failed replacing storage pool config cephobject.radosgsw.endpoint* with cephobject.radosgw.endpoint*: %w", err)
	}

	return nil
}

// updatefromV64 updates nodes_cluster_groups to include an ID field so that it works well with generate-database.
func updateFromV64(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "nodes_cluster_groups_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    group_id INTEGER NOT NULL,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (group_id) REFERENCES cluster_groups (id) ON DELETE CASCADE,
    UNIQUE (node_id, group_id)
);

INSERT INTO nodes_cluster_groups_new (node_id, group_id)
    SELECT node_id, group_id FROM nodes_cluster_groups;

DROP TABLE nodes_cluster_groups;

ALTER TABLE nodes_cluster_groups_new RENAME TO nodes_cluster_groups;
`)
	if err != nil {
		return fmt.Errorf("Failed altering nodes_cluster_groups table: %w", err)
	}

	return nil
}

// updateFromV63 creates the storage buckets tables and adds features.storage.buckets=true to all projects that
// have features.storage.volumes=true.
func updateFromV63(ctx context.Context, tx *sql.Tx) error {
	// Find all projects that have features.storage.volumes=true and add features.storage.buckets=true.
	rows, err := tx.QueryContext(ctx, `SELECT project_id FROM projects_config WHERE key = "features.storage.volumes" AND value = "true"`)
	if err != nil {
		return fmt.Errorf("Failed getting projects with features.storage.volumes=true: %w", err)
	}

	defer func() { _ = rows.Close() }()

	var projectIDs []int64

	for rows.Next() {
		var projectID int64
		err = rows.Scan(&projectID)
		if err != nil {
			return fmt.Errorf("Failed scanning project ID row: %w", err)
		}

		projectIDs = append(projectIDs, projectID)
	}

	err = rows.Err()
	if err != nil {
		return fmt.Errorf("Got a row error getting projects with features.storage.volumes=true: %w", err)
	}

	for _, projectID := range projectIDs {
		_, err = tx.Exec(`INSERT OR REPLACE INTO projects_config (project_id,key,value) VALUES(?,?,?);`, projectID, "features.storage.buckets", "true")
		if err != nil {
			return fmt.Errorf("Failed adding features.storage.buckets=true to projects: %w", err)
		}
	}

	// Create storage buckets tables.
	_, err = tx.Exec(`
CREATE TABLE IF NOT EXISTS "storage_buckets" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER,
    description TEXT NOT NULL,
    project_id INTEGER NOT NULL,
    UNIQUE (node_id, name),
    FOREIGN KEY (storage_pool_id) REFERENCES "storage_pools" (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES "nodes" (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES "projects" (id) ON DELETE CASCADE
);
CREATE UNIQUE INDEX storage_buckets_unique_storage_pool_id_node_id_name ON "storage_buckets" (storage_pool_id, IFNULL(node_id, -1), name);

CREATE TABLE "storage_buckets_config" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_bucket_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (storage_bucket_id, key),
    FOREIGN KEY (storage_bucket_id) REFERENCES "storage_buckets" (id) ON DELETE CASCADE
);

CREATE TABLE "storage_buckets_keys" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_bucket_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    access_key TEXT NOT NULL,
    secret_key TEXT NOT NULL,
    role TEXT NOT NULL,
    UNIQUE (storage_bucket_id, name),
    FOREIGN KEY (storage_bucket_id) REFERENCES "storage_buckets" (id) ON DELETE CASCADE
);
`)
	if err != nil {
		return fmt.Errorf("Failed adding storage bucket tables: %w", err)
	}

	return nil
}

// updateFromV62 adds unique index to storage_volumes that prevents duplicate volumes when using remote storage
// pool where the node_id column is NULL.
// Also ensures that the default project has features.networks set to true.
func updateFromV62(ctx context.Context, tx *sql.Tx) error {
	// Find the default project ID, and what it has features.networks config key set to (if at all).
	rows := tx.QueryRowContext(ctx, `
SELECT
    projects.id,
    IFNULL(projects_config.key, "") as key,
    IFNULL(projects_config.value, "") as value
FROM projects
LEFT JOIN
    projects_config ON projects_config.project_id = projects.id
    AND projects_config.key = "features.networks"
WHERE projects.name = "default"
`)

	var defaultProjectID int64
	var featureKey, featureValue string

	err := rows.Scan(&defaultProjectID, &featureKey, &featureValue)
	if err != nil {
		return fmt.Errorf("Failed scanning default project row: %w", err)
	}

	// If the features.networks key is missing or not set to true, insert/replace the correct row.
	if featureKey == "" || featureValue != "true" {
		_, err = tx.Exec(`INSERT OR REPLACE INTO projects_config (project_id,key,value) VALUES(?,?,?);`, defaultProjectID, "features.networks", "true")
		if err != nil {
			return fmt.Errorf("Failed adding features.networks=true to default project: %w", err)
		}
	}

	// Create unique index on storage_volumes that protects against duplicate volumes when using remote
	// storage pool where the node_id field is NULL (which the current unique index doesn't protect against).
	_, err = tx.Exec(`CREATE UNIQUE INDEX storage_volumes_unique_storage_pool_id_node_id_project_id_name_type ON "storage_volumes" (storage_pool_id, IFNULL(node_id, -1), project_id, name, type);`)
	if err != nil {
		return fmt.Errorf("Failed adding storage volumes unique index: %w", err)
	}

	return nil
}

// updateFromV61 converts config value fields to NOT NULL and config key fields to TEXT (from VARCHAR).
func updateFromV61(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "instances_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (instance_id) REFERENCES "instances" (id) ON DELETE CASCADE,
    UNIQUE (instance_id, key)
);

INSERT INTO "instances_config_new" SELECT * FROM "instances_config";
DROP TABLE "instances_config";
ALTER TABLE "instances_config_new" RENAME TO "instances_config";

CREATE TABLE "instances_devices_config_new" (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (instance_device_id) REFERENCES "instances_devices" (id) ON DELETE CASCADE,
    UNIQUE (instance_device_id, key)
);

INSERT INTO "instances_devices_config_new" SELECT * FROM "instances_devices_config";
DROP TABLE "instances_devices_config";
ALTER TABLE "instances_devices_config_new" RENAME TO "instances_devices_config";

CREATE TABLE "instances_snapshots_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    instance_snapshot_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (instance_snapshot_id) REFERENCES "instances_snapshots" (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_id, key)
);

INSERT INTO "instances_snapshots_config_new" SELECT * FROM "instances_snapshots_config";
DROP TABLE "instances_snapshots_config";
ALTER TABLE "instances_snapshots_config_new" RENAME TO "instances_snapshots_config";

CREATE TABLE "instances_snapshots_devices_config_new" (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_snapshot_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (instance_snapshot_device_id) REFERENCES "instances_snapshots_devices" (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_device_id, key)
);

INSERT INTO "instances_snapshots_devices_config_new" SELECT * FROM "instances_snapshots_devices_config";
DROP TABLE "instances_snapshots_devices_config";
ALTER TABLE "instances_snapshots_devices_config_new" RENAME TO "instances_snapshots_devices_config";

CREATE TABLE "networks_acls_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_acl_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_acl_id, key),
    FOREIGN KEY (network_acl_id) REFERENCES "networks_acls" (id) ON DELETE CASCADE
);

INSERT INTO "networks_acls_config_new" SELECT * FROM "networks_acls_config";
DROP TABLE "networks_acls_config";
ALTER TABLE "networks_acls_config_new" RENAME TO "networks_acls_config";

CREATE TABLE "networks_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_id, node_id, key),
    FOREIGN KEY (network_id) REFERENCES "networks" (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES "nodes" (id) ON DELETE CASCADE
);

INSERT INTO "networks_config_new" SELECT * FROM "networks_config";
DROP TABLE "networks_config";
ALTER TABLE "networks_config_new" RENAME TO "networks_config";

CREATE UNIQUE INDEX networks_unique_network_id_node_id_key ON "networks_config" (network_id, IFNULL(node_id, -1), key);

CREATE TABLE "networks_forwards_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_forward_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_forward_id, key),
    FOREIGN KEY (network_forward_id) REFERENCES "networks_forwards" (id) ON DELETE CASCADE
);

INSERT INTO "networks_forwards_config_new" SELECT * FROM "networks_forwards_config";
DROP TABLE "networks_forwards_config";
ALTER TABLE "networks_forwards_config_new" RENAME TO "networks_forwards_config";

CREATE TABLE "networks_peers_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_peer_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_peer_id, key),
    FOREIGN KEY (network_peer_id) REFERENCES "networks_peers" (id) ON DELETE CASCADE
);

INSERT INTO "networks_peers_config_new" SELECT * FROM "networks_peers_config";
DROP TABLE "networks_peers_config";
ALTER TABLE "networks_peers_config_new" RENAME TO "networks_peers_config";

CREATE TABLE "networks_zones_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_zone_id, key),
    FOREIGN KEY (network_zone_id) REFERENCES "networks_zones" (id) ON DELETE CASCADE
);

INSERT INTO "networks_zones_config_new" SELECT * FROM "networks_zones_config";
DROP TABLE "networks_zones_config";
ALTER TABLE "networks_zones_config_new" RENAME TO "networks_zones_config";

CREATE TABLE networks_zones_records_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_record_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_zone_record_id, key),
    FOREIGN KEY (network_zone_record_id) REFERENCES networks_zones_records (id) ON DELETE CASCADE
);

INSERT INTO "networks_zones_records_config_new" SELECT * FROM "networks_zones_records_config";
DROP TABLE "networks_zones_records_config";
ALTER TABLE "networks_zones_records_config_new" RENAME TO "networks_zones_records_config";

CREATE TABLE "nodes_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (node_id) REFERENCES "nodes" (id) ON DELETE CASCADE,
    UNIQUE (node_id, key)
);

INSERT INTO "nodes_config_new" SELECT * FROM "nodes_config";
DROP TABLE "nodes_config";
ALTER TABLE "nodes_config_new" RENAME TO "nodes_config";

CREATE TABLE "profiles_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (profile_id, key),
    FOREIGN KEY (profile_id) REFERENCES "profiles"(id) ON DELETE CASCADE
);

INSERT INTO "profiles_config_new" SELECT * FROM "profiles_config";
DROP TABLE "profiles_config";
ALTER TABLE "profiles_config_new" RENAME TO "profiles_config";

CREATE TABLE "profiles_devices_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (profile_device_id, key),
    FOREIGN KEY (profile_device_id) REFERENCES "profiles_devices" (id) ON DELETE CASCADE
);

INSERT INTO "profiles_devices_config_new" SELECT * FROM "profiles_devices_config";
DROP TABLE "profiles_devices_config";
ALTER TABLE "profiles_devices_config_new" RENAME TO "profiles_devices_config";

CREATE TABLE "projects_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (project_id) REFERENCES "projects" (id) ON DELETE CASCADE,
    UNIQUE (project_id, key)
);

INSERT INTO "projects_config_new" SELECT * FROM "projects_config";
DROP TABLE "projects_config";
ALTER TABLE "projects_config_new" RENAME TO "projects_config";

CREATE TABLE "storage_pools_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (storage_pool_id, node_id, key),
    FOREIGN KEY (storage_pool_id) REFERENCES "storage_pools" (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES "nodes" (id) ON DELETE CASCADE
);

INSERT INTO "storage_pools_config_new" SELECT * FROM "storage_pools_config";
DROP TABLE "storage_pools_config";
ALTER TABLE "storage_pools_config_new" RENAME TO "storage_pools_config";

CREATE UNIQUE INDEX storage_pools_unique_storage_pool_id_node_id_key ON storage_pools_config (storage_pool_id, IFNULL(node_id, -1), key);

CREATE TABLE "storage_volumes_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (storage_volume_id, key),
    FOREIGN KEY (storage_volume_id) REFERENCES "storage_volumes" (id) ON DELETE CASCADE
);

INSERT INTO "storage_volumes_config_new" SELECT * FROM "storage_volumes_config";
DROP TABLE "storage_volumes_config";
ALTER TABLE "storage_volumes_config_new" RENAME TO "storage_volumes_config";

CREATE TABLE "storage_volumes_snapshots_config_new" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_snapshot_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    FOREIGN KEY (storage_volume_snapshot_id) REFERENCES "storage_volumes_snapshots" (id) ON DELETE CASCADE,
    UNIQUE (storage_volume_snapshot_id, key)
);

INSERT INTO "storage_volumes_snapshots_config_new" SELECT * FROM "storage_volumes_snapshots_config";
DROP TABLE "storage_volumes_snapshots_config";
ALTER TABLE "storage_volumes_snapshots_config_new" RENAME TO "storage_volumes_snapshots_config";
`)
	if err != nil {
		return fmt.Errorf("Failed altering config tables schema: %w", err)
	}

	return nil
}

// updateFromV60 creates the networks_load_balancers and networks_load_balancers_config tables.
func updateFromV60(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "networks_load_balancers" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    listen_address TEXT NOT NULL,
    description TEXT NOT NULL,
    backends TEXT NOT NULL,
    ports TEXT NOT NULL,
    UNIQUE (network_id, node_id, listen_address),
    FOREIGN KEY (network_id) REFERENCES "networks" (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES "nodes" (id) ON DELETE CASCADE
);

CREATE TABLE "networks_load_balancers_config" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_load_balancer_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT NOT NULL,
    UNIQUE (network_load_balancer_id, key),
    FOREIGN KEY (network_load_balancer_id) REFERENCES "networks_load_balancers" (id) ON DELETE CASCADE
);
`)
	if err != nil {
		return fmt.Errorf("Failed creating network load balancers tables: %w", err)
	}

	return nil
}

func updateFromV59(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE networks_zones_records (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    entries TEXT NOT NULL,
    UNIQUE (name),
    FOREIGN KEY (network_zone_id) REFERENCES networks_zones (id) ON DELETE CASCADE
);

CREATE TABLE networks_zones_records_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_record_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_zone_record_id, key),
    FOREIGN KEY (network_zone_record_id) REFERENCES networks_zones_records (id) ON DELETE CASCADE
);
`)
	if err != nil {
		return fmt.Errorf("Failed creating network zone records tables: %w", err)
	}

	return nil
}

func updateFromV58(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
UPDATE sqlite_sequence SET seq = (
    SELECT max(
        (SELECT coalesce(max(storage_volumes.id), 0) FROM storage_volumes),
        (SELECT coalesce(max(storage_volumes_snapshots.id), 0)
    FROM storage_volumes_snapshots)))
WHERE name='storage_volumes';
`)

	return err
}

func updateFromV57(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
UPDATE sqlite_sequence SET seq = (
    SELECT coalesce(max(max(coalesce(storage_volumes.id, 0)), max(coalesce(storage_volumes_snapshots.id, 0))), 0)
    FROM storage_volumes, storage_volumes_snapshots)
WHERE name='storage_volumes';
`)

	return err
}

func updateFromV56(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
UPDATE sqlite_sequence SET seq = (
    SELECT max(max(coalesce(storage_volumes.id, 0)), max(coalesce(storage_volumes_snapshots.id, 0)))
    FROM storage_volumes, storage_volumes_snapshots)
WHERE name='storage_volumes';
`)

	return err
}

func updateFromV55(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
DROP VIEW storage_volumes_all;

CREATE TABLE projects_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    UNIQUE (name)
);

INSERT INTO projects_new (id, name, description) SELECT id, name, IFNULL(description, '') FROM projects;

CREATE TABLE certificates_projects_new (
    certificate_id INTEGER NOT NULL,
    project_id INTEGER NOT NULL,
    FOREIGN KEY (certificate_id) REFERENCES certificates (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE,
    UNIQUE (certificate_id, project_id)
);

INSERT INTO certificates_projects_new (certificate_id, project_id) SELECT certificate_id, project_id FROM certificates_projects;

CREATE TABLE images_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    fingerprint TEXT NOT NULL,
    filename TEXT NOT NULL,
    size INTEGER NOT NULL,
    public INTEGER NOT NULL DEFAULT 0,
    architecture INTEGER NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    upload_date DATETIME NOT NULL,
    cached INTEGER NOT NULL DEFAULT 0,
    last_use_date DATETIME,
    auto_update INTEGER NOT NULL DEFAULT 0,
    project_id INTEGER NOT NULL,
    type INTEGER NOT NULL DEFAULT 0,
    UNIQUE (project_id, fingerprint),
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO images_new (id, fingerprint, filename, size, public, architecture, creation_date, expiry_date, upload_date, cached, last_use_date, auto_update, project_id, type)
    SELECT id, fingerprint, filename, size, public, architecture, creation_date, expiry_date, upload_date, cached, last_use_date, auto_update, project_id, type FROM images;

CREATE TABLE images_aliases_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    image_id INTEGER NOT NULL,
    description TEXT NOT NULL,
    project_id INTEGER NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (image_id) REFERENCES images_new (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO images_aliases_new (id, name, image_id, description, project_id)
    SELECT id, name, image_id, IFNULL(description, ''), project_id FROM images_aliases;

CREATE TABLE nodes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    address TEXT NOT NULL,
    schema INTEGER NOT NULL,
    api_extensions INTEGER NOT NULL,
    heartbeat DATETIME DEFAULT CURRENT_TIMESTAMP,
    state INTEGER NOT NULL DEFAULT 0,
    arch INTEGER NOT NULL DEFAULT 0 CHECK (arch > 0),
    failure_domain_id INTEGER DEFAULT NULL REFERENCES nodes_failure_domains (id) ON DELETE SET NULL,
    UNIQUE (name),
    UNIQUE (address)
);

INSERT INTO nodes_new (id, name, description, address, schema, api_extensions, heartbeat, state, arch, failure_domain_id)
    SELECT id, name, IFNULL(description, ''), address, schema, api_extensions, heartbeat, state, arch, failure_domain_id FROM nodes;

CREATE TABLE images_nodes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    image_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    UNIQUE (image_id, node_id),
    FOREIGN KEY (image_id) REFERENCES images_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE
);

INSERT INTO images_nodes_new (id, image_id, node_id)
    SELECT id, image_id, node_id FROM images_nodes;

CREATE TABLE profiles_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    project_id INTEGER NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO profiles_new (id, name, description, project_id)
    SELECT id, name, IFNULL(description, ''), project_id FROM profiles;

CREATE TABLE images_profiles_new (
    image_id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    FOREIGN KEY (image_id) REFERENCES images_new (id) ON DELETE CASCADE,
    FOREIGN KEY (profile_id) REFERENCES profiles_new (id) ON DELETE CASCADE,
    UNIQUE (image_id, profile_id)
);

INSERT INTO images_profiles_new (image_id, profile_id)
    SELECT image_id, profile_id FROM images_profiles;

CREATE TABLE images_properties_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    image_id INTEGER NOT NULL,
    type INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (image_id) REFERENCES images_new (id) ON DELETE CASCADE
);

INSERT INTO images_properties_new (id, image_id, type, key, value)
    SELECT id, image_id, type, key, value FROM images_properties;

CREATE TABLE images_source_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    image_id INTEGER NOT NULL,
    server TEXT NOT NULL,
    protocol INTEGER NOT NULL,
    certificate TEXT NOT NULL,
    alias TEXT NOT NULL,
    FOREIGN KEY (image_id) REFERENCES images_new (id) ON DELETE CASCADE
);

INSERT INTO images_source_new (id, image_id, server, protocol, certificate, alias)
    SELECT id, image_id, server, protocol, certificate, alias FROM images_source;

CREATE TABLE instances_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    architecture INTEGER NOT NULL,
    type INTEGER NOT NULL,
    ephemeral INTEGER NOT NULL DEFAULT 0,
    creation_date DATETIME NOT NULL DEFAULT 0,
    stateful INTEGER NOT NULL DEFAULT 0,
    last_use_date DATETIME,
    description TEXT NOT NULL,
    project_id INTEGER NOT NULL,
    expiry_date DATETIME,
    UNIQUE (project_id, name),
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO instances_new (id, node_id, name, architecture, type, ephemeral, creation_date, stateful, last_use_date, description, project_id, expiry_date)
    SELECT id, node_id, name, architecture, type, ephemeral, creation_date, stateful, last_use_date, IFNULL(description, ''), project_id, expiry_date FROM instances;

CREATE TABLE instances_backups_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    name VARCHAR(255) NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    container_only INTEGER NOT NULL default 0,
    optimized_storage INTEGER NOT NULL default 0,
    FOREIGN KEY (instance_id) REFERENCES instances_new (id) ON DELETE CASCADE,
    UNIQUE (instance_id, name)
);

INSERT INTO instances_backups_new (id, instance_id, name, creation_date, expiry_date, container_only, optimized_storage)
    SELECT id, instance_id, name, creation_date, expiry_date, container_only, optimized_storage FROM instances_backups;

CREATE TABLE instances_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (instance_id) REFERENCES instances_new (id) ON DELETE CASCADE,
    UNIQUE (instance_id, key)
);

INSERT INTO instances_config_new (id, instance_id, key, value)
    SELECT id, instance_id, key, value FROM instances_config;

CREATE TABLE instances_devices_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    FOREIGN KEY (instance_id) REFERENCES instances_new (id) ON DELETE CASCADE,
    UNIQUE (instance_id, name)
);

INSERT INTO instances_devices_new (id, instance_id, name, type)
    SELECT id, instance_id, name, type FROM instances_devices;

CREATE TABLE instances_devices_config_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (instance_device_id) REFERENCES instances_devices_new (id) ON DELETE CASCADE,
    UNIQUE (instance_device_id, key)
);

INSERT INTO instances_devices_config_new (id, instance_device_id, key, value)
    SELECT id, instance_device_id, key, value FROM instances_devices_config;

CREATE TABLE instances_profiles_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    apply_order INTEGER NOT NULL default 0,
    UNIQUE (instance_id, profile_id),
    FOREIGN KEY (instance_id) REFERENCES instances_new (id) ON DELETE CASCADE,
    FOREIGN KEY (profile_id) REFERENCES profiles_new(id) ON DELETE CASCADE
);

INSERT INTO instances_profiles_new (id, instance_id, profile_id, apply_order)
    SELECT id, instance_id, profile_id, apply_order FROM instances_profiles;

CREATE TABLE instances_snapshots_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    creation_date DATETIME NOT NULL DEFAULT 0,
    stateful INTEGER NOT NULL DEFAULT 0,
    description TEXT NOT NULL,
    expiry_date DATETIME,
    UNIQUE (instance_id, name),
    FOREIGN KEY (instance_id) REFERENCES instances_new (id) ON DELETE CASCADE
);

INSERT INTO instances_snapshots_new (id, instance_id, name, creation_date, stateful, description, expiry_date)
    SELECT id, instance_id, name, creation_date, stateful, IFNULL(description, ''), expiry_date FROM instances_snapshots;

CREATE TABLE instances_snapshots_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    instance_snapshot_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (instance_snapshot_id) REFERENCES instances_snapshots_new (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_id, key)
);

INSERT INTO instances_snapshots_config_new (id, instance_snapshot_id, key, value)
    SELECT id, instance_snapshot_id, key, value FROM instances_snapshots_config;

CREATE TABLE instances_snapshots_devices_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_snapshot_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    FOREIGN KEY (instance_snapshot_id) REFERENCES instances_snapshots_new (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_id, name)
);

INSERT INTO instances_snapshots_devices_new (id, instance_snapshot_id, name, type)
    SELECT id, instance_snapshot_id, name, type FROM instances_snapshots_devices;

CREATE TABLE instances_snapshots_devices_config_new (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_snapshot_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (instance_snapshot_device_id) REFERENCES instances_snapshots_devices_new (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_device_id, key)
);

INSERT INTO instances_snapshots_devices_config_new (id, instance_snapshot_device_id, key, value)
    SELECT id, instance_snapshot_device_id, key, value FROM instances_snapshots_devices_config;

CREATE TABLE networks_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    state INTEGER NOT NULL DEFAULT 0,
    type INTEGER NOT NULL DEFAULT 0,
    UNIQUE (project_id, name),
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO networks_new (id, project_id, name, description, state, type)
    SELECT id, project_id, name, IFNULL(description, ''), state, type FROM networks;

CREATE TABLE networks_acls_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    ingress TEXT NOT NULL,
    egress TEXT NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO networks_acls_new (id, project_id, name, description, ingress, egress)
    SELECT id, project_id, name, IFNULL(description, ''), ingress, egress FROM networks_acls;

CREATE TABLE networks_acls_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_acl_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (network_acl_id, key),
    FOREIGN KEY (network_acl_id) REFERENCES networks_acls_new (id) ON DELETE CASCADE
);

CREATE TABLE networks_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (network_id, node_id, key),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE
);

INSERT INTO networks_config_new (id, network_id, node_id, key, value)
    SELECT id, network_id, node_id, key, value FROM networks_config;

CREATE TABLE networks_forwards_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    listen_address TEXT NOT NULL,
    description TEXT NOT NULL,
    ports TEXT NOT NULL,
    UNIQUE (network_id, node_id, listen_address),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE
);

INSERT INTO networks_forwards_new (id, network_id, node_id, listen_address, description, ports)
    SELECT id, network_id, node_id, listen_address, IFNULL(description, ''), ports FROM networks_forwards;

CREATE TABLE networks_forwards_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_forward_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_forward_id, key),
    FOREIGN KEY (network_forward_id) REFERENCES networks_forwards_new (id) ON DELETE CASCADE
);

INSERT INTO networks_forwards_config_new (id, network_forward_id, key, value)
    SELECT id, network_forward_id, key, value FROM networks_forwards_config;

CREATE TABLE networks_nodes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    state INTEGER NOT NULL DEFAULT 0,
    UNIQUE (network_id, node_id),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE
);

INSERT INTO networks_nodes_new (id, network_id, node_id, state)
    SELECT id, network_id, node_id, state FROM networks_nodes;

CREATE TABLE networks_peers_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    target_network_project TEXT NULL,
    target_network_name TEXT NULL,
    target_network_id INTEGER NULL,
    UNIQUE (network_id, name),
    UNIQUE (network_id, target_network_project, target_network_name),
    UNIQUE (network_id, target_network_id),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE
);

INSERT INTO networks_peers_new (id, network_id, name, description, target_network_project, target_network_name, target_network_id)
    SELECT id, network_id, name, IFNULL(description, ''), target_network_project, target_network_name, target_network_id FROM networks_peers;

CREATE TABLE networks_peers_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_peer_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_peer_id, key),
    FOREIGN KEY (network_peer_id) REFERENCES networks_peers_new (id) ON DELETE CASCADE
);

INSERT INTO networks_peers_config_new (id, network_peer_id, key, value)
    SELECT id, network_peer_id, key, value FROM networks_peers_config;

CREATE TABLE networks_zones_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    UNIQUE (name),
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO networks_zones_new (id, project_id, name, description)
    SELECT id, project_id, name, IFNULL(description, '') FROM networks_zones;

CREATE TABLE networks_zones_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_zone_id, key),
    FOREIGN KEY (network_zone_id) REFERENCES networks_zones_new (id) ON DELETE CASCADE
);

INSERT INTO networks_zones_config_new (id, network_zone_id, key, value)
    SELECT id, network_zone_id, key, value FROM networks_zones_config;

CREATE TABLE nodes_cluster_groups_new (
    node_id INTEGER NOT NULL,
    group_id INTEGER NOT NULL,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE,
    FOREIGN KEY (group_id) REFERENCES cluster_groups (id) ON DELETE CASCADE,
    UNIQUE (node_id, group_id)
);

INSERT INTO nodes_cluster_groups_new (node_id, group_id)
    SELECT node_id, group_id FROM nodes_cluster_groups;

CREATE TABLE nodes_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE,
    UNIQUE (node_id, key)
);

INSERT INTO nodes_config_new (id, node_id, key, value)
    SELECT id, node_id, key, value FROM nodes_config;

CREATE TABLE nodes_roles_new (
    node_id INTEGER NOT NULL,
    role INTEGER NOT NULL,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE,
    UNIQUE (node_id, role)
);

INSERT INTO nodes_roles_new (node_id, role)
    SELECT node_id, role FROM nodes_roles;

CREATE TABLE operations_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    uuid TEXT NOT NULL,
    node_id TEXT NOT NULL,
    type INTEGER NOT NULL DEFAULT 0,
    project_id INTEGER,
    UNIQUE (uuid),
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO operations_new (id, uuid, node_id, type, project_id)
    SELECT id, uuid, node_id, type, project_id FROM operations;

CREATE TABLE profiles_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (profile_id, key),
    FOREIGN KEY (profile_id) REFERENCES profiles_new(id) ON DELETE CASCADE
);

INSERT INTO profiles_config_new (id, profile_id, key, value)
    SELECT id, profile_id, key, value FROM profiles_config;

CREATE TABLE profiles_devices_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    UNIQUE (profile_id, name),
    FOREIGN KEY (profile_id) REFERENCES profiles_new (id) ON DELETE CASCADE
);

INSERT INTO profiles_devices_new (id, profile_id, name, type)
    SELECT id, profile_id, name, type FROM profiles_devices;

CREATE TABLE profiles_devices_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (profile_device_id, key),
    FOREIGN KEY (profile_device_id) REFERENCES profiles_devices_new (id) ON DELETE CASCADE
);

INSERT INTO profiles_devices_config_new (id, profile_device_id, key, value)
    SELECT id, profile_device_id, key, value FROM profiles_devices_config;

CREATE TABLE projects_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE,
    UNIQUE (project_id, key)
);

INSERT INTO projects_config_new (id, project_id, key, value)
    SELECT id, project_id, key, value FROM projects_config;

CREATE TABLE storage_pools_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    driver TEXT NOT NULL,
    description TEXT NOT NULL,
    state INTEGER NOT NULL DEFAULT 0,
    UNIQUE (name)
);

INSERT INTO storage_pools_new (id, name, driver, description, state)
    SELECT id, name, driver, IFNULL(description, ''), state FROM storage_pools;

CREATE TABLE storage_pools_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (storage_pool_id, node_id, key),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE
);

INSERT INTO storage_pools_config_new (id, storage_pool_id, node_id, key, value)
    SELECT id, storage_pool_id, node_id, key, value FROM storage_pools_config;

CREATE TABLE storage_pools_nodes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    state INTEGER NOT NULL DEFAULT 0,
    UNIQUE (storage_pool_id, node_id),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE
);

INSERT INTO storage_pools_nodes_new (id, storage_pool_id, node_id, state)
    SELECT id, storage_pool_id, node_id, state FROM storage_pools_nodes;

CREATE TABLE storage_volumes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER,
    type INTEGER NOT NULL,
    description TEXT NOT NULL,
    project_id INTEGER NOT NULL,
    content_type INTEGER NOT NULL DEFAULT 0,
    UNIQUE (storage_pool_id, node_id, project_id, name, type),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes_new (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO storage_volumes_new (id, name, storage_pool_id, node_id, type, description, project_id, content_type)
    SELECT id, name, storage_pool_id, node_id, type, IFNULL(description, ''), project_id, content_type FROM storage_volumes;

CREATE TABLE storage_volumes_backups_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    name VARCHAR(255) NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    volume_only INTEGER NOT NULL default 0,
    optimized_storage INTEGER NOT NULL default 0,
    FOREIGN KEY (storage_volume_id) REFERENCES storage_volumes_new (id) ON DELETE CASCADE,
    UNIQUE (storage_volume_id, name)
);

INSERT INTO storage_volumes_backups_new (id, storage_volume_id, name, creation_date, expiry_date, volume_only, optimized_storage)
    SELECT id, storage_volume_id, name, creation_date, expiry_date, volume_only, optimized_storage FROM storage_volumes_backups;

CREATE TABLE storage_volumes_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (storage_volume_id, key),
    FOREIGN KEY (storage_volume_id) REFERENCES storage_volumes_new (id) ON DELETE CASCADE
);

INSERT INTO storage_volumes_config_new (id, storage_volume_id, key, value)
    SELECT id, storage_volume_id, key, value FROM storage_volumes_config;

CREATE TABLE storage_volumes_snapshots_new (
    id INTEGER NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    expiry_date DATETIME,
    UNIQUE (id),
    UNIQUE (storage_volume_id, name),
    FOREIGN KEY (storage_volume_id) REFERENCES storage_volumes_new (id) ON DELETE CASCADE
);

INSERT INTO storage_volumes_snapshots_new (id, storage_volume_id, name, description, expiry_date)
    SELECT id, storage_volume_id, name, IFNULL(description, ''), expiry_date FROM storage_volumes_snapshots;

CREATE TABLE storage_volumes_snapshots_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_snapshot_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (storage_volume_snapshot_id) REFERENCES storage_volumes_snapshots_new (id) ON DELETE CASCADE,
    UNIQUE (storage_volume_snapshot_id, key)
);

INSERT INTO storage_volumes_snapshots_config_new (id, storage_volume_snapshot_id, key, value)
    SELECT id, storage_volume_snapshot_id, key, value FROM storage_volumes_snapshots_config;

CREATE TABLE warnings_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    node_id INTEGER,
    project_id INTEGER,
    entity_type_code INTEGER,
    entity_id INTEGER,
    uuid TEXT NOT NULL,
    type_code INTEGER NOT NULL,
    status INTEGER NOT NULL,
    first_seen_date DATETIME NOT NULL,
    last_seen_date DATETIME NOT NULL,
    updated_date DATETIME,
    last_message TEXT NOT NULL,
    count INTEGER NOT NULL,
    UNIQUE (uuid),
    FOREIGN KEY (node_id) REFERENCES nodes_new(id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects_new (id) ON DELETE CASCADE
);

INSERT INTO warnings_new (id, node_id, project_id, entity_type_code, entity_id, uuid, type_code, status, first_seen_date, last_seen_date, updated_date, last_message, count)
    SELECT id, node_id, project_id, entity_type_code, entity_id, uuid, type_code, status, first_seen_date, last_seen_date, updated_date, last_message, count FROM warnings;

DROP TABLE warnings;
DROP TABLE storage_volumes_snapshots_config;
DROP TABLE storage_volumes_snapshots;
DROP TABLE storage_volumes_config;
DROP TABLE storage_volumes_backups;
DROP TABLE storage_volumes;
DROP TABLE storage_pools_nodes;
DROP TABLE storage_pools_config;
DROP TABLE storage_pools;
DROP TABLE projects_config;
DROP TABLE profiles_devices_config;
DROP TABLE profiles_devices;
DROP TABLE profiles_config;
DROP TABLE operations;
DROP TABLE nodes_roles;
DROP TABLE nodes_config;
DROP TABLE nodes_cluster_groups;
DROP TABLE networks_zones_config;
DROP TABLE networks_zones;
DROP TABLE networks_peers_config;
DROP TABLE networks_peers;
DROP TABLE networks_nodes;
DROP TABLE networks_forwards_config;
DROP TABLE networks_forwards;
DROP TABLE networks_config;
DROP TABLE networks_acls_config;
DROP TABLE networks_acls;
DROP TABLE networks;
DROP TABLE instances_snapshots_devices_config;
DROP TABLE instances_snapshots_devices;
DROP TABLE instances_snapshots_config;
DROP TABLE instances_snapshots;
DROP TABLE instances_profiles;
DROP TABLE instances_devices_config;
DROP TABLE instances_devices;
DROP TABLE instances_config;
DROP TABLE instances_backups;
DROP TABLE instances;
DROP TABLE images_source;
DROP TABLE images_properties;
DROP TABLE images_profiles;
DROP TABLE profiles;
DROP TABLE images_nodes;
DROP TABLE images_aliases;
DROP TABLE nodes;
DROP TABLE certificates_projects;
DROP TABLE images;
DROP TABLE projects;

ALTER TABLE projects_new RENAME TO projects;
ALTER TABLE certificates_projects_new RENAME TO certificates_projects;
ALTER TABLE images_new RENAME TO images;
ALTER TABLE images_aliases_new RENAME TO images_aliases;
ALTER TABLE nodes_new RENAME TO nodes;
ALTER TABLE images_nodes_new RENAME TO images_nodes;
ALTER TABLE profiles_new RENAME TO profiles;
ALTER TABLE images_profiles_new RENAME TO images_profiles;
ALTER TABLE images_properties_new RENAME TO images_properties;
ALTER TABLE images_source_new RENAME TO images_source;
ALTER TABLE instances_new RENAME TO instances;
ALTER TABLE instances_backups_new RENAME TO instances_backups;
ALTER TABLE instances_config_new RENAME TO instances_config;
ALTER TABLE instances_devices_new RENAME TO instances_devices;
ALTER TABLE instances_devices_config_new RENAME TO instances_devices_config;
ALTER TABLE instances_profiles_new RENAME TO instances_profiles;
ALTER TABLE instances_snapshots_new RENAME TO instances_snapshots;
ALTER TABLE instances_snapshots_config_new RENAME TO instances_snapshots_config;
ALTER TABLE instances_snapshots_devices_new RENAME TO instances_snapshots_devices;
ALTER TABLE instances_snapshots_devices_config_new RENAME TO instances_snapshots_devices_config;
ALTER TABLE networks_new RENAME TO networks;
ALTER TABLE networks_acls_new RENAME TO networks_acls;
ALTER TABLE networks_acls_config_new RENAME TO networks_acls_config;
ALTER TABLE networks_config_new RENAME TO networks_config;
ALTER TABLE networks_forwards_new RENAME TO networks_forwards;
ALTER TABLE networks_forwards_config_new RENAME TO networks_forwards_config;
ALTER TABLE networks_nodes_new RENAME TO networks_nodes;
ALTER TABLE networks_peers_new RENAME TO networks_peers;
ALTER TABLE networks_peers_config_new RENAME TO networks_peers_config;
ALTER TABLE networks_zones_new RENAME TO networks_zones;
ALTER TABLE networks_zones_config_new RENAME TO networks_zones_config;
ALTER TABLE nodes_cluster_groups_new RENAME TO nodes_cluster_groups;
ALTER TABLE nodes_config_new RENAME TO nodes_config;
ALTER TABLE nodes_roles_new RENAME TO nodes_roles;
ALTER TABLE operations_new RENAME TO operations;
ALTER TABLE profiles_config_new RENAME TO profiles_config;
ALTER TABLE profiles_devices_new RENAME TO profiles_devices;
ALTER TABLE profiles_devices_config_new RENAME TO profiles_devices_config;
ALTER TABLE projects_config_new RENAME TO projects_config;
ALTER TABLE storage_pools_new RENAME TO storage_pools;
ALTER TABLE storage_pools_config_new RENAME TO storage_pools_config;
ALTER TABLE storage_pools_nodes_new RENAME TO storage_pools_nodes;
ALTER TABLE storage_volumes_new RENAME TO storage_volumes;
ALTER TABLE storage_volumes_backups_new RENAME TO storage_volumes_backups;
ALTER TABLE storage_volumes_config_new RENAME TO storage_volumes_config;
ALTER TABLE storage_volumes_snapshots_new RENAME TO storage_volumes_snapshots;
ALTER TABLE storage_volumes_snapshots_config_new RENAME TO storage_volumes_snapshots_config;
ALTER TABLE warnings_new RENAME TO warnings;

CREATE INDEX images_aliases_project_id_idx ON images_aliases (project_id);
CREATE INDEX images_project_id_idx ON images (project_id);
CREATE INDEX instances_project_id_and_name_idx ON instances (project_id, name);
CREATE INDEX instances_project_id_and_node_id_and_name_idx ON instances (project_id, node_id, name);
CREATE INDEX instances_project_id_and_node_id_idx ON instances (project_id, node_id);
CREATE INDEX instances_project_id_idx ON instances (project_id);
CREATE UNIQUE INDEX storage_pools_unique_storage_pool_id_node_id_key ON storage_pools_config (storage_pool_id, IFNULL(node_id, -1), key);
CREATE INDEX instances_node_id_idx ON instances (node_id);
CREATE UNIQUE INDEX networks_unique_network_id_node_id_key ON "networks_config" (network_id, IFNULL(node_id, -1), key);
CREATE INDEX profiles_project_id_idx ON profiles (project_id);
CREATE UNIQUE INDEX warnings_unique_node_id_project_id_entity_type_code_entity_id_type_code ON warnings(IFNULL(node_id, -1), IFNULL(project_id, -1), entity_type_code, entity_id, type_code);

CREATE TRIGGER storage_volumes_check_id
    BEFORE INSERT ON storage_volumes
    WHEN NEW.id IN (SELECT id FROM storage_volumes_snapshots)
    BEGIN
        SELECT RAISE(FAIL,
        "invalid ID");
    END;

CREATE TRIGGER storage_volumes_snapshots_check_id
    BEFORE INSERT ON storage_volumes_snapshots
    WHEN NEW.id IN (SELECT id FROM storage_volumes)
    BEGIN
        SELECT RAISE(FAIL,
        "invalid ID");
    END;

CREATE VIEW storage_volumes_all (
    id,
    name,
    storage_pool_id,
    node_id,
    type,
    description,
    project_id,
    content_type) AS
        SELECT id,
            name,
            storage_pool_id,
            node_id,
            type,
            description,
            project_id,
            content_type
        FROM storage_volumes UNION
            SELECT storage_volumes_snapshots.id,
                printf('%s/%s',
                    storage_volumes.name,
                    storage_volumes_snapshots.name),
                storage_volumes.storage_pool_id,
                storage_volumes.node_id,
                storage_volumes.type,
                storage_volumes_snapshots.description,
                storage_volumes.project_id,
                storage_volumes.content_type
            FROM storage_volumes
            JOIN storage_volumes_snapshots ON storage_volumes.id = storage_volumes_snapshots.storage_volume_id;
`)
	if err != nil {
		return fmt.Errorf("Could not add not null constraint to description field: %w", err)
	}

	return nil
}

func updateFromV54(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
DROP VIEW certificates_projects_ref;
DROP VIEW instances_config_ref;
DROP VIEW instances_devices_ref;
DROP VIEW instances_profiles_ref;
DROP VIEW instances_snapshots_config_ref;
DROP VIEW instances_snapshots_devices_ref;
DROP VIEW profiles_config_ref;
DROP VIEW profiles_devices_ref;
DROP VIEW profiles_used_by_ref;
DROP VIEW projects_config_ref;
DROP VIEW projects_used_by_ref;
`)
	if err != nil {
		return fmt.Errorf("Failed to drop database views: %w", err)
	}

	return nil
}

// updateFromV53 creates the cluster_groups and nodes_cluster_groups tables.
func updateFromV53(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "cluster_groups" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    UNIQUE (name)
);

CREATE TABLE "nodes_cluster_groups" (
    node_id INTEGER NOT NULL,
    group_id INTEGER NOT NULL,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (group_id) REFERENCES cluster_groups (id) ON DELETE CASCADE,
    UNIQUE (node_id, group_id)
);

INSERT INTO cluster_groups (id, name, description) VALUES (1, 'default', 'Default cluster group');

INSERT INTO nodes_cluster_groups (node_id, group_id) SELECT id, 1 FROM nodes;
`)
	if err != nil {
		return fmt.Errorf("Failed creating cluster group tables: %w", err)
	}

	return nil
}

// updateFromV52 creates the networks_zones and networks_zones_config tables.
func updateFromV52(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "networks_zones" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    UNIQUE (name),
    FOREIGN KEY (project_id) REFERENCES "projects" (id) ON DELETE CASCADE
);

CREATE TABLE "networks_zones_config" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_zone_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_zone_id, key),
    FOREIGN KEY (network_zone_id) REFERENCES "networks_zones" (id) ON DELETE CASCADE
);
`)
	if err != nil {
		return fmt.Errorf("Failed creating network zones tables: %w", err)
	}

	return nil
}

// updateFromV51 creates the networks_peers and networks_peers_config tables.
func updateFromV51(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "networks_peers" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    target_network_project TEXT NULL,
    target_network_name TEXT NULL,
    target_network_id INTEGER NULL,
    UNIQUE (network_id, name),
    UNIQUE (network_id, target_network_project, target_network_name),
    UNIQUE (network_id, target_network_id),
    FOREIGN KEY (network_id) REFERENCES "networks" (id) ON DELETE CASCADE
);

CREATE TABLE "networks_peers_config" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_peer_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_peer_id, key),
    FOREIGN KEY (network_peer_id) REFERENCES "networks_peers" (id) ON DELETE CASCADE
);
`)
	if err != nil {
		return fmt.Errorf("Failed creating network peers tables: %w", err)
	}

	return nil
}

// updateFromV50 creates the nodes_config table.
func updateFromV50(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "nodes_config" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    UNIQUE (node_id, key)
);
	`)
	if err != nil {
		return fmt.Errorf("Failed creating nodes_config table: %w", err)
	}

	return nil
}

// updateFromV49 creates the networks_forwards and networks_forwards_config tables.
func updateFromV49(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE "networks_forwards" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    listen_address TEXT NOT NULL,
    description TEXT NOT NULL,
    ports TEXT NOT NULL,
    UNIQUE (network_id, node_id, listen_address),
    FOREIGN KEY (network_id) REFERENCES "networks" (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES "nodes" (id) ON DELETE CASCADE
);

CREATE TABLE "networks_forwards_config" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_forward_id INTEGER NOT NULL,
    key VARCHAR(255) NOT NULL,
    value TEXT,
    UNIQUE (network_forward_id, key),
    FOREIGN KEY (network_forward_id) REFERENCES "networks_forwards" (id) ON DELETE CASCADE
);
`)
	if err != nil {
		return fmt.Errorf("Failed creating network forwards tables: %w", err)
	}

	return nil
}

// updateFromV48 renames the "pending" column to "state" in the "nodes" table.
func updateFromV48(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
ALTER TABLE nodes RENAME COLUMN pending TO state;
`)
	if err != nil {
		return fmt.Errorf(`Failed to rename column "pending" to "state" in table "nodes": %w`, err)
	}

	return nil
}

// updateFromV47 adds warnings.
func updateFromV47(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE warnings (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    node_id INTEGER,
    project_id INTEGER,
    entity_type_code INTEGER,
    entity_id INTEGER,
    uuid TEXT NOT NULL,
    type_code INTEGER NOT NULL,
    status INTEGER NOT NULL,
    first_seen_date DATETIME NOT NULL,
    last_seen_date DATETIME NOT NULL,
    updated_date DATETIME,
    last_message TEXT NOT NULL,
    count INTEGER NOT NULL,
    UNIQUE (uuid),
    FOREIGN KEY (node_id) REFERENCES nodes(id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE UNIQUE INDEX warnings_unique_node_id_project_id_entity_type_code_entity_id_type_code ON warnings(IFNULL(node_id, -1), IFNULL(project_id, -1), entity_type_code, entity_id, type_code);
`)
	if err != nil {
		return fmt.Errorf("Failed to create warnings table and warnings_unique_node_id_project_id_entity_type_code_entity_id_type_code index: %w", err)
	}

	return err
}

// updateFromV46 adds support for restricting certificates to projects.
func updateFromV46(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
ALTER TABLE certificates ADD COLUMN restricted INTEGER NOT NULL DEFAULT 0;
CREATE TABLE certificates_projects (
    certificate_id INTEGER NOT NULL,
    project_id INTEGER NOT NULL,
    FOREIGN KEY (certificate_id) REFERENCES certificates (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE,
    UNIQUE (certificate_id, project_id)
);

CREATE VIEW certificates_projects_ref (fingerprint, value) AS
    SELECT certificates.fingerprint, projects.name FROM certificates_projects
        JOIN certificates ON certificates.id=certificates_projects.certificate_id
        JOIN projects ON projects.id=certificates_projects.project_id
        ORDER BY projects.name;
`)
	if err != nil {
		return fmt.Errorf("Failed extending certificates to support project restrictions: %w", err)
	}

	return nil
}

// updateFromV45 updates projects_used_by_ref to include ceph volumes.
func updateFromV45(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
DROP VIEW projects_used_by_ref;
CREATE VIEW projects_used_by_ref (name,
    value) AS
  SELECT projects.name,
    printf('/1.0/instances/%s?project=%s',
    "instances".name,
    projects.name)
    FROM "instances" JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/images/%s?project=%s',
    images.fingerprint,
    projects.name)
    FROM images JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/storage-pools/%s/volumes/custom/%s?project=%s&target=%s',
    storage_pools.name,
    storage_volumes.name,
    projects.name,
    nodes.name)
    FROM storage_volumes JOIN storage_pools ON storage_pool_id=storage_pools.id JOIN nodes ON node_id=nodes.id JOIN projects ON project_id=projects.id WHERE storage_volumes.type=2 UNION
  SELECT projects.name,
    printf('/1.0/storage-pools/%s/volumes/custom/%s?project=%s',
    storage_pools.name,
    storage_volumes.name,
    projects.name)
    FROM storage_volumes JOIN storage_pools ON storage_pool_id=storage_pools.id JOIN projects ON project_id=projects.id WHERE storage_volumes.type=2 AND storage_volumes.node_id IS NULL UNION
  SELECT projects.name,
    printf('/1.0/profiles/%s?project=%s',
    profiles.name,
    projects.name)
    FROM profiles JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/networks/%s?project=%s',
    networks.name,
    projects.name)
    FROM networks JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/network-acls/%s?project=%s',
    networks_acls.name,
    projects.name)
    FROM networks_acls JOIN projects ON project_id=projects.id;
`)
	if err != nil {
		return fmt.Errorf("Failed to update projects_used_by_ref: %w", err)
	}

	return nil
}

// updateFromV44 adds networks_acls table, and adds a foreign key relationship between networks and projects.
// API extension: network_acl.
func updateFromV44(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
DROP VIEW projects_used_by_ref;

CREATE TABLE networks_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    state INTEGER NOT NULL DEFAULT 0,
    type INTEGER NOT NULL DEFAULT 0,
    UNIQUE (project_id, name),
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

INSERT INTO networks_new (id, project_id, name, description, state, type)
    SELECT id, project_id, name, description, state, type FROM networks;

CREATE TABLE networks_nodes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    state INTEGER NOT NULL DEFAULT 0,
    UNIQUE (network_id, node_id),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);

INSERT INTO networks_nodes_new (id, network_id, node_id, state)
    SELECT id, network_id, node_id, state FROM networks_nodes;

CREATE TABLE networks_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (network_id, node_id, key),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);

INSERT INTO networks_config_new (id, network_id, node_id, key, value)
    SELECT id, network_id, node_id, key, value FROM networks_config;

DROP TABLE networks;
DROP TABLE networks_nodes;
DROP TABLE networks_config;

CREATE UNIQUE INDEX networks_unique_network_id_node_id_key ON networks_config_new (network_id, IFNULL(node_id, -1), key);

ALTER TABLE networks_new RENAME TO networks;
ALTER TABLE networks_nodes_new RENAME TO networks_nodes;
ALTER TABLE networks_config_new RENAME TO networks_config;

CREATE TABLE networks_acls (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT NOT NULL,
    ingress TEXT NOT NULL,
    egress TEXT NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE TABLE networks_acls_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_acl_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (network_acl_id, key),
    FOREIGN KEY (network_acl_id) REFERENCES networks_acls (id) ON DELETE CASCADE
);

CREATE VIEW projects_used_by_ref (name,
    value) AS
  SELECT projects.name,
    printf('/1.0/instances/%s?project=%s',
    "instances".name,
    projects.name)
    FROM "instances" JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/images/%s?project=%s',
    images.fingerprint,
    projects.name)
    FROM images JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/storage-pools/%s/volumes/custom/%s?project=%s&target=%s',
    storage_pools.name,
    storage_volumes.name,
    projects.name,
    nodes.name)
    FROM storage_volumes JOIN storage_pools ON storage_pool_id=storage_pools.id JOIN nodes ON node_id=nodes.id JOIN projects ON project_id=projects.id WHERE storage_volumes.type=2 UNION
  SELECT projects.name,
    printf('/1.0/profiles/%s?project=%s',
    profiles.name,
    projects.name)
    FROM profiles JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/networks/%s?project=%s',
    networks.name,
    projects.name)
    FROM networks JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/network-acls/%s?project=%s',
    networks_acls.name,
    projects.name)
    FROM networks_acls JOIN projects ON project_id=projects.id;
`)
	if err != nil {
		return fmt.Errorf("Failed to add networks_acls and networks_acls_config tables, and update projects_used_by_ref view: %w", err)
	}

	return nil
}

// updateFromV43 adds a unique index to the storage_pools_config and networks_config tables.
func updateFromV43(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE UNIQUE INDEX storage_pools_unique_storage_pool_id_node_id_key ON storage_pools_config (storage_pool_id, IFNULL(node_id, -1), key);
CREATE UNIQUE INDEX networks_unique_network_id_node_id_key ON networks_config (network_id, IFNULL(node_id, -1), key);
	`)
	if err != nil {
		return fmt.Errorf("Failed adding unique index to storage_pools_config and networks_config tables: %w", err)
	}

	return nil
}

// updateFromV42 removes any duplicated storage pool config rows that have the same value.
// This can occur when multiple create requests have been issued when setting up a clustered storage pool.
func updateFromV42(ctx context.Context, tx *sql.Tx) error {
	// Find all duplicated config rows and return comma delimited list of affected row IDs for each dupe set.
	stmt := `SELECT storage_pool_id, IFNULL(node_id, -1), key, value, COUNT(*) AS rowCount, GROUP_CONCAT(id, ",") AS dupeRowIDs
			FROM storage_pools_config
			GROUP BY storage_pool_id, node_id, key, value
			HAVING rowCount > 1
		`
	rows, err := tx.QueryContext(ctx, stmt)
	if err != nil {
		return fmt.Errorf("Failed running query: %w", err)
	}

	defer func() { _ = rows.Close() }()

	type dupeRow struct {
		storagePoolID int64
		nodeID        int64
		key           string
		value         string
		rowCount      int64
		dupeRowIDs    string
	}

	var dupeRows []dupeRow

	for rows.Next() {
		r := dupeRow{}
		err = rows.Scan(&r.storagePoolID, &r.nodeID, &r.key, &r.value, &r.rowCount, &r.dupeRowIDs)
		if err != nil {
			return fmt.Errorf("Failed scanning rows: %w", err)
		}

		dupeRows = append(dupeRows, r)
	}

	err = rows.Err()
	if err != nil {
		return fmt.Errorf("Got a row error: %w", err)
	}

	for _, r := range dupeRows {
		logger.Warn("Found duplicated storage pool config rows", logger.Ctx{"storagePoolID": r.storagePoolID, "nodeID": r.nodeID, "key": r.key, "value": r.value, "rowCount": r.rowCount, "dupeRowIDs": r.dupeRowIDs})

		rowIDs := strings.Split(r.dupeRowIDs, ",")

		// Iterate and delete all but 1 of the rowIDs so we leave just one left.
		for i := range len(rowIDs) - 1 {
			rowID, err := strconv.Atoi(rowIDs[i])
			if err != nil {
				return fmt.Errorf("Failed converting row ID: %w", err)
			}

			_, err = tx.Exec("DELETE FROM storage_pools_config WHERE id = ?", rowID)
			if err != nil {
				return fmt.Errorf("Failed deleting storage pool config row with ID %d: %w", rowID, err)
			}

			logger.Warn("Deleted duplicated storage pool config row", logger.Ctx{"storagePoolID": r.storagePoolID, "nodeID": r.nodeID, "key": r.key, "value": r.value, "rowCount": r.rowCount, "rowID": rowID})
		}
	}

	return nil
}

// updateFromV41 removes any duplicated network config rows that have the same value.
// This can occur when multiple create requests have been issued when setting up a clustered network.
func updateFromV41(ctx context.Context, tx *sql.Tx) error {
	// Find all duplicated config rows and return comma delimited list of affected row IDs for each dupe set.
	stmt := `SELECT network_id, IFNULL(node_id, -1), key, value, COUNT(*) AS rowCount, GROUP_CONCAT(id, ",") AS dupeRowIDs
			FROM networks_config
			GROUP BY network_id, node_id, key, value
			HAVING rowCount > 1
		`
	rows, err := tx.QueryContext(ctx, stmt)
	if err != nil {
		return fmt.Errorf("Failed running query: %w", err)
	}

	defer func() { _ = rows.Close() }()

	type dupeRow struct {
		networkID  int64
		nodeID     int64
		key        string
		value      string
		rowCount   int64
		dupeRowIDs string
	}

	var dupeRows []dupeRow

	for rows.Next() {
		r := dupeRow{}
		err = rows.Scan(&r.networkID, &r.nodeID, &r.key, &r.value, &r.rowCount, &r.dupeRowIDs)
		if err != nil {
			return fmt.Errorf("Failed scanning rows: %w", err)
		}

		dupeRows = append(dupeRows, r)
	}

	err = rows.Err()
	if err != nil {
		return fmt.Errorf("Got a row error: %w", err)
	}

	for _, r := range dupeRows {
		logger.Warn("Found duplicated network config rows", logger.Ctx{"networkID": r.networkID, "nodeID": r.nodeID, "key": r.key, "value": r.value, "rowCount": r.rowCount, "dupeRowIDs": r.dupeRowIDs})

		rowIDs := strings.Split(r.dupeRowIDs, ",")

		// Iterate and delete all but 1 of the rowIDs so we leave just one left.
		for i := range len(rowIDs) - 1 {
			rowID, err := strconv.Atoi(rowIDs[i])
			if err != nil {
				return fmt.Errorf("Failed converting row ID: %w", err)
			}

			_, err = tx.Exec("DELETE FROM networks_config WHERE id = ?", rowID)
			if err != nil {
				return fmt.Errorf("Failed deleting network config row with ID %d: %w", rowID, err)
			}

			logger.Warn("Deleted duplicated network config row", logger.Ctx{"networkID": r.networkID, "nodeID": r.nodeID, "key": r.key, "value": r.value, "rowCount": r.rowCount, "rowID": rowID})
		}
	}

	return nil
}

// Add state column to storage_pools_nodes tables. Set existing row's state to 1 ("created").
func updateFromV40(ctx context.Context, tx *sql.Tx) error {
	stmt := `
ALTER TABLE storage_pools_nodes ADD COLUMN state INTEGER NOT NULL DEFAULT 0;
UPDATE storage_pools_nodes SET state = 1;
	`
	_, err := tx.Exec(stmt)
	return err
}

// Add state column to networks_nodes tables. Set existing row's state to 1 ("created").
func updateFromV39(ctx context.Context, tx *sql.Tx) error {
	stmt := `
ALTER TABLE networks_nodes ADD COLUMN state INTEGER NOT NULL DEFAULT 0;
UPDATE networks_nodes SET state = 1;
	`
	_, err := tx.Exec(stmt)
	return err
}

// Add storage_volumes_backups table.
func updateFromV38(ctx context.Context, tx *sql.Tx) error {
	stmt := `
CREATE TABLE storage_volumes_backups (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    name VARCHAR(255) NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    volume_only INTEGER NOT NULL default 0,
    optimized_storage INTEGER NOT NULL default 0,
    FOREIGN KEY (storage_volume_id) REFERENCES "storage_volumes" (id) ON DELETE CASCADE,
    UNIQUE (storage_volume_id, name)
);
`
	_, err := tx.Exec(stmt)
	if err != nil {
		return err
	}

	return nil
}

// Attempt to add missing project features.networks feature to default project.
func updateFromV37(ctx context.Context, tx *sql.Tx) error {
	ids, err := query.SelectIntegers(ctx, tx, `SELECT id FROM projects WHERE name = "default" LIMIT 1`)
	if err != nil {
		return err
	}

	if len(ids) == 1 {
		_, _ = tx.Exec("INSERT INTO projects_config (project_id, key, value) VALUES (?, 'features.networks', 'true');", ids[0])
	}

	return nil
}

// Add networks to projects references.
func updateFromV36(ctx context.Context, tx *sql.Tx) error {
	stmts := `
DROP VIEW projects_used_by_ref;
CREATE VIEW projects_used_by_ref (name,
    value) AS
  SELECT projects.name,
    printf('/1.0/instances/%s?project=%s',
    "instances".name,
    projects.name)
    FROM "instances" JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/images/%s?project=%s',
    images.fingerprint,
    projects.name)
    FROM images JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/storage-pools/%s/volumes/custom/%s?project=%s&target=%s',
    storage_pools.name,
    storage_volumes.name,
    projects.name,
    nodes.name)
    FROM storage_volumes JOIN storage_pools ON storage_pool_id=storage_pools.id JOIN nodes ON node_id=nodes.id JOIN projects ON project_id=projects.id WHERE storage_volumes.type=2 UNION
  SELECT projects.name,
    printf('/1.0/profiles/%s?project=%s',
    profiles.name,
    projects.name)
    FROM profiles JOIN projects ON project_id=projects.id UNION
  SELECT projects.name,
    printf('/1.0/networks/%s?project=%s',
    networks.name,
    projects.name)
    FROM networks JOIN projects ON project_id=projects.id;
`
	_, err := tx.Exec(stmts)
	return err
}

// This fixes node IDs of storage volumes on non-remote pools which were
// wrongly set to NULL.
func updateFromV35(ctx context.Context, tx *sql.Tx) error {
	stmts := `
WITH storage_volumes_tmp (id, node_id)
AS (
  SELECT storage_volumes.id, storage_pools_nodes.node_id
  FROM storage_volumes
    JOIN storage_pools_nodes ON storage_pools_nodes.storage_pool_id=storage_volumes.storage_pool_id
    JOIN storage_pools ON storage_pools.id=storage_volumes.storage_pool_id
  WHERE storage_pools.driver NOT IN ("ceph", "cephfs"))
UPDATE storage_volumes
SET node_id=(
  SELECT storage_volumes_tmp.node_id
  FROM storage_volumes_tmp
  WHERE storage_volumes.id=storage_volumes_tmp.id)
WHERE id IN (SELECT id FROM storage_volumes_tmp) AND node_id IS NULL
`

	_, err := tx.Exec(stmts)
	if err != nil {
		return err
	}

	return nil
}

// Remove multiple entries of the same volume when using remote storage.
// Also, allow node ID to be null for the instances and storage_volumes tables, and set it to null
// for instances and storage volumes using remote storage.
func updateFromV34(ctx context.Context, tx *sql.Tx) error {
	stmts := `
SELECT storage_volumes.id, storage_volumes.name
FROM storage_volumes
JOIN storage_pools ON storage_pools.id=storage_volumes.storage_pool_id
WHERE storage_pools.driver IN ("ceph", "cephfs")
ORDER BY storage_volumes.name
`

	// Get the total number of storage volume rows.
	count, err := query.Count(ctx, tx, "storage_volumes JOIN storage_pools ON storage_pools.id=storage_volumes.storage_pool_id",
		`storage_pools.driver IN ("ceph", "cephfs")`)
	if err != nil {
		return fmt.Errorf("Failed to get storage volumes count: %w", err)
	}

	type volume struct {
		ID            int
		Name          string
		StoragePoolID int
		NodeID        string
		Type          int
		Description   string
		ProjectID     int
		ContentType   int
	}

	volumes := make([]volume, 0, count)
	err = query.Scan(ctx, tx, stmts, func(scan func(dest ...any) error) error {
		vol := volume{}
		err := scan(&vol.ID, &vol.Name)
		if err != nil {
			return err
		}

		volumes = append(volumes, vol)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch storage volumes with remote storage: %w", err)
	}

	// Remove multiple entries of the same volume when using remote storage
	for i := 1; i < count; i++ {
		if volumes[i-1].Name == volumes[i].Name {
			_, err = tx.Exec(`DELETE FROM storage_volumes WHERE id=?`, volumes[i-1].ID)
			if err != nil {
				return fmt.Errorf("Failed to delete row from storage_volumes: %w", err)
			}
		}
	}

	stmts = `
CREATE TABLE storage_volumes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER,
    type INTEGER NOT NULL,
    description TEXT,
    project_id INTEGER NOT NULL,
    content_type INTEGER NOT NULL DEFAULT 0,
    UNIQUE (storage_pool_id, node_id, project_id, name, type),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);`

	// Create new tables where node ID can be null.
	_, err = tx.Exec(stmts)
	if err != nil {
		return err
	}

	// Copy rows from storage_volumes to storage_volumes_new
	count, err = query.Count(ctx, tx, "storage_volumes", "")
	if err != nil {
		return fmt.Errorf("Failed to get storage_volumes count: %w", err)
	}

	storageVolumes := make([]volume, 0, count)

	sqlStr := `
SELECT id, name, storage_pool_id, node_id, type, coalesce(description, ''), project_id, content_type
FROM storage_volumes`

	err = query.Scan(ctx, tx, sqlStr, func(scan func(dest ...any) error) error {
		vol := volume{}
		err := scan(&vol.ID, &vol.Name, &vol.StoragePoolID, &vol.NodeID, &vol.Type, &vol.Description, &vol.ProjectID, &vol.ContentType)
		if err != nil {
			return err
		}

		storageVolumes = append(storageVolumes, vol)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch storage volumes: %w", err)
	}

	for _, storageVolume := range storageVolumes {
		_, err = tx.Exec(`
INSERT INTO storage_volumes_new (id, name, storage_pool_id, node_id, type, description, project_id, content_type)
VALUES (?, ?, ?, ?, ?, ?, ?, ?);`,
			storageVolume.ID, storageVolume.Name, storageVolume.StoragePoolID, storageVolume.NodeID,
			storageVolume.Type, storageVolume.Description, storageVolume.ProjectID, storageVolume.ContentType)
		if err != nil {
			return err
		}
	}

	// Store rows of storage_volumes_config as we need to re-add them at the end.
	count, err = query.Count(ctx, tx, "storage_volumes_config", "")
	if err != nil {
		return fmt.Errorf("Failed to get storage_volumes_config count: %w", err)
	}

	type volumeConfig struct {
		ID              int
		StorageVolumeID int
		Key             string
		Value           string
	}

	storageVolumeConfigs := make([]volumeConfig, 0, count)
	sqlStr = `SELECT * FROM storage_volumes_config;`
	err = query.Scan(ctx, tx, sqlStr, func(scan func(dest ...any) error) error {
		config := volumeConfig{}
		err := scan(&config.ID, &config.StorageVolumeID, &config.Key, &config.Value)
		if err != nil {
			return err
		}

		storageVolumeConfigs = append(storageVolumeConfigs, config)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch storage volume configs: %w", err)
	}

	// Store rows of storage_volumes_snapshots as we need to re-add them at the end.
	count, err = query.Count(ctx, tx, "storage_volumes_snapshots", "")
	if err != nil {
		return fmt.Errorf("Failed to get storage_volumes_snapshots count: %w", err)
	}

	type volumeSnapshot struct {
		ID              int
		StorageVolumeID int
		Name            string
		Description     string
		ExpiryDate      sql.NullTime
	}

	sqlStr = `SELECT * FROM storage_volumes_snapshots;`
	storageVolumeSnapshots := make([]volumeSnapshot, 0, count)
	err = query.Scan(ctx, tx, sqlStr, func(scan func(dest ...any) error) error {
		vol := volumeSnapshot{}
		err := scan(&vol.ID, &vol.StorageVolumeID, &vol.Name, &vol.Description, &vol.ExpiryDate)
		if err != nil {
			return err
		}

		storageVolumeSnapshots = append(storageVolumeSnapshots, vol)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch storage volume snapshots: %w", err)
	}

	// Store rows of storage_volumes_snapshots_config as we need to re-add them at the end.
	count, err = query.Count(ctx, tx, "storage_volumes_snapshots_config", "")
	if err != nil {
		return fmt.Errorf("Failed to get storage_volumes_snapshots_config count: %w", err)
	}

	type volumeSnapshotConfig struct {
		ID                      int
		StorageVolumeSnapshotID int
		Key                     string
		Value                   string
	}

	storageVolumeSnapshotConfigs := make([]volumeSnapshotConfig, 0, count)

	sqlStr = `SELECT * FROM storage_volumes_snapshots_config;`
	err = query.Scan(ctx, tx, sqlStr, func(scan func(dest ...any) error) error {
		config := volumeSnapshotConfig{}
		err := scan(&config.ID, &config.StorageVolumeSnapshotID, &config.Key, &config.Value)
		if err != nil {
			return err
		}

		storageVolumeSnapshotConfigs = append(storageVolumeSnapshotConfigs, config)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch storage volume snapshot configs: %w", err)
	}

	_, err = tx.Exec(`
PRAGMA foreign_keys = OFF;
PRAGMA legacy_alter_table = ON;

DROP TABLE storage_volumes;
ALTER TABLE storage_volumes_new RENAME TO storage_volumes;

UPDATE storage_volumes
SET node_id=null
WHERE storage_volumes.id IN (
    SELECT storage_volumes.id FROM storage_volumes
    JOIN storage_pools ON storage_volumes.storage_pool_id=storage_pools.id
    WHERE storage_pools.driver IN ("ceph", "cephfs")
);

PRAGMA foreign_keys = ON;
PRAGMA legacy_alter_table = OFF;

CREATE TRIGGER storage_volumes_check_id
    BEFORE INSERT ON storage_volumes
    WHEN NEW.id IN (SELECT id FROM storage_volumes_snapshots)
    BEGIN
        SELECT RAISE(FAIL, "invalid ID");
    END;
`)
	if err != nil {
		return err
	}

	// When we dropped the storage_volumes table earlier, all config entries
	// were removed as well. Let's re-add them.
	for _, storageVolumeConfig := range storageVolumeConfigs {
		_, err = tx.Exec(`INSERT INTO storage_volumes_config (id, storage_volume_id, key, value) VALUES (?, ?, ?, ?);`, storageVolumeConfig.ID, storageVolumeConfig.StorageVolumeID, storageVolumeConfig.Key, storageVolumeConfig.Value)
		if err != nil {
			return err
		}
	}

	// When we dropped the storage_volumes table earlier, all snapshot entries
	// were removed as well. Let's re-add them.
	for _, storageVolumeSnapshot := range storageVolumeSnapshots {
		_, err = tx.Exec(`INSERT INTO storage_volumes_snapshots (id, storage_volume_id, name, description, expiry_date) VALUES (?, ?, ?, ?, ?);`, storageVolumeSnapshot.ID, storageVolumeSnapshot.StorageVolumeID, storageVolumeSnapshot.Name, storageVolumeSnapshot.Description, storageVolumeSnapshot.ExpiryDate)
		if err != nil {
			return err
		}
	}

	// When we dropped the storage_volumes table earlier, all snapshot config entries
	// were removed as well. Let's re-add them.
	for _, storageVolumeSnapshotConfig := range storageVolumeSnapshotConfigs {
		_, err = tx.Exec(`INSERT INTO storage_volumes_snapshots_config (id, storage_volume_snapshot_id, key, value) VALUES (?, ?, ?, ?);`, storageVolumeSnapshotConfig.ID, storageVolumeSnapshotConfig.StorageVolumeSnapshotID, storageVolumeSnapshotConfig.Key, storageVolumeSnapshotConfig.Value)
		if err != nil {
			return err
		}
	}

	count, err = query.Count(ctx, tx, "storage_volumes_all", "")
	if err != nil {
		return fmt.Errorf("Failed to get storage_volumes count: %w", err)
	}

	if count > 0 {
		var maxID int64

		row := tx.QueryRowContext(ctx, "SELECT MAX(id) FROM storage_volumes_all LIMIT 1")
		err = row.Scan(&maxID)
		if err != nil {
			return err
		}

		// Set sqlite_sequence to max(id)
		_, err = tx.Exec("UPDATE sqlite_sequence SET seq = ? WHERE name = 'storage_volumes'", maxID)
		if err != nil {
			return fmt.Errorf("Increment storage volumes sequence: %w", err)
		}
	}

	return nil
}

// Add project_id field to networks, add unique index across project_id and name,
// and set existing networks to project_id 1.
// This is made a lot more complex because it requires re-creating the referenced tables as there is no way to
// disable foreign keys temporarily within a transaction.
func updateFromV33(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec(`
CREATE TABLE networks_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    state INTEGER NOT NULL DEFAULT 0,
    type INTEGER NOT NULL DEFAULT 0,
    UNIQUE (project_id, name)
);

INSERT INTO networks_new (id, project_id, name, description, state, type)
    SELECT id, 1, name, description, state, type FROM networks;

CREATE TABLE networks_nodes_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    UNIQUE (network_id, node_id),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);

INSERT INTO networks_nodes_new (id, network_id, node_id)
    SELECT id, network_id, node_id FROM networks_nodes;

CREATE TABLE networks_config_new (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (network_id, node_id, key),
    FOREIGN KEY (network_id) REFERENCES networks_new (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);

INSERT INTO networks_config_new (id, network_id, node_id, key, value)
    SELECT id, network_id, node_id, key, value FROM networks_config;

DROP TABLE networks;
DROP TABLE networks_nodes;
DROP TABLE networks_config;

ALTER TABLE networks_new RENAME TO networks;
ALTER TABLE networks_nodes_new RENAME TO networks_nodes;
ALTER TABLE networks_config_new RENAME TO networks_config;
	`)
	if err != nil {
		return fmt.Errorf("Failed to add project_id column to networks table: %w", err)
	}

	return nil
}

// Add type field to networks.
func updateFromV32(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec("ALTER TABLE networks ADD COLUMN type INTEGER NOT NULL DEFAULT 0;")
	if err != nil {
		return fmt.Errorf("Failed to add type column to networks table: %w", err)
	}

	return nil
}

// Add failure_domain column to nodes table.
func updateFromV31(ctx context.Context, tx *sql.Tx) error {
	stmts := `
CREATE TABLE nodes_failure_domains (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    UNIQUE (name)
);

ALTER TABLE nodes
    ADD COLUMN failure_domain_id INTEGER DEFAULT NULL REFERENCES nodes_failure_domains (id) ON DELETE SET NULL;
`
	_, err := tx.Exec(stmts)
	if err != nil {
		return err
	}

	return nil
}

// Add content type field to storage volumes.
func updateFromV30(ctx context.Context, tx *sql.Tx) error {
	stmts := `ALTER TABLE storage_volumes ADD COLUMN content_type INTEGER NOT NULL DEFAULT 0;
UPDATE storage_volumes SET content_type = 1 WHERE type = 3;
UPDATE storage_volumes SET content_type = 1 WHERE storage_volumes.id IN (
    SELECT storage_volumes.id
        FROM storage_volumes
        JOIN images ON storage_volumes.name = images.fingerprint
        WHERE images.type = 1
);

DROP VIEW storage_volumes_all;
CREATE VIEW storage_volumes_all (
    id,
    name,
    storage_pool_id,
    node_id,
    type,
    description,
    project_id,
    content_type) AS
        SELECT id,
            name,
            storage_pool_id,
            node_id,
            type,
            description,
            project_id,
            content_type
        FROM storage_volumes UNION
            SELECT storage_volumes_snapshots.id,
                printf('%s/%s', storage_volumes.name, storage_volumes_snapshots.name),
                storage_volumes.storage_pool_id,
                storage_volumes.node_id,
                storage_volumes.type,
                storage_volumes_snapshots.description,
                storage_volumes.project_id,
                storage_volumes.content_type
            FROM storage_volumes
            JOIN storage_volumes_snapshots ON storage_volumes.id = storage_volumes_snapshots.storage_volume_id;
`
	_, err := tx.Exec(stmts)
	if err != nil {
		return fmt.Errorf("Failed to add storage volume content type: %w", err)
	}

	return nil
}

// Add storage volumes to projects references and fix images.
func updateFromV29(ctx context.Context, tx *sql.Tx) error {
	stmts := `
DROP VIEW projects_used_by_ref;
CREATE VIEW projects_used_by_ref (name, value) AS
    SELECT projects.name,
        printf('/1.0/instances/%s?project=%s',
        "instances".name,
        projects.name)
        FROM "instances" JOIN projects ON project_id=projects.id UNION
    SELECT projects.name,
        printf('/1.0/images/%s?project=%s',
        images.fingerprint,
        projects.name)
        FROM images JOIN projects ON project_id=projects.id UNION
    SELECT projects.name,
        printf('/1.0/storage-pools/%s/volumes/custom/%s?project=%s&target=%s',
        storage_pools.name,
        storage_volumes.name,
        projects.name,
        nodes.name)
        FROM storage_volumes JOIN storage_pools ON storage_pool_id=storage_pools.id JOIN nodes ON node_id=nodes.id JOIN projects ON project_id=projects.id WHERE storage_volumes.type=2 UNION
    SELECT projects.name,
        printf('/1.0/profiles/%s?project=%s',
        profiles.name,
        projects.name)
        FROM profiles JOIN projects ON project_id=projects.id;
`
	_, err := tx.Exec(stmts)
	return err
}

// Attempt to add missing project feature.
func updateFromV28(ctx context.Context, tx *sql.Tx) error {
	_, _ = tx.Exec("INSERT INTO projects_config (project_id, key, value) VALUES (1, 'features.storage.volumes', 'true');")
	return nil
}

// Add expiry date to storage volume snapshots.
func updateFromV27(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec("ALTER TABLE storage_volumes_snapshots ADD COLUMN expiry_date DATETIME;")
	return err
}

// Bump the sqlite_sequence value for storage volumes, to avoid unique
// constraint violations when inserting new snapshots.
func updateFromV26(ctx context.Context, tx *sql.Tx) error {
	ids, err := query.SelectIntegers(ctx, tx, "SELECT coalesce(max(id), 0) FROM storage_volumes_all")
	if err != nil {
		return err
	}

	_, err = tx.Exec("UPDATE sqlite_sequence SET seq = ? WHERE name = 'storage_volumes'", ids[0])
	return err
}

// Create new storage snapshot tables and migrate data to them.
func updateFromV25(ctx context.Context, tx *sql.Tx) error {
	// Get the total number of snapshot rows in the storage_volumes table.
	count, err := query.Count(ctx, tx, "storage_volumes", "snapshot=1")
	if err != nil {
		return fmt.Errorf("Failed to volume snapshot count: %w", err)
	}

	type snapshot struct {
		ID            int
		Name          string
		StoragePoolID int
		NodeID        int
		Type          int
		Description   string
		ProjectID     int
		Config        map[string]string
	}

	sql := `
SELECT id, name, storage_pool_id, node_id, type, coalesce(description, ''), project_id
    FROM storage_volumes
    WHERE snapshot=1
`
	if err != nil {
		return fmt.Errorf("Failed to prepare volume snapshot query: %w", err)
	}

	// Fetch all snapshot rows in the storage_volumes table.
	snapshots := make([]snapshot, 0, count)
	err = query.Scan(ctx, tx, sql, func(scan func(dest ...any) error) error {
		s := snapshot{}
		err := scan(&s.ID, &s.Name, &s.StoragePoolID, &s.NodeID, &s.Type, &s.Description, &s.ProjectID)
		if err != nil {
			return err
		}

		snapshots = append(snapshots, s)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch instances: %w", err)
	}

	for i, snapshot := range snapshots {
		config, err := query.SelectConfig(ctx, tx,
			"storage_volumes_config", "storage_volume_id=?",
			snapshot.ID)
		if err != nil {
			return fmt.Errorf("Failed to fetch volume snapshot config: %w", err)
		}

		snapshots[i].Config = config
	}

	stmts := `
ALTER TABLE storage_volumes RENAME TO old_storage_volumes;
CREATE TABLE "storage_volumes" (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    type INTEGER NOT NULL,
    description TEXT,
    project_id INTEGER NOT NULL,
    UNIQUE (storage_pool_id, node_id, project_id, name, type),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

ALTER TABLE storage_volumes_config RENAME TO old_storage_volumes_config;
CREATE TABLE storage_volumes_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (storage_volume_id, key),
    FOREIGN KEY (storage_volume_id) REFERENCES storage_volumes (id) ON DELETE CASCADE
);

INSERT INTO storage_volumes(id, name, storage_pool_id, node_id, type, description, project_id)
   SELECT id, name, storage_pool_id, node_id, type, description, project_id FROM old_storage_volumes
     WHERE snapshot=0;
INSERT INTO storage_volumes_config
   SELECT * FROM old_storage_volumes_config
     WHERE storage_volume_id IN (SELECT id FROM storage_volumes);
DROP TABLE old_storage_volumes;
DROP TABLE old_storage_volumes_config;

CREATE TABLE storage_volumes_snapshots (
    id INTEGER NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    UNIQUE (id),
    UNIQUE (storage_volume_id, name),
    FOREIGN KEY (storage_volume_id) REFERENCES storage_volumes (id) ON DELETE CASCADE
);

CREATE TRIGGER storage_volumes_check_id
    BEFORE INSERT ON storage_volumes
    WHEN NEW.id IN (SELECT id FROM storage_volumes_snapshots)
    BEGIN
        SELECT RAISE(FAIL, "invalid ID");
    END;
CREATE TRIGGER storage_volumes_snapshots_check_id
    BEFORE INSERT ON storage_volumes_snapshots
    WHEN NEW.id IN (SELECT id FROM storage_volumes)
    BEGIN
        SELECT RAISE(FAIL, "invalid ID");
    END;
CREATE TABLE storage_volumes_snapshots_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_snapshot_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (storage_volume_snapshot_id) REFERENCES storage_volumes_snapshots (id) ON DELETE CASCADE,
    UNIQUE (storage_volume_snapshot_id, key)
);

CREATE VIEW storage_volumes_all (
    id,
    name,
    storage_pool_id,
    node_id,
    type,
    description,
    project_id) AS
        SELECT id,
            name,
            storage_pool_id,
            node_id,
            type,
            description,
            project_id
        FROM storage_volumes UNION
            SELECT storage_volumes_snapshots.id,
                printf('%s/%s', storage_volumes.name, storage_volumes_snapshots.name),
                storage_volumes.storage_pool_id,
                storage_volumes.node_id,
                storage_volumes.type,
                storage_volumes_snapshots.description,
                storage_volumes.project_id
            FROM storage_volumes
            JOIN storage_volumes_snapshots ON storage_volumes.id = storage_volumes_snapshots.storage_volume_id;
`
	_, err = tx.Exec(stmts)
	if err != nil {
		return fmt.Errorf("Failed to create storage snapshots tables: %w", err)
	}

	// Migrate snapshots to the new tables.
	for _, snapshot := range snapshots {
		parts := strings.Split(snapshot.Name, internalInstance.SnapshotDelimiter)
		if len(parts) != 2 {
			logger.Errorf("Invalid volume snapshot name: %s", snapshot.Name)
			continue
		}

		volume := parts[0]
		name := parts[1]
		ids, err := query.SelectIntegers(ctx, tx, "SELECT id FROM storage_volumes WHERE name=?", volume)
		if err != nil {
			return err
		}

		if len(ids) != 1 {
			logger.Errorf("Volume snapshot %s has no parent", snapshot.Name)
			continue
		}

		volumeID := ids[0]
		_, err = tx.Exec(`
INSERT INTO storage_volumes_snapshots(id, storage_volume_id, name, description) VALUES(?, ?, ?, ?)
`, snapshot.ID, volumeID, name, snapshot.Description)
		if err != nil {
			return err
		}

		for key, value := range snapshot.Config {
			_, err = tx.Exec(`
INSERT INTO storage_volumes_snapshots_config(storage_volume_snapshot_id, key, value) VALUES(?, ?, ?)
`, snapshot.ID, key, value)
			if err != nil {
				return err
			}
		}
	}

	return nil
}

// The ceph.user.name config key is required for Ceph to function.
func updateFromV24(ctx context.Context, tx *sql.Tx) error {
	// Fetch the IDs of all existing Ceph pools.
	poolIDs, err := query.SelectIntegers(ctx, tx, `SELECT id FROM storage_pools WHERE driver='ceph'`)
	if err != nil {
		return fmt.Errorf("Failed to get IDs of current ceph pools: %w", err)
	}

	for _, poolID := range poolIDs {
		// Fetch the config for this Ceph pool.
		config, err := query.SelectConfig(ctx, tx, "storage_pools_config", "storage_pool_id=?", poolID)
		if err != nil {
			return fmt.Errorf("Failed to fetch of ceph pool config: %w", err)
		}

		// Check if already set.
		_, ok := config["ceph.user.name"]
		if ok {
			continue
		}

		// Add ceph.user.name config entry.
		_, err = tx.Exec("INSERT INTO storage_pools_config (storage_pool_id, key, value) VALUES (?, 'ceph.user.name', 'admin')", poolID)
		if err != nil {
			return fmt.Errorf("Failed to create ceph.user.name config: %w", err)
		}
	}

	return nil
}

// The lvm.vg_name config key is required for LVM to function.
func updateFromV23(ctx context.Context, tx *sql.Tx) error {
	// Fetch the IDs of all existing nodes.
	nodeIDs, err := query.SelectIntegers(ctx, tx, "SELECT id FROM nodes")
	if err != nil {
		return fmt.Errorf("Failed to get IDs of current nodes: %w", err)
	}

	// Fetch the IDs of all existing lvm pools.
	poolIDs, err := query.SelectIntegers(ctx, tx, `SELECT id FROM storage_pools WHERE driver='lvm'`)
	if err != nil {
		return fmt.Errorf("Failed to get IDs of current lvm pools: %w", err)
	}

	for _, poolID := range poolIDs {
		for _, nodeID := range nodeIDs {
			// Fetch the config for this lvm pool.
			config, err := query.SelectConfig(ctx, tx, "storage_pools_config", "storage_pool_id=? AND node_id=?", poolID, nodeID)
			if err != nil {
				return fmt.Errorf("Failed to fetch of lvm pool config: %w", err)
			}

			// Check if already set.
			_, ok := config["lvm.vg_name"]
			if ok {
				continue
			}

			// Add lvm.vg_name config entry.
			_, err = tx.Exec(`
INSERT INTO storage_pools_config(storage_pool_id, node_id, key, value)
SELECT ?, ?, 'lvm.vg_name', name FROM storage_pools WHERE id=?
`, poolID, nodeID, poolID)
			if err != nil {
				return fmt.Errorf("Failed to create lvm.vg_name node config: %w", err)
			}
		}
	}

	return nil
}

// The zfs.pool_name config key is required for ZFS to function.
func updateFromV22(ctx context.Context, tx *sql.Tx) error {
	// Fetch the IDs of all existing nodes.
	nodeIDs, err := query.SelectIntegers(ctx, tx, "SELECT id FROM nodes")
	if err != nil {
		return fmt.Errorf("Failed to get IDs of current nodes: %w", err)
	}

	// Fetch the IDs of all existing zfs pools.
	poolIDs, err := query.SelectIntegers(ctx, tx, `SELECT id FROM storage_pools WHERE driver='zfs'`)
	if err != nil {
		return fmt.Errorf("Failed to get IDs of current zfs pools: %w", err)
	}

	for _, poolID := range poolIDs {
		for _, nodeID := range nodeIDs {
			// Fetch the config for this zfs pool.
			config, err := query.SelectConfig(ctx, tx, "storage_pools_config", "storage_pool_id=? AND node_id=?", poolID, nodeID)
			if err != nil {
				return fmt.Errorf("Failed to fetch of zfs pool config: %w", err)
			}

			// Check if already set.
			_, ok := config["zfs.pool_name"]
			if ok {
				continue
			}

			// Add zfs.pool_name config entry
			_, err = tx.Exec(`
INSERT INTO storage_pools_config(storage_pool_id, node_id, key, value)
SELECT ?, ?, 'zfs.pool_name', name FROM storage_pools WHERE id=?
`, poolID, nodeID, poolID)
			if err != nil {
				return fmt.Errorf("Failed to create zfs.pool_name node config: %w", err)
			}
		}
	}

	return nil
}

// Fix "images_profiles" table (missing UNIQUE).
func updateFromV21(ctx context.Context, tx *sql.Tx) error {
	stmts := `
ALTER TABLE images_profiles RENAME TO old_images_profiles;
CREATE TABLE images_profiles (
    image_id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE,
    FOREIGN KEY (profile_id) REFERENCES profiles (id) ON DELETE CASCADE,
    UNIQUE (image_id, profile_id)
);

INSERT INTO images_profiles SELECT * FROM old_images_profiles;
DROP TABLE old_images_profiles;
`
	_, err := tx.Exec(stmts)
	return err
}

// Add "images_profiles" table.
func updateFromV20(ctx context.Context, tx *sql.Tx) error {
	stmts := `
CREATE TABLE images_profiles (
    image_id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE,
    FOREIGN KEY (profile_id) REFERENCES profiles (id) ON DELETE CASCADE,
    UNIQUE (image_id, profile_id)
);

INSERT INTO images_profiles (image_id, profile_id)
    SELECT images.id, profiles.id FROM images
    JOIN profiles ON images.project_id = profiles.project_id
    WHERE profiles.name = 'default';
INSERT INTO images_profiles (image_id, profile_id)
    SELECT images.id, profiles.id FROM projects_config AS R
    JOIN projects_config AS S ON R.project_id = S.project_id
    JOIN images ON images.project_id = R.project_id
    JOIN profiles ON profiles.project_id = 1 AND profiles.name = "default"
    WHERE R.key = "features.images" AND S.key = "features.profiles" AND R.value = "true" AND S.value != "true";
INSERT INTO images_profiles (image_id, profile_id)
    SELECT images.id, profiles.id FROM projects_config AS R
    JOIN projects_config AS S ON R.project_id = S.project_id
    JOIN profiles ON profiles.project_id = R.project_id
    JOIN images ON images.project_id = 1
    WHERE R.key = "features.images" AND S.key = "features.profiles" AND R.value != "true" AND S.value = "true"
        AND profiles.name = "default";
`
	_, err := tx.Exec(stmts)
	return err
}

// Add a new "arch" column to the "nodes" table.
func updateFromV19(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec("PRAGMA ignore_check_constraints=on")
	if err != nil {
		return err
	}

	defer func() { _, _ = tx.Exec("PRAGMA ignore_check_constraints=off") }()

	// The column has a not-null constraint and a default value of
	// 0. However, leaving the 0 default won't effectively be accepted when
	// creating a new, due to the check constraint, so we are sure to end
	// up with a valid value.
	_, err = tx.Exec("ALTER TABLE nodes ADD COLUMN arch INTEGER NOT NULL DEFAULT 0 CHECK (arch > 0)")
	if err != nil {
		return err
	}

	arch, err := osarch.ArchitectureGetLocalID()
	if err != nil {
		return err
	}

	_, err = tx.Exec("UPDATE nodes SET arch = ?", arch)
	if err != nil {
		return err
	}

	return nil
}

// Rename 'containers' to 'instances' in *_used_by_ref views.
func updateFromV18(ctx context.Context, tx *sql.Tx) error {
	stmts := `
DROP VIEW profiles_used_by_ref;
CREATE VIEW profiles_used_by_ref (project, name, value) AS
    SELECT projects.name,
        profiles.name,
        printf('/1.0/instances/%s?project=%s',
        "instances".name,
        instances_projects.name)
    FROM profiles
    JOIN projects ON projects.id=profiles.project_id
    JOIN "instances_profiles" ON "instances_profiles".profile_id=profiles.id
    JOIN "instances" ON "instances".id="instances_profiles".instance_id
    JOIN projects AS instances_projects ON instances_projects.id="instances".project_id;

DROP VIEW projects_used_by_ref;
CREATE VIEW projects_used_by_ref (name, value) AS
    SELECT projects.name,
        printf('/1.0/instances/%s?project=%s',
        "instances".name,
        projects.name)
    FROM "instances" JOIN projects ON project_id=projects.id UNION
    SELECT projects.name,
        printf('/1.0/images/%s',
        images.fingerprint)
    FROM images JOIN projects ON project_id=projects.id UNION
    SELECT projects.name,
        printf('/1.0/profiles/%s?project=%s',
        profiles.name,
        projects.name)
    FROM profiles JOIN projects ON project_id=projects.id;
`
	_, err := tx.Exec(stmts)
	return err
}

// Add nodes_roles table.
func updateFromV17(ctx context.Context, tx *sql.Tx) error {
	stmts := `
CREATE TABLE nodes_roles (
    node_id INTEGER NOT NULL,
    role INTEGER NOT NULL,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    UNIQUE (node_id, role)
);
`
	_, err := tx.Exec(stmts)
	return err
}

// Add image type column.
func updateFromV16(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec("ALTER TABLE images ADD COLUMN type INTEGER NOT NULL DEFAULT 0;")
	return err
}

// Create new snapshot tables and migrate data to them.
func updateFromV15(ctx context.Context, tx *sql.Tx) error {
	stmts := `
CREATE TABLE instances_snapshots (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    creation_date DATETIME NOT NULL DEFAULT 0,
    stateful INTEGER NOT NULL DEFAULT 0,
    description TEXT,
    expiry_date DATETIME,
    UNIQUE (instance_id, name),
    FOREIGN KEY (instance_id) REFERENCES instances (id) ON DELETE CASCADE
);
CREATE TABLE instances_snapshots_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    instance_snapshot_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (instance_snapshot_id) REFERENCES instances_snapshots (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_id, key)
);
CREATE TABLE instances_snapshots_devices (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_snapshot_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    FOREIGN KEY (instance_snapshot_id) REFERENCES instances_snapshots (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_id, name)
);
CREATE TABLE instances_snapshots_devices_config (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    instance_snapshot_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (instance_snapshot_device_id) REFERENCES instances_snapshots_devices (id) ON DELETE CASCADE,
    UNIQUE (instance_snapshot_device_id, key)
);
CREATE VIEW instances_snapshots_config_ref (
    project,
    instance,
    name,
    key,
    value) AS
        SELECT
            projects.name,
            instances.name,
            instances_snapshots.name,
            instances_snapshots_config.key,
            instances_snapshots_config.value
        FROM instances_snapshots_config
            JOIN instances_snapshots ON instances_snapshots.id=instances_snapshots_config.instance_snapshot_id
            JOIN instances ON instances.id=instances_snapshots.instance_id
            JOIN projects ON projects.id=instances.project_id;
CREATE VIEW instances_snapshots_devices_ref (
    project,
    instance,
    name,
    device,
    type,
    key,
    value) AS
        SELECT
            projects.name,
            instances.name,
            instances_snapshots.name,
            instances_snapshots_devices.name,
            instances_snapshots_devices.type,
            coalesce(instances_snapshots_devices_config.key, ''),
            coalesce(instances_snapshots_devices_config.value, '')
        FROM instances_snapshots_devices
            LEFT OUTER JOIN instances_snapshots_devices_config ON instances_snapshots_devices_config.instance_snapshot_device_id=instances_snapshots_devices.id
            JOIN instances ON instances.id=instances_snapshots.instance_id
            JOIN projects ON projects.id=instances.project_id
            JOIN instances_snapshots ON instances_snapshots.id=instances_snapshots_devices.instance_snapshot_id
`
	_, err := tx.Exec(stmts)
	if err != nil {
		return fmt.Errorf("Failed to create snapshots tables: %w", err)
	}

	// Get the total number of rows in the instances table.
	count, err := query.Count(ctx, tx, "instances", "")
	if err != nil {
		return fmt.Errorf("Failed to count rows in instances table: %w", err)
	}

	// Fetch all rows in the instances table.
	type instance struct {
		ID           int
		Name         string
		Type         int
		CreationDate time.Time
		Stateful     bool
		Description  string
		ExpiryDate   sql.NullTime
	}

	sql := `SELECT id, name, type, creation_date, stateful, coalesce(description, ''), expiry_date FROM instances`
	instances := make([]instance, 0, count)
	err = query.Scan(ctx, tx, sql, func(scan func(dest ...any) error) error {
		inst := instance{}
		err := scan(&inst.ID, &inst.Name, &inst.Type, &inst.CreationDate, &inst.Stateful, &inst.Description, &inst.ExpiryDate)
		if err != nil {
			return err
		}

		instances = append(instances, inst)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch instances: %w", err)
	}

	// Create an index mapping instance names to their IDs.
	instanceIDsByName := make(map[string]int)
	for _, instance := range instances {
		if instance.Type == 1 {
			continue
		}

		instanceIDsByName[instance.Name] = instance.ID
	}

	// Fetch all rows in the instances_config table that references
	// snapshots and index them by instance ID.
	count, err = query.Count(
		ctx,
		tx,
		"instances_config JOIN instances ON instances_config.instance_id = instances.id",
		"instances.type = 1")
	if err != nil {
		return fmt.Errorf("Failed to count rows in instances_config table: %w", err)
	}

	type instanceConfig struct {
		ID         int
		InstanceID int
		Key        string
		Value      string
	}

	configs := make([]instanceConfig, 0, count)
	sql = `
SELECT instances_config.id, instance_id, key, value
    FROM instances_config JOIN instances ON instances_config.instance_id = instances.id
    WHERE instances.type = 1
`

	err = query.Scan(ctx, tx, sql, func(scan func(dest ...any) error) error {
		config := instanceConfig{}
		err := scan(&config.ID, &config.InstanceID, &config.Key, &config.Value)
		if err != nil {
			return err
		}

		configs = append(configs, config)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch snapshots config: %w", err)
	}

	configBySnapshotID := make(map[int]map[string]string)
	for _, config := range configs {
		c, ok := configBySnapshotID[config.InstanceID]
		if !ok {
			c = make(map[string]string)
			configBySnapshotID[config.InstanceID] = c
		}

		c[config.Key] = config.Value
	}

	// Fetch all rows in the instances_devices table that references
	// snapshots and index them by instance ID.
	count, err = query.Count(
		ctx,
		tx,
		"instances_devices JOIN instances ON instances_devices.instance_id = instances.id",
		"instances.type = 1")
	if err != nil {
		return fmt.Errorf("Failed to count rows in instances_devices table: %w", err)
	}

	type device struct {
		ID         int
		InstanceID int
		Name       string
		Type       int
	}

	devices := make([]device, 0, count)
	sql = `
SELECT instances_devices.id, instance_id, instances_devices.name, instances_devices.type
    FROM instances_devices JOIN instances ON instances_devices.instance_id = instances.id
    WHERE instances.type = 1
`

	err = query.Scan(ctx, tx, sql, func(scan func(dest ...any) error) error {
		d := device{}
		err := scan(&d.ID, &d.InstanceID, &d.Name, &d.Type)
		if err != nil {
			return err
		}

		devices = append(devices, d)

		return nil
	})
	if err != nil {
		return fmt.Errorf("Failed to fetch snapshots devices: %w", err)
	}

	devicesBySnapshotID := make(map[int]map[string]struct {
		Type   int
		Config map[string]string
	})
	for _, device := range devices {
		d, ok := devicesBySnapshotID[device.InstanceID]
		if !ok {
			d = make(map[string]struct {
				Type   int
				Config map[string]string
			})
			devicesBySnapshotID[device.InstanceID] = d
		}
		// Fetch the config for this device.
		config, err := query.SelectConfig(ctx, tx, "instances_devices_config", "instance_device_id = ?", device.ID)
		if err != nil {
			return fmt.Errorf("Failed to fetch snapshots devices config: %w", err)
		}

		d[device.Name] = struct {
			Type   int
			Config map[string]string
		}{
			Type:   device.Type,
			Config: config,
		}
	}

	// Migrate all snapshots to the new tables.
	for _, instance := range instances {
		if instance.Type == 0 {
			continue
		}

		// Figure out the instance and snapshot names.
		parts := strings.SplitN(instance.Name, internalInstance.SnapshotDelimiter, 2)
		if len(parts) != 2 {
			return fmt.Errorf("Snapshot %s has an invalid name", instance.Name)
		}

		instanceName := parts[0]
		instanceID, ok := instanceIDsByName[instanceName]
		if !ok {
			return fmt.Errorf("Found snapshot %s with no associated instance", instance.Name)
		}

		snapshotName := parts[1]

		// Insert a new row in instances_snapshots
		columns := []string{
			"instance_id",
			"name",
			"creation_date",
			"stateful",
			"description",
			"expiry_date",
		}

		id, err := query.UpsertObject(
			tx,
			"instances_snapshots",
			columns,
			[]any{
				instanceID,
				snapshotName,
				instance.CreationDate,
				instance.Stateful,
				instance.Description,
				instance.ExpiryDate,
			},
		)
		if err != nil {
			return fmt.Errorf("Failed migrate snapshot %s: %w", instance.Name, err)
		}

		// Migrate the snapshot config
		for key, value := range configBySnapshotID[instance.ID] {
			columns := []string{
				"instance_snapshot_id",
				"key",
				"value",
			}

			_, err := query.UpsertObject(
				tx,
				"instances_snapshots_config",
				columns,
				[]any{
					id,
					key,
					value,
				},
			)
			if err != nil {
				return fmt.Errorf("Failed migrate config %s/%s for snapshot %s: %w", key, value, instance.Name, err)
			}
		}

		// Migrate the snapshot devices
		for name, device := range devicesBySnapshotID[instance.ID] {
			columns := []string{
				"instance_snapshot_id",
				"name",
				"type",
			}

			deviceID, err := query.UpsertObject(
				tx,
				"instances_snapshots_devices",
				columns,
				[]any{
					id,
					name,
					device.Type,
				},
			)
			if err != nil {
				return fmt.Errorf("Failed migrate device %s for snapshot %s: %w", name, instance.Name, err)
			}

			for key, value := range device.Config {
				columns := []string{
					"instance_snapshot_device_id",
					"key",
					"value",
				}

				_, err := query.UpsertObject(
					tx,
					"instances_snapshots_devices_config",
					columns,
					[]any{
						deviceID,
						key,
						value,
					},
				)
				if err != nil {
					return fmt.Errorf("Failed migrate config %s/%s for device %s of snapshot %s: %w", key, value, name, instance.Name, err)
				}
			}
		}

		deleted, err := query.DeleteObject(tx, "instances", int64(instance.ID))
		if err != nil {
			return fmt.Errorf("Failed to delete snapshot %s: %w", instance.Name, err)
		}

		if !deleted {
			return fmt.Errorf("Expected to delete snapshot %s", instance.Name)
		}
	}

	// Make sure that no snapshot is left in the instances table.
	count, err = query.Count(ctx, tx, "instances", "type = 1")
	if err != nil {
		return fmt.Errorf("Failed to count leftover snapshot rows: %w", err)
	}

	if count != 0 {
		return fmt.Errorf("Found %d unexpected snapshots left in instances table", count)
	}

	return nil
}

// Rename all containers* tables to instances*/.
func updateFromV14(ctx context.Context, tx *sql.Tx) error {
	stmts := `
ALTER TABLE containers RENAME TO instances;
ALTER TABLE containers_backups RENAME COLUMN container_id TO instance_id;
ALTER TABLE containers_backups RENAME TO instances_backups;
ALTER TABLE containers_config RENAME COLUMN container_id TO instance_id;
ALTER TABLE containers_config RENAME TO instances_config;

DROP VIEW containers_config_ref;
CREATE VIEW instances_config_ref (project,
    node,
    name,
    key,
    value) AS
        SELECT projects.name,
            nodes.name,
            instances.name,
            instances_config.key,
            instances_config.value
        FROM instances_config
            JOIN instances ON instances.id=instances_config.instance_id
            JOIN projects ON projects.id=instances.project_id
            JOIN nodes ON nodes.id=instances.node_id;

ALTER TABLE containers_devices RENAME COLUMN container_id TO instance_id;
ALTER TABLE containers_devices RENAME TO instances_devices;
ALTER TABLE containers_devices_config RENAME COLUMN container_device_id TO instance_device_id;
ALTER TABLE containers_devices_config RENAME TO instances_devices_config;

DROP VIEW containers_devices_ref;
CREATE VIEW instances_devices_ref (project,
    node,
    name,
    device,
    type,
    key,
    value) AS
        SELECT projects.name,
            nodes.name,
            instances.name,
            instances_devices.name,
            instances_devices.type,
            coalesce(instances_devices_config.key, ''),
            coalesce(instances_devices_config.value, '')
        FROM instances_devices
        LEFT OUTER JOIN instances_devices_config ON instances_devices_config.instance_device_id=instances_devices.id
        JOIN instances ON instances.id=instances_devices.instance_id
        JOIN projects ON projects.id=instances.project_id
        JOIN nodes ON nodes.id=instances.node_id;

DROP INDEX containers_node_id_idx;
CREATE INDEX instances_node_id_idx ON instances (node_id);
ALTER TABLE containers_profiles RENAME COLUMN container_id TO instance_id;
ALTER TABLE containers_profiles RENAME TO instances_profiles;

DROP VIEW containers_profiles_ref;
CREATE VIEW instances_profiles_ref (project,
    node,
    name,
    value) AS
        SELECT projects.name,
            nodes.name,
            instances.name,
            profiles.name
        FROM instances_profiles
        JOIN instances ON instances.id=instances_profiles.instance_id
        JOIN profiles ON profiles.id=instances_profiles.profile_id
        JOIN projects ON projects.id=instances.project_id
        JOIN nodes ON nodes.id=instances.node_id
        ORDER BY instances_profiles.apply_order;

DROP INDEX containers_project_id_and_name_idx;
DROP INDEX containers_project_id_and_node_id_and_name_idx;
DROP INDEX containers_project_id_and_node_id_idx;
DROP INDEX containers_project_id_idx;
CREATE INDEX instances_project_id_and_name_idx ON instances (project_id, name);
CREATE INDEX instances_project_id_and_node_id_and_name_idx ON instances (project_id, node_id, name);
CREATE INDEX instances_project_id_and_node_id_idx ON instances (project_id, node_id);
CREATE INDEX instances_project_id_idx ON instances (project_id);

DROP VIEW profiles_used_by_ref;
CREATE VIEW profiles_used_by_ref (project,
    name,
    value) AS
        SELECT projects.name,
            profiles.name,
            printf('/1.0/containers/%s?project=%s',
            "instances".name,
            instances_projects.name)
        FROM profiles
        JOIN projects ON projects.id=profiles.project_id
        JOIN "instances_profiles" ON "instances_profiles".profile_id=profiles.id
        JOIN "instances" ON "instances".id="instances_profiles".instance_id
        JOIN projects AS instances_projects ON instances_projects.id="instances".project_id;
`
	_, err := tx.Exec(stmts)
	return err
}

func updateFromV13(ctx context.Context, tx *sql.Tx) error {
	_, err := tx.Exec("ALTER TABLE containers ADD COLUMN expiry_date DATETIME;")
	return err
}

func updateFromV12(ctx context.Context, tx *sql.Tx) error {
	stmts := `
DROP VIEW profiles_used_by_ref;
CREATE VIEW profiles_used_by_ref (project,
    name,
    value) AS
        SELECT projects.name,
            profiles.name,
            printf('/1.0/containers/%s?project=%s',
            containers.name,
            containers_projects.name)
        FROM profiles
        JOIN projects ON projects.id=profiles.project_id
        JOIN containers_profiles ON containers_profiles.profile_id=profiles.id
        JOIN containers ON containers.id=containers_profiles.container_id
        JOIN projects AS containers_projects ON containers_projects.id=containers.project_id;
`
	_, err := tx.Exec(stmts)
	return err
}

func updateFromV11(ctx context.Context, tx *sql.Tx) error {
	// There was at least a case of dangling references to rows in the
	// containers table that don't exist anymore. So sanitize them before
	// we move forward. See #5176.
	stmts := `
DELETE FROM containers_config WHERE container_id NOT IN (SELECT id FROM containers);
DELETE FROM containers_backups WHERE container_id NOT IN (SELECT id FROM containers);
DELETE FROM containers_devices WHERE container_id NOT IN (SELECT id FROM containers);
DELETE FROM containers_devices_config WHERE container_device_id NOT IN (SELECT id FROM containers_devices);
DELETE FROM containers_profiles WHERE container_id NOT IN (SELECT id FROM containers);
DELETE FROM containers_profiles WHERE profile_id NOT IN (SELECT id FROM profiles);
DELETE FROM images_aliases WHERE image_id NOT IN (SELECT id FROM images);
DELETE FROM images_properties WHERE image_id NOT IN (SELECT id FROM images);
DELETE FROM images_source WHERE image_id NOT IN (SELECT id FROM images);
DELETE FROM networks_config WHERE network_id NOT IN (SELECT id FROM networks);
DELETE FROM profiles_config WHERE profile_id NOT IN (SELECT id FROM profiles);
DELETE FROM profiles_devices WHERE profile_id NOT IN (SELECT id FROM profiles);
DELETE FROM profiles_devices_config WHERE profile_device_id NOT IN (SELECT id FROM profiles_devices);
DELETE FROM storage_pools_config WHERE storage_pool_id NOT IN (SELECT id FROM storage_pools);
DELETE FROM storage_volumes WHERE storage_pool_id NOT IN (SELECT id FROM storage_pools);
DELETE FROM storage_volumes_config WHERE storage_volume_id NOT IN (SELECT id FROM storage_volumes);
`
	_, err := tx.Exec(stmts)
	if err != nil {
		return fmt.Errorf("Remove dangling references to containers: %w", err)
	}

	// Before doing anything save the counts of all tables, so we can later
	// check that we don't accidentally delete or add anything.
	counts1, err := query.CountAll(ctx, tx)
	if err != nil {
		return fmt.Errorf("Failed to count rows in current tables: %w", err)
	}

	// Temporarily increase the cache size and disable page spilling, to
	// avoid unnecessary writes to the WAL.
	_, err = tx.Exec("PRAGMA cache_size=100000")
	if err != nil {
		return fmt.Errorf("Increase cache size: %w", err)
	}

	_, err = tx.Exec("PRAGMA cache_spill=0")
	if err != nil {
		return fmt.Errorf("Disable spilling cache pages to disk: %w", err)
	}

	// Use a large timeout since the update might take a while, due to the
	// new indexes being created.
	ctx, cancel := context.WithTimeout(ctx, time.Minute)
	defer cancel()

	stmts = `
CREATE TABLE projects (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    UNIQUE (name)
);

CREATE TABLE projects_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    project_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE,
    UNIQUE (project_id, key)
);

CREATE VIEW projects_config_ref (name, key, value) AS
    SELECT projects.name, projects_config.key, projects_config.value
        FROM projects_config
        JOIN projects ON projects.id=projects_config.project_id;

-- Insert the default project, with ID 1
INSERT INTO projects (name, description) VALUES ('default', 'Default Incus project');
INSERT INTO projects_config (project_id, key, value) VALUES (1, 'features.images', 'true');
INSERT INTO projects_config (project_id, key, value) VALUES (1, 'features.profiles', 'true');

-- Add a project_id column to all tables that need to be project-scoped.
-- The column is added without the FOREIGN KEY constraint
ALTER TABLE containers ADD COLUMN project_id INTEGER NOT NULL DEFAULT 1;
ALTER TABLE images ADD COLUMN project_id INTEGER NOT NULL DEFAULT 1;
ALTER TABLE images_aliases ADD COLUMN project_id INTEGER NOT NULL DEFAULT 1;
ALTER TABLE profiles ADD COLUMN project_id INTEGER NOT NULL DEFAULT 1;
ALTER TABLE storage_volumes ADD COLUMN project_id INTEGER NOT NULL DEFAULT 1;
ALTER TABLE operations ADD COLUMN project_id INTEGER;

-- Create new versions of the above tables, this time with the FOREIGN key constraint
CREATE TABLE new_containers (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    architecture INTEGER NOT NULL,
    type INTEGER NOT NULL,
    ephemeral INTEGER NOT NULL DEFAULT 0,
    creation_date DATETIME NOT NULL DEFAULT 0,
    stateful INTEGER NOT NULL DEFAULT 0,
    last_use_date DATETIME,
    description TEXT,
    project_id INTEGER NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE TABLE new_images (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    fingerprint TEXT NOT NULL,
    filename TEXT NOT NULL,
    size INTEGER NOT NULL,
    public INTEGER NOT NULL DEFAULT 0,
    architecture INTEGER NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    upload_date DATETIME NOT NULL,
    cached INTEGER NOT NULL DEFAULT 0,
    last_use_date DATETIME,
    auto_update INTEGER NOT NULL DEFAULT 0,
    project_id INTEGER NOT NULL,
    UNIQUE (project_id, fingerprint),
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE TABLE new_images_aliases (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    image_id INTEGER NOT NULL,
    description TEXT,
    project_id INTEGER NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE TABLE new_profiles (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    project_id INTEGER NOT NULL,
    UNIQUE (project_id, name),
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE TABLE new_storage_volumes (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    type INTEGER NOT NULL,
    description TEXT,
    snapshot INTEGER NOT NULL DEFAULT 0,
    project_id INTEGER NOT NULL,
    UNIQUE (storage_pool_id, node_id, project_id, name, type),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

CREATE TABLE new_operations (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    uuid TEXT NOT NULL,
    node_id TEXT NOT NULL,
    type INTEGER NOT NULL DEFAULT 0,
    project_id INTEGER,
    UNIQUE (uuid),
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE,
    FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE
);

-- Create copy version of all the tables that have direct or indirect references
-- to the tables above, which we are going to drop. The copy just have the data,
-- without FOREIGN KEY references.
CREATE TABLE containers_backups_copy (
    id INTEGER NOT NULL,
    container_id INTEGER NOT NULL,
    name VARCHAR(255) NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    container_only INTEGER NOT NULL default 0,
    optimized_storage INTEGER NOT NULL default 0,
    UNIQUE (container_id, name)
);
INSERT INTO containers_backups_copy SELECT * FROM containers_backups;

CREATE TABLE containers_config_copy (
    id INTEGER NOT NULL,
    container_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (container_id, key)
);
INSERT INTO containers_config_copy SELECT * FROM containers_config;

CREATE TABLE containers_devices_copy (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    container_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    UNIQUE (container_id, name)
);
INSERT INTO containers_devices_copy SELECT * FROM containers_devices;

CREATE TABLE containers_devices_config_copy (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    container_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (container_device_id, key)
);
INSERT INTO containers_devices_config_copy SELECT * FROM containers_devices_config;

CREATE TABLE containers_profiles_copy (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    container_id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    apply_order INTEGER NOT NULL default 0,
    UNIQUE (container_id, profile_id)
);
INSERT INTO containers_profiles_copy SELECT * FROM containers_profiles;

CREATE TABLE images_aliases_copy (
    id INTEGER NOT NULL,
    name TEXT NOT NULL,
    image_id INTEGER NOT NULL,
    description TEXT,
    project_id INTEGER NOT NULL,
    UNIQUE (name)
);
INSERT INTO images_aliases_copy SELECT * FROM images_aliases;

CREATE TABLE images_nodes_copy (
    id INTEGER NOT NULL,
    image_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    UNIQUE (image_id, node_id)
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
INSERT INTO images_nodes_copy SELECT * FROM images_nodes;

CREATE TABLE images_properties_copy (
    id INTEGER NOT NULL,
    image_id INTEGER NOT NULL,
    type INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT
);
INSERT INTO images_properties_copy SELECT * FROM images_properties;

CREATE TABLE images_source_copy (
    id INTEGER NOT NULL,
    image_id INTEGER NOT NULL,
    server TEXT NOT NULL,
    protocol INTEGER NOT NULL,
    certificate TEXT NOT NULL,
    alias TEXT NOT NULL
);
INSERT INTO images_source_copy SELECT * FROM images_source;

CREATE TABLE profiles_config_copy (
    id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (profile_id, key)
);
INSERT INTO profiles_config_copy SELECT * FROM profiles_config;

CREATE TABLE profiles_devices_copy (
    id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    UNIQUE (profile_id, name)
);
INSERT INTO profiles_devices_copy SELECT * FROM profiles_devices;

CREATE TABLE profiles_devices_config_copy (
    id INTEGER NOT NULL,
    profile_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (profile_device_id, key)
);
INSERT INTO profiles_devices_config_copy SELECT * FROM profiles_devices_config;

CREATE TABLE storage_volumes_config_copy (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (storage_volume_id, key)
);
INSERT INTO storage_volumes_config_copy SELECT * FROM storage_volumes_config;

-- Copy existing data into the new tables with the project_id reference
INSERT INTO new_containers SELECT * FROM containers;
INSERT INTO new_images SELECT * FROM images;
INSERT INTO new_profiles SELECT * FROM profiles;
INSERT INTO new_storage_volumes SELECT * FROM storage_volumes;
INSERT INTO new_operations SELECT * FROM operations;

-- Drop the old table and rename the new ones. This will trigger cascading
-- deletes on all tables that have direct or indirect references to the old
-- table, but we have a copy of them that we will use for restoring.
DROP TABLE containers;
ALTER TABLE new_containers RENAME TO containers;

DROP TABLE images;
ALTER TABLE new_images RENAME TO images;

DROP TABLE profiles;
ALTER TABLE new_profiles RENAME TO profiles;

DROP TABLE storage_volumes;
ALTER TABLE new_storage_volumes RENAME TO storage_volumes;

INSERT INTO new_images_aliases SELECT * FROM images_aliases_copy;

DROP TABLE images_aliases;
DROP TABLE images_aliases_copy;
ALTER TABLE new_images_aliases RENAME TO images_aliases;

DROP TABLE operations;
ALTER TABLE new_operations RENAME TO operations;

-- Restore the content of the tables with direct or indirect references.
INSERT INTO containers_backups SELECT * FROM containers_backups_copy;
INSERT INTO containers_config SELECT * FROM containers_config_copy;
INSERT INTO containers_devices SELECT * FROM containers_devices_copy;
INSERT INTO containers_devices_config SELECT * FROM containers_devices_config_copy;
INSERT INTO containers_profiles SELECT * FROM containers_profiles_copy;
INSERT INTO images_nodes SELECT * FROM images_nodes_copy;
INSERT INTO images_properties SELECT * FROM images_properties_copy;
INSERT INTO images_source SELECT * FROM images_source_copy;
INSERT INTO profiles_config SELECT * FROM profiles_config_copy;
INSERT INTO profiles_devices SELECT * FROM profiles_devices_copy;
INSERT INTO profiles_devices_config SELECT * FROM profiles_devices_config_copy;
INSERT INTO storage_volumes_config SELECT * FROM storage_volumes_config_copy;

-- Drop the copies.
DROP TABLE containers_backups_copy;
DROP TABLE containers_config_copy;
DROP TABLE containers_devices_copy;
DROP TABLE containers_devices_config_copy;
DROP TABLE containers_profiles_copy;
DROP TABLE images_nodes_copy;
DROP TABLE images_properties_copy;
DROP TABLE images_source_copy;
DROP TABLE profiles_config_copy;
DROP TABLE profiles_devices_copy;
DROP TABLE profiles_devices_config_copy;
DROP TABLE storage_volumes_config_copy;

-- Create some indexes to speed up queries filtered by project ID and node ID
CREATE INDEX containers_node_id_idx ON containers (node_id);
CREATE INDEX containers_project_id_idx ON containers (project_id);
CREATE INDEX containers_project_id_and_name_idx ON containers (project_id, name);
CREATE INDEX containers_project_id_and_node_id_idx ON containers (project_id, node_id);
CREATE INDEX containers_project_id_and_node_id_and_name_idx ON containers (project_id, node_id, name);
CREATE INDEX images_project_id_idx ON images (project_id);
CREATE INDEX images_aliases_project_id_idx ON images_aliases (project_id);
CREATE INDEX profiles_project_id_idx ON profiles (project_id);
`
	_, err = tx.ExecContext(ctx, stmts)
	if err != nil {
		return fmt.Errorf("Failed to add project_id column: %w", err)
	}

	// Create a view to easily query all resources using a certain project
	stmt := fmt.Sprintf(`
CREATE VIEW projects_used_by_ref (name, value) AS
    SELECT projects.name, printf('%s', containers.name, projects.name)
        FROM containers JOIN projects ON project_id=projects.id UNION
    SELECT projects.name, printf('%s', images.fingerprint)
        FROM images JOIN projects ON project_id=projects.id UNION
    SELECT projects.name, printf('%s', profiles.name, projects.name)
        FROM profiles JOIN projects ON project_id=projects.id
`, EntityURIs[TypeContainer], EntityURIs[TypeImage], EntityURIs[TypeProfile])
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to create projects_used_by_ref view: %w", err)
	}

	// Create a view to easily query all profiles used by a certain container
	stmt = `
CREATE VIEW containers_profiles_ref (project, node, name, value) AS
    SELECT projects.name, nodes.name, containers.name, profiles.name
    FROM containers_profiles
    JOIN containers ON containers.id=containers_profiles.container_id
    JOIN profiles ON profiles.id=containers_profiles.profile_id
    JOIN projects ON projects.id=containers.project_id
    JOIN nodes ON nodes.id=containers.node_id
    ORDER BY containers_profiles.apply_order
`
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to containers_profiles_ref view: %w", err)
	}

	// Create a view to easily query the config of a certain container.
	stmt = `
CREATE VIEW containers_config_ref (project, node, name, key, value) AS
    SELECT projects.name, nodes.name, containers.name, containers_config.key, containers_config.value
    FROM containers_config
    JOIN containers ON containers.id=containers_config.container_id
    JOIN projects ON projects.id=containers.project_id
    JOIN nodes ON nodes.id=containers.node_id
`
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to containers_config_ref view: %w", err)
	}

	// Create a view to easily query the devices of a certain container.
	stmt = `
CREATE VIEW containers_devices_ref (project, node, name, device, type, key, value) AS
    SELECT projects.name, nodes.name, containers.name,
           containers_devices.name, containers_devices.type,
           coalesce(containers_devices_config.key, ''), coalesce(containers_devices_config.value, '')
    FROM containers_devices
    LEFT OUTER JOIN containers_devices_config ON containers_devices_config.container_device_id=containers_devices.id
    JOIN containers ON containers.id=containers_devices.container_id
    JOIN projects ON projects.id=containers.project_id
    JOIN nodes ON nodes.id=containers.node_id
`
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to containers_devices_ref view: %w", err)
	}

	// Create a view to easily query the config of a certain profile.
	stmt = `
CREATE VIEW profiles_config_ref (project, name, key, value) AS
    SELECT projects.name, profiles.name, profiles_config.key, profiles_config.value
    FROM profiles_config
    JOIN profiles ON profiles.id=profiles_config.profile_id
    JOIN projects ON projects.id=profiles.project_id
`
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to profiles_config_ref view: %w", err)
	}

	// Create a view to easily query the devices of a certain profile.
	stmt = `
CREATE VIEW profiles_devices_ref (project, name, device, type, key, value) AS
    SELECT projects.name, profiles.name,
           profiles_devices.name, profiles_devices.type,
           coalesce(profiles_devices_config.key, ''), coalesce(profiles_devices_config.value, '')
    FROM profiles_devices
    LEFT OUTER JOIN profiles_devices_config ON profiles_devices_config.profile_device_id=profiles_devices.id
    JOIN profiles ON profiles.id=profiles_devices.profile_id
    JOIN projects ON projects.id=profiles.project_id
`
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to profiles_devices_ref view: %w", err)
	}

	// Create a view to easily query all resources using a certain profile
	stmt = fmt.Sprintf(`
CREATE VIEW profiles_used_by_ref (project, name, value) AS
    SELECT projects.name, profiles.name, printf('%s', containers.name, projects.name)
    FROM profiles
    JOIN projects ON projects.id=profiles.project_id
    JOIN containers_profiles
      ON containers_profiles.profile_id=profiles.id
    JOIN containers
      ON containers.id=containers_profiles.container_id
`, EntityURIs[TypeContainer])
	_, err = tx.Exec(stmt)
	if err != nil {
		return fmt.Errorf("Failed to create profiles_used_by_ref view: %w", err)
	}

	// Check that the count of all rows in the database is unchanged
	// (i.e. we didn't accidentally delete or add anything).
	counts2, err := query.CountAll(ctx, tx)
	if err != nil {
		return fmt.Errorf("Failed to count rows in updated tables: %w", err)
	}

	delete(counts2, "projects")

	for table, count1 := range counts1 {
		if table == "sqlite_sequence" {
			continue
		}

		count2 := counts2[table]
		if count1 != count2 {
			return fmt.Errorf("Row count mismatch in table '%s': %d vs %d", table, count1, count2)
		}
	}

	// Restore default cache values.
	_, err = tx.Exec("PRAGMA cache_size=2000")
	if err != nil {
		return fmt.Errorf("Increase cache size: %w", err)
	}

	_, err = tx.Exec("PRAGMA cache_spill=1")
	if err != nil {
		return fmt.Errorf("Disable spilling cache pages to disk: %w", err)
	}

	return err
}

func updateFromV10(ctx context.Context, tx *sql.Tx) error {
	stmt := `
ALTER TABLE storage_volumes ADD COLUMN snapshot INTEGER NOT NULL DEFAULT 0;
UPDATE storage_volumes SET snapshot = 0;
`
	_, err := tx.Exec(stmt)
	return err
}

// Add a new 'type' column to the operations table.
func updateFromV9(ctx context.Context, tx *sql.Tx) error {
	stmts := `
	ALTER TABLE operations ADD COLUMN type INTEGER NOT NULL DEFAULT 0;
	UPDATE operations SET type = 0;
	`
	_, err := tx.Exec(stmts)
	return err
}

// The lvm.thinpool_name and lvm.vg_name config keys are node-specific and need
// to be linked to nodes.
func updateFromV8(ctx context.Context, tx *sql.Tx) error {
	// Moved to patchLvmNodeSpecificConfigKeys, since there's no schema
	// change. That makes it easier to backport.
	return nil
}

func updateFromV7(ctx context.Context, tx *sql.Tx) error {
	stmts := `
CREATE TABLE containers_backups (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    container_id INTEGER NOT NULL,
    name VARCHAR(255) NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    container_only INTEGER NOT NULL default 0,
    optimized_storage INTEGER NOT NULL default 0,
    FOREIGN KEY (container_id) REFERENCES containers (id) ON DELETE CASCADE,
    UNIQUE (container_id, name)
);
`
	_, err := tx.Exec(stmts)
	return err
}

// The zfs.pool_name config key is node-specific, and needs to be linked to
// nodes.
func updateFromV6(ctx context.Context, tx *sql.Tx) error {
	// Fetch the IDs of all existing nodes.
	nodeIDs, err := query.SelectIntegers(ctx, tx, "SELECT id FROM nodes")
	if err != nil {
		return fmt.Errorf("failed to get IDs of current nodes: %w", err)
	}

	// Fetch the IDs of all existing zfs pools.
	poolIDs, err := query.SelectIntegers(ctx, tx, `SELECT id FROM storage_pools WHERE driver='zfs'`)
	if err != nil {
		return fmt.Errorf("failed to get IDs of current zfs pools: %w", err)
	}

	for _, poolID := range poolIDs {
		// Fetch the config for this zfs pool and check if it has the zfs.pool_name key
		config, err := query.SelectConfig(ctx, tx, "storage_pools_config", "storage_pool_id=? AND node_id IS NULL", poolID)
		if err != nil {
			return fmt.Errorf("failed to fetch of zfs pool config: %w", err)
		}

		poolName, ok := config["zfs.pool_name"]
		if !ok {
			continue // This zfs storage pool does not have a zfs.pool_name config
		}

		// Delete the current zfs.pool_name key
		_, err = tx.Exec(`
DELETE FROM storage_pools_config WHERE key='zfs.pool_name' AND storage_pool_id=? AND node_id IS NULL
`, poolID)
		if err != nil {
			return fmt.Errorf("failed to delete zfs.pool_name config: %w", err)
		}

		// Add zfs.pool_name config entry for each node
		for _, nodeID := range nodeIDs {
			_, err := tx.Exec(`
INSERT INTO storage_pools_config(storage_pool_id, node_id, key, value)
  VALUES(?, ?, 'zfs.pool_name', ?)
`, poolID, nodeID, poolName)
			if err != nil {
				return fmt.Errorf("failed to create zfs.pool_name node config: %w", err)
			}
		}
	}

	return nil
}

// For ceph volumes, add node-specific rows for all existing nodes, since any
// node is able to access those volumes.
func updateFromV5(ctx context.Context, tx *sql.Tx) error {
	// Fetch the IDs of all existing nodes.
	nodeIDs, err := query.SelectIntegers(ctx, tx, "SELECT id FROM nodes")
	if err != nil {
		return fmt.Errorf("failed to get IDs of current nodes: %w", err)
	}

	// Fetch the IDs of all existing ceph volumes.
	volumeIDs, err := query.SelectIntegers(ctx, tx, `
SELECT storage_volumes.id FROM storage_volumes
    JOIN storage_pools ON storage_volumes.storage_pool_id=storage_pools.id
    WHERE storage_pools.driver='ceph'
`)
	if err != nil {
		return fmt.Errorf("failed to get IDs of current ceph volumes: %w", err)
	}

	// Fetch all existing ceph volumes.
	type volume struct {
		ID            int
		Name          string
		StoragePoolID int
		NodeID        int
		Type          int
		Description   string
	}

	volumes := make([]volume, 0, len(volumeIDs))
	sql := `
SELECT
    storage_volumes.id,
    storage_volumes.name,
    storage_volumes.storage_pool_id,
    storage_volumes.node_id,
    storage_volumes.type,
    storage_volumes.description
FROM storage_volumes
    JOIN storage_pools ON storage_volumes.storage_pool_id=storage_pools.id
    WHERE storage_pools.driver='ceph'
`

	err = query.Scan(ctx, tx, sql, func(scan func(dest ...any) error) error {
		vol := volume{}
		err := scan(&vol.ID, &vol.Name, &vol.StoragePoolID, &vol.NodeID, &vol.Type, &vol.Description)
		if err != nil {
			return err
		}

		volumes = append(volumes, vol)

		return nil
	})
	if err != nil {
		return fmt.Errorf("failed to fetch current volumes: %w", err)
	}

	// Duplicate each volume row across all nodes, and keep track of the
	// new volume IDs that we've inserted.
	created := make(map[int][]int64) // Existing volume ID to new volumes IDs.
	columns := []string{"name", "storage_pool_id", "node_id", "type", "description"}
	for _, volume := range volumes {
		for _, nodeID := range nodeIDs {
			if volume.NodeID == nodeID {
				// This node already has the volume row
				continue
			}

			values := []any{
				volume.Name,
				volume.StoragePoolID,
				nodeID,
				volume.Type,
				volume.Description,
			}

			id, err := query.UpsertObject(tx, "storage_volumes", columns, values)
			if err != nil {
				return fmt.Errorf("failed to insert new volume: %w", err)
			}

			_, ok := created[volume.ID]
			if !ok {
				created[volume.ID] = make([]int64, 0)
			}

			created[volume.ID] = append(created[volume.ID], id)
		}
	}

	// Duplicate each volume config row across all nodes.
	for id, newIDs := range created {
		config, err := query.SelectConfig(ctx, tx, "storage_volumes_config", "storage_volume_id=?", id)
		if err != nil {
			return fmt.Errorf("failed to fetch volume config: %w", err)
		}

		for _, newID := range newIDs {
			for key, value := range config {
				_, err := tx.Exec(`
INSERT INTO storage_volumes_config(storage_volume_id, key, value) VALUES(?, ?, ?)
`, newID, key, value)
				if err != nil {
					return fmt.Errorf("failed to insert new volume config: %w", err)
				}
			}
		}
	}

	return nil
}

func updateFromV4(ctx context.Context, tx *sql.Tx) error {
	stmt := "UPDATE networks SET state = 1"
	_, err := tx.Exec(stmt)
	return err
}

func updateFromV3(ctx context.Context, tx *sql.Tx) error {
	stmt := `
CREATE TABLE storage_pools_nodes (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    UNIQUE (storage_pool_id, node_id),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
ALTER TABLE storage_pools ADD COLUMN state INTEGER NOT NULL DEFAULT 0;
UPDATE storage_pools SET state = 1;
`
	_, err := tx.Exec(stmt)
	return err
}

func updateFromV2(ctx context.Context, tx *sql.Tx) error {
	stmt := `
CREATE TABLE operations (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    uuid TEXT NOT NULL,
    node_id TEXT NOT NULL,
    UNIQUE (uuid),
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
`
	_, err := tx.Exec(stmt)
	return err
}

func updateFromV1(ctx context.Context, tx *sql.Tx) error {
	stmt := `
CREATE TABLE certificates (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    fingerprint TEXT NOT NULL,
    type INTEGER NOT NULL,
    name TEXT NOT NULL,
    certificate TEXT NOT NULL,
    UNIQUE (fingerprint)
);
CREATE TABLE config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (key)
);
CREATE TABLE containers (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    node_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    architecture INTEGER NOT NULL,
    type INTEGER NOT NULL,
    ephemeral INTEGER NOT NULL DEFAULT 0,
    creation_date DATETIME NOT NULL DEFAULT 0,
    stateful INTEGER NOT NULL DEFAULT 0,
    last_use_date DATETIME,
    description TEXT,
    UNIQUE (name),
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
CREATE TABLE containers_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    container_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (container_id) REFERENCES containers (id) ON DELETE CASCADE,
    UNIQUE (container_id, key)
);
CREATE TABLE containers_devices (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    container_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    FOREIGN KEY (container_id) REFERENCES containers (id) ON DELETE CASCADE,
    UNIQUE (container_id, name)
);
CREATE TABLE containers_devices_config (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    container_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (container_device_id) REFERENCES containers_devices (id) ON DELETE CASCADE,
    UNIQUE (container_device_id, key)
);
CREATE TABLE containers_profiles (
    id INTEGER primary key AUTOINCREMENT NOT NULL,
    container_id INTEGER NOT NULL,
    profile_id INTEGER NOT NULL,
    apply_order INTEGER NOT NULL default 0,
    UNIQUE (container_id, profile_id),
    FOREIGN KEY (container_id) REFERENCES containers(id) ON DELETE CASCADE,
    FOREIGN KEY (profile_id) REFERENCES profiles(id) ON DELETE CASCADE
);
CREATE TABLE images (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    fingerprint TEXT NOT NULL,
    filename TEXT NOT NULL,
    size INTEGER NOT NULL,
    public INTEGER NOT NULL DEFAULT 0,
    architecture INTEGER NOT NULL,
    creation_date DATETIME,
    expiry_date DATETIME,
    upload_date DATETIME NOT NULL,
    cached INTEGER NOT NULL DEFAULT 0,
    last_use_date DATETIME,
    auto_update INTEGER NOT NULL DEFAULT 0,
    UNIQUE (fingerprint)
);
CREATE TABLE images_aliases (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    image_id INTEGER NOT NULL,
    description TEXT,
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE,
    UNIQUE (name)
);
CREATE TABLE images_properties (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    image_id INTEGER NOT NULL,
    type INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE
);
CREATE TABLE images_source (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    image_id INTEGER NOT NULL,
    server TEXT NOT NULL,
    protocol INTEGER NOT NULL,
    certificate TEXT NOT NULL,
    alias TEXT NOT NULL,
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE
);
CREATE TABLE images_nodes (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    image_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    UNIQUE (image_id, node_id),
    FOREIGN KEY (image_id) REFERENCES images (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
CREATE TABLE networks (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    state INTEGER NOT NULL DEFAULT 0,
    UNIQUE (name)
);
CREATE TABLE networks_nodes (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    UNIQUE (network_id, node_id),
    FOREIGN KEY (network_id) REFERENCES networks (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
CREATE TABLE networks_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    network_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (network_id, node_id, key),
    FOREIGN KEY (network_id) REFERENCES networks (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
CREATE TABLE profiles (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT,
    UNIQUE (name)
);
CREATE TABLE profiles_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (profile_id, key),
    FOREIGN KEY (profile_id) REFERENCES profiles(id) ON DELETE CASCADE
);
CREATE TABLE profiles_devices (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_id INTEGER NOT NULL,
    name TEXT NOT NULL,
    type INTEGER NOT NULL default 0,
    UNIQUE (profile_id, name),
    FOREIGN KEY (profile_id) REFERENCES profiles (id) ON DELETE CASCADE
);
CREATE TABLE profiles_devices_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    profile_device_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (profile_device_id, key),
    FOREIGN KEY (profile_device_id) REFERENCES profiles_devices (id) ON DELETE CASCADE
);
CREATE TABLE storage_pools (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    driver TEXT NOT NULL,
    description TEXT,
    UNIQUE (name)
);
CREATE TABLE storage_pools_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (storage_pool_id, node_id, key),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
CREATE TABLE storage_volumes (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    storage_pool_id INTEGER NOT NULL,
    node_id INTEGER NOT NULL,
    type INTEGER NOT NULL,
    description TEXT,
    UNIQUE (storage_pool_id, node_id, name, type),
    FOREIGN KEY (storage_pool_id) REFERENCES storage_pools (id) ON DELETE CASCADE,
    FOREIGN KEY (node_id) REFERENCES nodes (id) ON DELETE CASCADE
);
CREATE TABLE storage_volumes_config (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    storage_volume_id INTEGER NOT NULL,
    key TEXT NOT NULL,
    value TEXT,
    UNIQUE (storage_volume_id, key),
    FOREIGN KEY (storage_volume_id) REFERENCES storage_volumes (id) ON DELETE CASCADE
);
`
	_, err := tx.Exec(stmt)
	return err
}

func updateFromV0(ctx context.Context, tx *sql.Tx) error {
	// v0..v1 the dawn of clustering
	stmt := `
CREATE TABLE nodes (
    id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    name TEXT NOT NULL,
    description TEXT DEFAULT '',
    address TEXT NOT NULL,
    schema INTEGER NOT NULL,
    api_extensions INTEGER NOT NULL,
    heartbeat DATETIME DEFAULT CURRENT_TIMESTAMP,
    pending INTEGER NOT NULL DEFAULT 0,
    UNIQUE (name),
    UNIQUE (address)
);
`
	_, err := tx.Exec(stmt)
	return err
}