summaryrefslogtreecommitdiffstats
path: root/src/share/database/scripts/pgsql/upgrade_017_to_018.sh.in
blob: 6b7b9769d0bca002d698f9708ef393426b43655b (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
#!/bin/sh

# Copyright (C) 2023 Internet Systems Consortium, Inc. ("ISC")
#
# This Source Code Form is subject to the terms of the Mozilla Public
# License, v. 2.0. If a copy of the MPL was not distributed with this
# file, You can obtain one at http://mozilla.org/MPL/2.0/.

# shellcheck disable=SC1091
# SC1091: Not following: ... was not specified as input (see shellcheck -x).

# Exit with error if commands exit with non-zero and if undefined variables are
# used.
set -eu

# shellcheck disable=SC2034
# SC2034: ... appears unused. Verify use (or export if used externally).
prefix="@prefix@"

# Include utilities. Use installed version if available and
# use build version if it isn't.
if test -f "@datarootdir@/@PACKAGE_NAME@/scripts/admin-utils.sh"; then
    . "@datarootdir@/@PACKAGE_NAME@/scripts/admin-utils.sh"
else
    . "@abs_top_builddir@/src/bin/admin/admin-utils.sh"
fi

VERSION=$(pgsql_version "$@")

if [ "$VERSION" != "17.0" ]; then
    printf 'This script upgrades 17.0 to 18.0. '
    printf 'Reported version is %s. Skipping upgrade.\n' "${VERSION}"
    exit 0
fi

psql "$@" >/dev/null <<EOF

-- This line starts the schema upgrade to version 18.0.

-- Drop binaddr index and column from lease6.
DROP INDEX lease6_by_binaddr;
ALTER TABLE lease6
    DROP COLUMN binaddr;

-- Change lease6:address to INET.
ALTER TABLE lease6 ALTER COLUMN address TYPE INET USING address::INET;

-- Change ipv6_reservations:address to INET.
ALTER TABLE ipv6_reservations ALTER COLUMN address TYPE INET USING address::INET;

-- Invoke HOST() on address now that address type is inet
CREATE OR REPLACE FUNCTION lease6DumpData()
RETURNS TABLE (
    address VARCHAR,
    duid VARCHAR,
    valid_lifetime BIGINT,
    expire BIGINT,
    subnet_id BIGINT,
    pref_lifetime BIGINT,
    lease_type SMALLINT,
    iaid INT,
    prefix_len SMALLINT,
    fqdn_fwd INT,
    fqdn_rev INT,
    hostname VARCHAR,
    hwaddr VARCHAR,
    state INT8,
    user_context VARCHAR,
    hwtype SMALLINT,
    hwaddr_source SMALLINT,
    pool_id BIGINT
) AS \$\$
    SELECT
        HOST(address),
        colonSeparatedHex(encode(duid, 'hex')),
        valid_lifetime,
        extract(epoch from expire)::bigint,
        subnet_id,
        pref_lifetime,
        lease_type,
        iaid,
        prefix_len,
        fqdn_fwd::int,
        fqdn_rev::int,
        replace(hostname, ',', '&#x2c'),
        colonSeparatedHex(encode(hwaddr, 'hex')),
        state,
        replace(user_context, ',', '&#x2c'),
        hwtype,
        hwaddr_source,
        pool_id
    FROM lease6
    ORDER BY address;
\$\$ LANGUAGE SQL;

-- Invoke HOST() on address now that address type is inet
CREATE OR REPLACE FUNCTION lease6Upload(
    IN address VARCHAR,
    IN duid VARCHAR,
    IN valid_lifetime BIGINT,
    IN expire BIGINT,
    IN subnet_id BIGINT,
    IN pref_lifetime BIGINT,
    IN lease_type INT,
    IN iaid INT,
    IN prefix_len INT,
    IN fqdn_fwd INT,
    IN fqdn_rev INT,
    IN hostname VARCHAR,
    IN hwaddr VARCHAR,
    IN state INT8,
    IN user_context VARCHAR,
    IN hwtype INT,
    IN hwaddr_source INT,
    IN pool_id BIGINT
) RETURNS VOID AS \$\$
BEGIN
    INSERT INTO lease6 (
        address,
        duid,
        valid_lifetime,
        expire,
        subnet_id,
        pref_lifetime,
        lease_type,
        iaid,
        prefix_len,
        fqdn_fwd,
        fqdn_rev,
        hostname,
        hwaddr,
        state,
        user_context,
        hwtype,
        hwaddr_source,
        pool_id
    ) VALUES (
        cast(address as inet),
        decode(replace(duid, ':', ''), 'hex'),
        valid_lifetime,
        to_timestamp(expire),
        subnet_id,
        pref_lifetime,
        lease_type,
        iaid,
        prefix_len,
        fqdn_fwd::int::boolean,
        fqdn_rev::int::boolean,
        replace(hostname, '&#x2c', ','),
        decode(replace(hwaddr, ':', ''), 'hex'),
        state,
        replace(user_context, '&#x2c', ','),
        hwtype,
        hwaddr_source,
        pool_id
    );
END
\$\$ LANGUAGE plpgsql;

-- Update the schema version number.
UPDATE schema_version
    SET version = '18', minor = '0';

-- This line concludes the schema upgrade to version 18.0.

-- Commit the script transaction.
COMMIT;

EOF