mirror of
https://gitlab.isc.org/isc-projects/kea
synced 2025-10-17 14:26:31 +00:00
[#2039] kea-admin lease-upload pgsql
This commit is contained in:
committed by
Wlodzimierz Wencel
parent
c83760ce68
commit
fee2981fd3
@@ -655,22 +655,6 @@ get_column_position() {
|
|||||||
fi
|
fi
|
||||||
}
|
}
|
||||||
|
|
||||||
# Checks that an input file was provided and that it has at least one lease.
|
|
||||||
lease_upload_checks() {
|
|
||||||
# Check that an input file was specified.
|
|
||||||
if test -z "${input_file-}"; then
|
|
||||||
log_error 'you must specify an input file with -i or --input for lease-upload'
|
|
||||||
usage
|
|
||||||
exit 1
|
|
||||||
fi
|
|
||||||
|
|
||||||
# Check that the input file has at least one row of values.
|
|
||||||
if test "$(wc -l < "${input_file}")" -le 1; then
|
|
||||||
log_error 'CSV file has no leases'
|
|
||||||
exit 1
|
|
||||||
fi
|
|
||||||
}
|
|
||||||
|
|
||||||
# Adds quotes around values at given positions starting with 1 in a CSV line.
|
# Adds quotes around values at given positions starting with 1 in a CSV line.
|
||||||
stringify_positions_in_line() {
|
stringify_positions_in_line() {
|
||||||
local positions="${1}"; shift
|
local positions="${1}"; shift
|
||||||
@@ -727,10 +711,20 @@ stringify_positions_in_line() {
|
|||||||
printf '%s' "${output}"
|
printf '%s' "${output}"
|
||||||
}
|
}
|
||||||
|
|
||||||
# Entry point for the lease-upload mysql command.
|
# Entry point for the lease-upload command.
|
||||||
mysql_lease_upload() {
|
lease_upload() {
|
||||||
# Do checks.
|
# Check that an input file was specified.
|
||||||
lease_upload_checks
|
if test -z "${input_file-}"; then
|
||||||
|
log_error 'you must specify an input file with -i or --input for lease-upload'
|
||||||
|
usage
|
||||||
|
exit 1
|
||||||
|
fi
|
||||||
|
|
||||||
|
# Check that the input file has at least one row of values.
|
||||||
|
if test "$(wc -l < "${input_file}")" -le 1; then
|
||||||
|
log_error 'CSV file has no leases'
|
||||||
|
exit 1
|
||||||
|
fi
|
||||||
|
|
||||||
# Determine the columns whose values need to be stringified to avoid syntax
|
# Determine the columns whose values need to be stringified to avoid syntax
|
||||||
# errors in the MySQL client. These are columns which are VARCHARs or need
|
# errors in the MySQL client. These are columns which are VARCHARs or need
|
||||||
@@ -753,29 +747,38 @@ mysql_lease_upload() {
|
|||||||
|
|
||||||
# Construct the SQL insert statements.
|
# Construct the SQL insert statements.
|
||||||
header_parsed=false
|
header_parsed=false
|
||||||
sql_statement='START TRANSACTION;\n'
|
sql_statement='START TRANSACTION;'
|
||||||
while read -r line; do
|
while read -r line; do
|
||||||
if "${header_parsed}"; then
|
if "${header_parsed}"; then
|
||||||
line=$(stringify_positions_in_line "${string_positions}" "${line}")
|
line=$(stringify_positions_in_line "${string_positions}" "${line}")
|
||||||
sql_statement="${sql_statement}CALL lease${dhcp_version}Upload(${line});\\n"
|
if test "${backend}" = 'mysql'; then
|
||||||
|
sql_statement="${sql_statement} CALL lease${dhcp_version}Upload(${line}); "
|
||||||
|
elif test "${backend}" = 'pgsql'; then
|
||||||
|
sql_statement="${sql_statement} SELECT lease${dhcp_version}Upload(${line}); "
|
||||||
|
else
|
||||||
|
log_error "lease-upload not implemented for ${backend}"
|
||||||
|
exit 1
|
||||||
|
fi
|
||||||
else
|
else
|
||||||
header_parsed=true
|
header_parsed=true
|
||||||
fi
|
fi
|
||||||
done < "${input_file}"
|
done < "${input_file}"
|
||||||
sql_statement="${sql_statement}COMMIT;\n"
|
sql_statement="${sql_statement} COMMIT;"
|
||||||
|
|
||||||
# Execute the SQL insert statements.
|
# Execute the SQL insert statements.
|
||||||
output="$(mysql_execute "${sql_statement}")"
|
if test "${backend}" = 'mysql'; then
|
||||||
|
output="$(mysql_execute "${sql_statement}")"
|
||||||
|
elif test "${backend}" = 'pgsql'; then
|
||||||
|
output="$(pgsql_execute "${sql_statement}")"
|
||||||
|
else
|
||||||
|
log_error "lease-upload not implemented for ${backend}"
|
||||||
|
exit 1
|
||||||
|
fi
|
||||||
|
|
||||||
# Print a confirmation message.
|
# Print a confirmation message.
|
||||||
printf 'lease%s successfully updated.\n' "${dhcp_version}"
|
printf 'lease%s successfully updated.\n' "${dhcp_version}"
|
||||||
}
|
}
|
||||||
|
|
||||||
# Entry point for the lease-upload pgsql command.
|
|
||||||
pgsql_lease_upload() {
|
|
||||||
log_error 'not implemented'
|
|
||||||
}
|
|
||||||
|
|
||||||
### Functions used for recounting statistics
|
### Functions used for recounting statistics
|
||||||
mysql_recount() {
|
mysql_recount() {
|
||||||
printf "Recount lease statistics from database\n"
|
printf "Recount lease statistics from database\n"
|
||||||
@@ -1056,10 +1059,10 @@ case ${command} in
|
|||||||
exit 1
|
exit 1
|
||||||
;;
|
;;
|
||||||
mysql)
|
mysql)
|
||||||
mysql_lease_upload
|
lease_upload
|
||||||
;;
|
;;
|
||||||
pgsql)
|
pgsql)
|
||||||
pgsql_lease_upload
|
lease_upload
|
||||||
;;
|
;;
|
||||||
cql)
|
cql)
|
||||||
log_error 'lease-export cql is deprecated'
|
log_error 'lease-export cql is deprecated'
|
||||||
|
@@ -3777,7 +3777,6 @@ LANGUAGE plpgsql;
|
|||||||
CREATE TRIGGER dhcp6_subnet_BDEL
|
CREATE TRIGGER dhcp6_subnet_BDEL
|
||||||
BEFORE DELETE ON dhcp6_subnet
|
BEFORE DELETE ON dhcp6_subnet
|
||||||
FOR EACH ROW EXECUTE PROCEDURE func_dhcp6_subnet_BDEL();
|
FOR EACH ROW EXECUTE PROCEDURE func_dhcp6_subnet_BDEL();
|
||||||
|
|
||||||
-- Trigger function for dhcp6_pd_pool_BDEL called BEFORE DELETE on dhcp6_pd_pool
|
-- Trigger function for dhcp6_pd_pool_BDEL called BEFORE DELETE on dhcp6_pd_pool
|
||||||
CREATE OR REPLACE FUNCTION func_dhcp6_pd_pool_BDEL() RETURNS TRIGGER AS $dhcp6_pd_pool_BDEL$
|
CREATE OR REPLACE FUNCTION func_dhcp6_pd_pool_BDEL() RETURNS TRIGGER AS $dhcp6_pd_pool_BDEL$
|
||||||
BEGIN
|
BEGIN
|
||||||
@@ -3793,7 +3792,8 @@ UPDATE schema_version
|
|||||||
|
|
||||||
-- Schema 7.0 specification ends here.
|
-- Schema 7.0 specification ends here.
|
||||||
|
|
||||||
-- This starts schema update to 8.0.
|
-- This starts schema update to 8.0. It adds a few missing elements for CB and
|
||||||
|
-- functions for kea-admin's lease-dump and lease-upload commands.
|
||||||
|
|
||||||
-- -----------------------------------------------------------------------
|
-- -----------------------------------------------------------------------
|
||||||
-- Extend the table holding DHCPv4 option definitions with a nullable
|
-- Extend the table holding DHCPv4 option definitions with a nullable
|
||||||
@@ -3824,7 +3824,7 @@ ALTER TABLE dhcp6_option_def
|
|||||||
ON UPDATE CASCADE;
|
ON UPDATE CASCADE;
|
||||||
|
|
||||||
-- -----------------------------------------------------------------------
|
-- -----------------------------------------------------------------------
|
||||||
-- Add preferred_lifetime columns to dhcp6_client_class table.
|
-- Add missing preferred_lifetime columns to dhcp6_client_class table.
|
||||||
-- -----------------------------------------------------------------------
|
-- -----------------------------------------------------------------------
|
||||||
ALTER TABLE dhcp6_client_class
|
ALTER TABLE dhcp6_client_class
|
||||||
ADD COLUMN preferred_lifetime BIGINT DEFAULT NULL,
|
ADD COLUMN preferred_lifetime BIGINT DEFAULT NULL,
|
||||||
@@ -4059,10 +4059,13 @@ END
|
|||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
-- Modify the function to output a memfile-ready CSV file.
|
-- Modify the function to output a memfile-ready CSV file.
|
||||||
|
-- Some columns that are SMALLINT in the lease4 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
DROP FUNCTION IF EXISTS lease4DumpData();
|
DROP FUNCTION IF EXISTS lease4DumpData();
|
||||||
CREATE OR REPLACE FUNCTION lease4DumpData()
|
CREATE OR REPLACE FUNCTION lease4DumpData()
|
||||||
RETURNS TABLE (
|
RETURNS TABLE (
|
||||||
address inet,
|
address INET,
|
||||||
hwaddr VARCHAR,
|
hwaddr VARCHAR,
|
||||||
client_id VARCHAR,
|
client_id VARCHAR,
|
||||||
valid_lifetime BIGINT,
|
valid_lifetime BIGINT,
|
||||||
@@ -4098,6 +4101,9 @@ RETURNS TEXT AS $$
|
|||||||
$$ LANGUAGE SQL;
|
$$ LANGUAGE SQL;
|
||||||
|
|
||||||
-- Modify the function to output a memfile-ready CSV file.
|
-- Modify the function to output a memfile-ready CSV file.
|
||||||
|
-- Some columns that are SMALLINT in the lease6 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
DROP FUNCTION IF EXISTS lease6DumpData();
|
DROP FUNCTION IF EXISTS lease6DumpData();
|
||||||
CREATE OR REPLACE FUNCTION lease6DumpData()
|
CREATE OR REPLACE FUNCTION lease6DumpData()
|
||||||
RETURNS TABLE (
|
RETURNS TABLE (
|
||||||
@@ -4141,6 +4147,116 @@ RETURNS TABLE (
|
|||||||
ORDER BY address;
|
ORDER BY address;
|
||||||
$$ LANGUAGE SQL;
|
$$ LANGUAGE SQL;
|
||||||
|
|
||||||
|
-- Create a procedure that inserts a v4 lease from memfile data.
|
||||||
|
-- Some columns that are SMALLINT in the lease4 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
|
CREATE OR REPLACE FUNCTION lease4Upload(
|
||||||
|
IN address VARCHAR,
|
||||||
|
IN hwaddr VARCHAR,
|
||||||
|
IN client_id VARCHAR,
|
||||||
|
IN valid_lifetime BIGINT,
|
||||||
|
IN expire BIGINT,
|
||||||
|
IN subnet_id BIGINT,
|
||||||
|
IN fqdn_fwd INT,
|
||||||
|
IN fqdn_rev INT,
|
||||||
|
IN hostname VARCHAR,
|
||||||
|
IN state INT8,
|
||||||
|
IN user_context VARCHAR
|
||||||
|
) RETURNS VOID AS $$
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO lease4 (
|
||||||
|
address,
|
||||||
|
hwaddr,
|
||||||
|
client_id,
|
||||||
|
valid_lifetime,
|
||||||
|
expire,
|
||||||
|
subnet_id,
|
||||||
|
fqdn_fwd,
|
||||||
|
fqdn_rev,
|
||||||
|
hostname,
|
||||||
|
state,
|
||||||
|
user_context
|
||||||
|
) VALUES (
|
||||||
|
address::inet - '0.0.0.0'::inet,
|
||||||
|
decode(replace(hwaddr, ':', ''), 'hex'),
|
||||||
|
decode(replace(client_id, ':', ''), 'hex'),
|
||||||
|
valid_lifetime,
|
||||||
|
to_timestamp(expire),
|
||||||
|
subnet_id,
|
||||||
|
fqdn_fwd::int::boolean,
|
||||||
|
fqdn_rev::int::boolean,
|
||||||
|
replace(hostname, ',', ','),
|
||||||
|
state,
|
||||||
|
replace(user_context, ',', ',')
|
||||||
|
);
|
||||||
|
END
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Create a procedure that inserts a v6 lease from memfile data.
|
||||||
|
-- Some columns that are SMALLINT in the lease6 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
|
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
|
||||||
|
) 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
|
||||||
|
) VALUES (
|
||||||
|
address,
|
||||||
|
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, ',', ','),
|
||||||
|
decode(replace(hwaddr, ':', ''), 'hex'),
|
||||||
|
state,
|
||||||
|
replace(user_context, ',', ','),
|
||||||
|
hwtype,
|
||||||
|
hwaddr_source
|
||||||
|
);
|
||||||
|
END
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
-- Update the schema version number.
|
-- Update the schema version number.
|
||||||
UPDATE schema_version
|
UPDATE schema_version
|
||||||
SET version = '8', minor = '0';
|
SET version = '8', minor = '0';
|
||||||
|
@@ -172,3 +172,6 @@ DROP FUNCTION IF EXISTS get_session_value(name text);
|
|||||||
DROP FUNCTION IF EXISTS set_session_value(name text, value TEXT);
|
DROP FUNCTION IF EXISTS set_session_value(name text, value TEXT);
|
||||||
DROP FUNCTION IF EXISTS set_session_value(name text, value BIGINT);
|
DROP FUNCTION IF EXISTS set_session_value(name text, value BIGINT);
|
||||||
DROP FUNCTION IF EXISTS set_session_value(name text, value BOOLEAN);
|
DROP FUNCTION IF EXISTS set_session_value(name text, value BOOLEAN);
|
||||||
|
|
||||||
|
DROP FUNCTION IF EXISTS lease4Upload();
|
||||||
|
DROP FUNCTION IF EXISTS lease6Upload();
|
||||||
|
@@ -34,10 +34,10 @@ if [ "$VERSION" != "7.0" ]; then
|
|||||||
fi
|
fi
|
||||||
|
|
||||||
psql "$@" >/dev/null <<EOF
|
psql "$@" >/dev/null <<EOF
|
||||||
-- Start the script transaction.
|
|
||||||
START TRANSACTION;
|
START TRANSACTION;
|
||||||
|
|
||||||
-- This starts schema update to 8.0. It adds a few missing elements for CB
|
-- This starts schema update to 8.0. It adds a few missing elements for CB and
|
||||||
|
-- functions for kea-admin's lease-dump and lease-upload commands.
|
||||||
|
|
||||||
-- -----------------------------------------------------------------------
|
-- -----------------------------------------------------------------------
|
||||||
-- Extend the table holding DHCPv4 option definitions with a nullable
|
-- Extend the table holding DHCPv4 option definitions with a nullable
|
||||||
@@ -78,7 +78,7 @@ ALTER TABLE dhcp6_client_class
|
|||||||
-- -----------------------------------------------------------------------
|
-- -----------------------------------------------------------------------
|
||||||
-- Add option scopes
|
-- Add option scopes
|
||||||
-- -----------------------------------------------------------------------
|
-- -----------------------------------------------------------------------
|
||||||
--Add scope for shared network specific options.
|
-- Add scope for shared network specific options.
|
||||||
INSERT INTO dhcp_option_scope (scope_id, scope_name)
|
INSERT INTO dhcp_option_scope (scope_id, scope_name)
|
||||||
VALUES(4, 'shared-network');
|
VALUES(4, 'shared-network');
|
||||||
|
|
||||||
@@ -306,10 +306,13 @@ END
|
|||||||
\$\$ LANGUAGE plpgsql;
|
\$\$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
-- Modify the function to output a memfile-ready CSV file.
|
-- Modify the function to output a memfile-ready CSV file.
|
||||||
|
-- Some columns that are SMALLINT in the lease4 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
DROP FUNCTION IF EXISTS lease4DumpData();
|
DROP FUNCTION IF EXISTS lease4DumpData();
|
||||||
CREATE OR REPLACE FUNCTION lease4DumpData()
|
CREATE OR REPLACE FUNCTION lease4DumpData()
|
||||||
RETURNS TABLE (
|
RETURNS TABLE (
|
||||||
address inet,
|
address INET,
|
||||||
hwaddr VARCHAR,
|
hwaddr VARCHAR,
|
||||||
client_id VARCHAR,
|
client_id VARCHAR,
|
||||||
valid_lifetime BIGINT,
|
valid_lifetime BIGINT,
|
||||||
@@ -345,6 +348,9 @@ RETURNS TEXT AS \$\$
|
|||||||
\$\$ LANGUAGE SQL;
|
\$\$ LANGUAGE SQL;
|
||||||
|
|
||||||
-- Modify the function to output a memfile-ready CSV file.
|
-- Modify the function to output a memfile-ready CSV file.
|
||||||
|
-- Some columns that are SMALLINT in the lease6 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
DROP FUNCTION IF EXISTS lease6DumpData();
|
DROP FUNCTION IF EXISTS lease6DumpData();
|
||||||
CREATE OR REPLACE FUNCTION lease6DumpData()
|
CREATE OR REPLACE FUNCTION lease6DumpData()
|
||||||
RETURNS TABLE (
|
RETURNS TABLE (
|
||||||
@@ -388,11 +394,121 @@ RETURNS TABLE (
|
|||||||
ORDER BY address;
|
ORDER BY address;
|
||||||
\$\$ LANGUAGE SQL;
|
\$\$ LANGUAGE SQL;
|
||||||
|
|
||||||
|
-- Create a procedure that inserts a v4 lease from memfile data.
|
||||||
|
-- Some columns that are SMALLINT in the lease4 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
|
CREATE OR REPLACE FUNCTION lease4Upload(
|
||||||
|
IN address VARCHAR,
|
||||||
|
IN hwaddr VARCHAR,
|
||||||
|
IN client_id VARCHAR,
|
||||||
|
IN valid_lifetime BIGINT,
|
||||||
|
IN expire BIGINT,
|
||||||
|
IN subnet_id BIGINT,
|
||||||
|
IN fqdn_fwd INT,
|
||||||
|
IN fqdn_rev INT,
|
||||||
|
IN hostname VARCHAR,
|
||||||
|
IN state INT8,
|
||||||
|
IN user_context VARCHAR
|
||||||
|
) RETURNS VOID AS \$\$
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO lease4 (
|
||||||
|
address,
|
||||||
|
hwaddr,
|
||||||
|
client_id,
|
||||||
|
valid_lifetime,
|
||||||
|
expire,
|
||||||
|
subnet_id,
|
||||||
|
fqdn_fwd,
|
||||||
|
fqdn_rev,
|
||||||
|
hostname,
|
||||||
|
state,
|
||||||
|
user_context
|
||||||
|
) VALUES (
|
||||||
|
address::inet - '0.0.0.0'::inet,
|
||||||
|
decode(replace(hwaddr, ':', ''), 'hex'),
|
||||||
|
decode(replace(client_id, ':', ''), 'hex'),
|
||||||
|
valid_lifetime,
|
||||||
|
to_timestamp(expire),
|
||||||
|
subnet_id,
|
||||||
|
fqdn_fwd::int::boolean,
|
||||||
|
fqdn_rev::int::boolean,
|
||||||
|
replace(hostname, ',', ','),
|
||||||
|
state,
|
||||||
|
replace(user_context, ',', ',')
|
||||||
|
);
|
||||||
|
END
|
||||||
|
\$\$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Create a procedure that inserts a v6 lease from memfile data.
|
||||||
|
-- Some columns that are SMALLINT in the lease6 table have their type promoted
|
||||||
|
-- to INT in the declaration of this function for backwards compatibility with
|
||||||
|
-- PostgreSQL versions.
|
||||||
|
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
|
||||||
|
) 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
|
||||||
|
) VALUES (
|
||||||
|
address,
|
||||||
|
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, ',', ','),
|
||||||
|
decode(replace(hwaddr, ':', ''), 'hex'),
|
||||||
|
state,
|
||||||
|
replace(user_context, ',', ','),
|
||||||
|
hwtype,
|
||||||
|
hwaddr_source
|
||||||
|
);
|
||||||
|
END
|
||||||
|
\$\$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
-- Update the schema version number.
|
-- Update the schema version number.
|
||||||
UPDATE schema_version
|
UPDATE schema_version
|
||||||
SET version = '8', minor = '0';
|
SET version = '8', minor = '0';
|
||||||
|
|
||||||
-- Commit the script transaction
|
-- Commit the script transaction.
|
||||||
COMMIT;
|
COMMIT;
|
||||||
|
|
||||||
EOF
|
EOF
|
||||||
|
Reference in New Issue
Block a user