bug_4002: issues referential integrity
Signed-off-by: Chris Cormack <chrisc@catalyst.net.nz> Signed-off-by: Paul Poulain <paul.poulain@biblibre.com> Signed-off-by: Chris Cormack <chrisc@catalyst.net.nz>
This commit is contained in:
parent
5b945d8c41
commit
d0c9592592
2 changed files with 39 additions and 6 deletions
|
@ -938,8 +938,8 @@ CREATE TABLE `import_items` (
|
|||
|
||||
DROP TABLE IF EXISTS `issues`;
|
||||
CREATE TABLE `issues` (
|
||||
`borrowernumber` int(11) default NULL,
|
||||
`itemnumber` int(11) default NULL,
|
||||
`borrowernumber` int(11),
|
||||
`itemnumber` int(11),
|
||||
`date_due` date default NULL,
|
||||
`branchcode` varchar(10) default NULL,
|
||||
`issuingbranch` varchar(18) default NULL,
|
||||
|
@ -949,11 +949,11 @@ CREATE TABLE `issues` (
|
|||
`renewals` tinyint(4) default NULL,
|
||||
`timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
|
||||
`issuedate` date default NULL,
|
||||
PRIMARY KEY (`itemnumber`),
|
||||
KEY `issuesborridx` (`borrowernumber`),
|
||||
KEY `issuesitemidx` (`itemnumber`),
|
||||
KEY `bordate` (`borrowernumber`,`timestamp`),
|
||||
CONSTRAINT `issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE SET NULL ON UPDATE SET NULL,
|
||||
CONSTRAINT `issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE SET NULL ON UPDATE SET NULL
|
||||
CONSTRAINT `issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE RESTRICT ON UPDATE CASCADE,
|
||||
CONSTRAINT `issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE RESTRICT ON UPDATE CASCADE
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
|
||||
|
||||
--
|
||||
|
@ -2100,7 +2100,7 @@ CREATE TABLE `serialitems` (
|
|||
UNIQUE KEY `serialitemsidx` (`itemnumber`),
|
||||
KEY `serialitems_sfk_1` (`serialid`),
|
||||
CONSTRAINT `serialitems_sfk_1` FOREIGN KEY (`serialid`) REFERENCES `serial` (`serialid`) ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
CONSTRAINT serialitems_sfk_2 FOREIGN KEY (itemnumber) REFERENCES items (itemnumber) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
CONSTRAINT `serialitems_sfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
|
||||
|
||||
DROP TABLE IF EXISTS `user_permissions`;
|
||||
|
|
|
@ -4399,6 +4399,39 @@ if (C4::Context->preference("Version") < TransformToNum($DBversion)) {
|
|||
SetVersion($DBversion);
|
||||
}
|
||||
|
||||
$DBversion = "3.05.00.XXX";
|
||||
if (C4::Context->preference("Version") < TransformToNum($DBversion)) {
|
||||
$dbh->do("INSERT INTO old_issues (borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate)
|
||||
SELECT borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate FROM issues WHERE borrowernumber IS NULL");
|
||||
$dbh->do("DELETE FROM issues WHERE borrowernumber IS NULL");
|
||||
|
||||
$dbh->do("INSERT INTO old_issues (borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate)
|
||||
SELECT borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate FROM issues WHERE itemnumber IS NULL");
|
||||
$dbh->do("DELETE FROM issues WHERE itemnumber IS NULL");
|
||||
|
||||
$dbh->do("INSERT INTO old_issues (borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate)
|
||||
SELECT borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate FROM issues WHERE NOT EXISTS (SELECT * FROM borrowers WHERE borrowernumber = issues.borrowernumber)");
|
||||
$dbh->do("DELETE FROM issues WHERE NOT EXISTS (SELECT * FROM borrowers WHERE borrowernumber = issues.borrowernumber)");
|
||||
|
||||
$dbh->do("INSERT INTO old_issues (borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate)
|
||||
SELECT borrowernumber, itemnumber, date_due, branchcode, issuingbranch, returndate, lastreneweddate, `return`, renewals, timestamp, issuedate FROM issues WHERE NOT EXISTS (SELECT * FROM items WHERE itemnumber = issues.itemnumber)");
|
||||
$dbh->do("DELETE FROM issues WHERE NOT EXISTS (SELECT * FROM items WHERE itemnumber = issues.itemnumber)");
|
||||
|
||||
$dbh->do("ALTER TABLE issues DROP FOREIGN KEY `issues_ibfk_1`");
|
||||
$dbh->do("ALTER TABLE issues DROP FOREIGN KEY `issues_ibfk_2`");
|
||||
$dbh->do("ALTER TABLE issues ALTER COLUMN borrowernumber DROP DEFAULT");
|
||||
$dbh->do("ALTER TABLE issues ALTER COLUMN itemnumber DROP DEFAULT");
|
||||
$dbh->do("ALTER TABLE issues MODIFY COLUMN borrowernumber int(11) NOT NULL");
|
||||
$dbh->do("ALTER TABLE issues MODIFY COLUMN itemnumber int(11) NOT NULL");
|
||||
$dbh->do("ALTER TABLE issues DROP KEY `issuesitemidx`");
|
||||
$dbh->do("ALTER TABLE issues ADD PRIMARY KEY (`itemnumber`)");
|
||||
$dbh->do("ALTER TABLE issues ADD CONSTRAINT `issues_ibfk_1` FOREIGN KEY (`borrowernumber`) REFERENCES `borrowers` (`borrowernumber`) ON DELETE RESTRICT ON UPDATE CASCADE");
|
||||
$dbh->do("ALTER TABLE issues ADD CONSTRAINT `issues_ibfk_2` FOREIGN KEY (`itemnumber`) REFERENCES `items` (`itemnumber`) ON DELETE RESTRICT ON UPDATE CASCADE");
|
||||
|
||||
print "Upgrade to $DBversion done (issues referential integrity)\n";
|
||||
SetVersion ($DBversion);
|
||||
}
|
||||
|
||||
=head1 FUNCTIONS
|
||||
|
||||
=head2 DropAllForeignKeys($table)
|
||||
|
|
Loading…
Reference in a new issue