upgrade_3.0_to_4.0.sh.in 4.9 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159
  1. #!/bin/sh
  2. # Include utilities. Use installed version if available and
  3. # use build version if it isn't.
  4. if [ -e @datarootdir@/@PACKAGE_NAME@/scripts/admin-utils.sh ]; then
  5. . @datarootdir@/@PACKAGE_NAME@/scripts/admin-utils.sh
  6. else
  7. . @abs_top_builddir@/src/bin/admin/admin-utils.sh
  8. fi
  9. VERSION=`mysql_version "$@"`
  10. if [ "$VERSION" != "3.0" ]; then
  11. printf "This script upgrades 3.0 to 4.0. Reported version is $VERSION. Skipping upgrade.\n"
  12. exit 0
  13. fi
  14. mysql "$@" <<EOF
  15. # Add state column to the lease4 table.
  16. ALTER TABLE lease4
  17. ADD COLUMN state INT UNSIGNED DEFAULT 0;
  18. # Add state column to the lease6 table.
  19. ALTER TABLE lease6
  20. ADD COLUMN state INT UNSIGNED DEFAULT 0;
  21. # Create indexes for querying leases in a given state and segregated
  22. # by the expiration time. One of the applications is to retrieve all
  23. # expired leases. However, these indexes can be also used to retrieve
  24. # leases in a given state regardless of the expiration time.
  25. CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
  26. CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
  27. # Create table holding mapping of the lease states to their names.
  28. # This is not used in queries from the DHCP server but rather in
  29. # direct queries from the lease database management tools.
  30. CREATE TABLE IF NOT EXISTS lease_state (
  31. state INT UNSIGNED PRIMARY KEY NOT NULL,
  32. name VARCHAR(64) NOT NULL
  33. ) ENGINE=INNODB;
  34. # Insert currently defined state names.
  35. INSERT INTO lease_state VALUES (0, "default");
  36. INSERT INTO lease_state VALUES (1, "declined");
  37. INSERT INTO lease_state VALUES (2, "expired-reclaimed");
  38. # Add a constraint that any state value added to the lease4 must
  39. # map to a value in the lease_state table.
  40. ALTER TABLE lease4
  41. ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
  42. REFERENCES lease_state (state);
  43. # Add a constraint that any state value added to the lease6 must
  44. # map to a value in the lease_state table.
  45. ALTER TABLE lease6
  46. ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
  47. REFERENCES lease_state (state);
  48. # Add a constraint that lease type in the lease6 table must map
  49. # to a lease type defined in the lease6_types table.
  50. ALTER TABLE lease6
  51. ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
  52. REFERENCES lease6_types (lease_type);
  53. # Modify the name of one of the HW address sources, and add a new one.
  54. UPDATE lease_hwaddr_source
  55. SET name = 'HWADDR_SOURCE_DOCSIS_CMTS'
  56. WHERE hwaddr_source = 64;
  57. INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
  58. # Add UNSIGNED to match with the lease6.
  59. ALTER TABLE lease_hwaddr_source
  60. MODIFY COLUMN hwaddr_source INT UNSIGNED NOT NULL DEFAULT 0;
  61. # Add a constraint that non-null hwaddr_source in the lease6 table
  62. # must map to an entry in the lease_hwaddr_source.
  63. ALTER TABLE lease6
  64. ADD CONSTRAINT fk_lease6_hwaddr_source FOREIGN KEY (hwaddr_source)
  65. REFERENCES lease_hwaddr_source (hwaddr_source);
  66. # FUNCTION that returns a result set containing the column names for lease4 dumps
  67. DROP PROCEDURE IF EXISTS lease4DumpHeader;
  68. DELIMITER $$
  69. CREATE PROCEDURE lease4DumpHeader()
  70. BEGIN
  71. SELECT 'address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state';
  72. END $$
  73. DELIMITER ;
  74. # FUNCTION that returns a result set containing the data for lease4 dumps
  75. DROP PROCEDURE IF EXISTS lease4DumpData;
  76. DELIMITER $$
  77. CREATE PROCEDURE lease4DumpData()
  78. BEGIN
  79. SELECT
  80. INET_NTOA(l.address),
  81. IFNULL(HEX(l.hwaddr), ''),
  82. IFNULL(HEX(l.client_id), ''),
  83. l.valid_lifetime,
  84. l.expire,
  85. l.subnet_id,
  86. l.fqdn_fwd,
  87. l.fqdn_rev,
  88. l.hostname,
  89. s.name
  90. from
  91. lease4 l
  92. LEFT OUTER JOIN lease_state s on (l.state = s.state);
  93. END $$
  94. DELIMITER ;
  95. # FUNCTION that returns a result set containing the column names for lease6 dumps
  96. DROP PROCEDURE IF EXISTS lease6DumpHeader;
  97. DELIMITER $$
  98. CREATE PROCEDURE lease6DumpHeader()
  99. BEGIN
  100. SELECT 'address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,hwaddr,hwtype,hwaddr_source,state';
  101. END $$
  102. DELIMITER ;
  103. # FUNCTION that returns a result set containing the data for lease6 dumps
  104. DROP PROCEDURE IF EXISTS lease6DumpData;
  105. DELIMITER $$
  106. CREATE PROCEDURE lease6DumpData()
  107. BEGIN
  108. SELECT
  109. l.address,
  110. IFNULL(HEX(l.duid), ''),
  111. l.valid_lifetime,
  112. l.expire,
  113. l.subnet_id,
  114. l.pref_lifetime,
  115. IFNULL(t.name, ''),
  116. l.iaid,
  117. l.prefix_len,
  118. l.fqdn_fwd,
  119. l.fqdn_rev,
  120. l.hostname,
  121. IFNULL(HEX(l.hwaddr), ''),
  122. IFNULL(l.hwtype, ''),
  123. IFNULL(h.name, ''),
  124. IFNULL(s.name, '')
  125. FROM lease6 l
  126. left outer join lease6_types t on (l.lease_type = t.lease_type)
  127. left outer join lease_state s on (l.state = s.state)
  128. left outer join lease_hwaddr_source h on (l.hwaddr_source = h.hwaddr_source);
  129. END $$
  130. DELIMITER ;
  131. # Update the schema version number
  132. UPDATE schema_version
  133. SET version = '4', minor = '0';
  134. # This line concludes database upgrade to version 4.0.
  135. EOF
  136. RESULT=$?
  137. exit $?