mirror of https://github.com/itflow-org/itflow
Update Asset reference SQL Tables to use Foreign keys and cascading delete, and remove orphaned data from the foreign tables to prevent integrity errors during update
This commit is contained in:
parent
509fb5cfed
commit
06c31e0808
|
|
@ -2479,14 +2479,29 @@ if (LATEST_DATABASE_VERSION > CURRENT_DATABASE_VERSION) {
|
||||||
}
|
}
|
||||||
|
|
||||||
if (CURRENT_DATABASE_VERSION == '1.9.3') {
|
if (CURRENT_DATABASE_VERSION == '1.9.3') {
|
||||||
mysqli_query($mysqli,
|
// Clean up orphaned ticket_id rows in ticket_assets
|
||||||
"CREATE TABLE `ticket_assets` (
|
mysqli_query($mysqli, "
|
||||||
`ticket_id` INT(11) NOT NULL,
|
DELETE FROM `ticket_assets`
|
||||||
`asset_id` INT(11) NOT NULL,
|
WHERE `ticket_id` NOT IN (SELECT `ticket_id` FROM `tickets`);
|
||||||
PRIMARY KEY (`ticket_id`,`asset_id`),
|
");
|
||||||
FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE,
|
|
||||||
FOREIGN KEY (`ticket_id`) REFERENCES `tickets`(`ticket_id`) ON DELETE CASCADE
|
// Clean up orphaned asset_id rows in ticket_assets
|
||||||
)");
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `ticket_assets`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Now create the table with foreign keys
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
CREATE TABLE `ticket_assets` (
|
||||||
|
`ticket_id` INT(11) NOT NULL,
|
||||||
|
`asset_id` INT(11) NOT NULL,
|
||||||
|
PRIMARY KEY (`ticket_id`, `asset_id`),
|
||||||
|
FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE,
|
||||||
|
FOREIGN KEY (`ticket_id`) REFERENCES `tickets`(`ticket_id`) ON DELETE CASCADE
|
||||||
|
)
|
||||||
|
");
|
||||||
|
|
||||||
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '1.9.4'");
|
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '1.9.4'");
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
@ -2518,14 +2533,30 @@ if (LATEST_DATABASE_VERSION > CURRENT_DATABASE_VERSION) {
|
||||||
}
|
}
|
||||||
|
|
||||||
if (CURRENT_DATABASE_VERSION == '1.9.5') {
|
if (CURRENT_DATABASE_VERSION == '1.9.5') {
|
||||||
mysqli_query($mysqli,
|
|
||||||
"CREATE TABLE `recurring_ticket_assets` (
|
// Clean up orphaned recurring_ticket_id rows in recurring_ticket_assets
|
||||||
`recurring_ticket_id` INT(11) NOT NULL,
|
mysqli_query($mysqli, "
|
||||||
`asset_id` INT(11) NOT NULL,
|
DELETE FROM `recurring_ticket_assets`
|
||||||
PRIMARY KEY (`recurring_ticket_id`,`asset_id`),
|
WHERE `recurring_ticket_id` NOT IN (SELECT `recurring_ticket_id` FROM `recurring_tickets`);
|
||||||
FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE,
|
");
|
||||||
FOREIGN KEY (`recurring_ticket_id`) REFERENCES `recurring_tickets`(`recurring_ticket_id`) ON DELETE CASCADE
|
|
||||||
)");
|
// Clean up orphaned asset_id rows in recurring_ticket_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `recurring_ticket_assets`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Now create the table with foreign keys
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
CREATE TABLE `recurring_ticket_assets` (
|
||||||
|
`recurring_ticket_id` INT(11) NOT NULL,
|
||||||
|
`asset_id` INT(11) NOT NULL,
|
||||||
|
PRIMARY KEY (`recurring_ticket_id`, `asset_id`),
|
||||||
|
FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE,
|
||||||
|
FOREIGN KEY (`recurring_ticket_id`) REFERENCES `recurring_tickets`(`recurring_ticket_id`) ON DELETE CASCADE
|
||||||
|
)
|
||||||
|
");
|
||||||
|
|
||||||
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '1.9.6'");
|
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '1.9.6'");
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
@ -2609,55 +2640,156 @@ if (LATEST_DATABASE_VERSION > CURRENT_DATABASE_VERSION) {
|
||||||
CHANGE COLUMN `login_client_id` `credential_client_id` INT(11) NOT NULL DEFAULT '0'
|
CHANGE COLUMN `login_client_id` `credential_client_id` INT(11) NOT NULL DEFAULT '0'
|
||||||
");
|
");
|
||||||
|
|
||||||
|
// Rename table contact_logins to contact_credentials
|
||||||
mysqli_query($mysqli, "RENAME TABLE `contact_logins` TO `contact_credentials`");
|
mysqli_query($mysqli, "RENAME TABLE `contact_logins` TO `contact_credentials`");
|
||||||
|
|
||||||
|
// Alter contact_credentials table and change login_id to credential_id
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `contact_credentials`
|
||||||
|
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned contact_id rows in contact_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `contact_credentials`
|
||||||
|
WHERE `contact_id` NOT IN (SELECT `contact_id` FROM `contacts`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned credential_id rows in contact_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `contact_credentials`
|
||||||
|
WHERE `credential_id` NOT IN (SELECT `credential_id` FROM `credentials`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to contact_credentials
|
||||||
mysqli_query($mysqli, "
|
mysqli_query($mysqli, "
|
||||||
ALTER TABLE `contact_credentials`
|
ALTER TABLE `contact_credentials`
|
||||||
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL,
|
|
||||||
ADD FOREIGN KEY (`contact_id`) REFERENCES `contacts`(`contact_id`) ON DELETE CASCADE,
|
ADD FOREIGN KEY (`contact_id`) REFERENCES `contacts`(`contact_id`) ON DELETE CASCADE,
|
||||||
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
||||||
");
|
");
|
||||||
|
|
||||||
|
// Rename table service_logins to service_credentials
|
||||||
mysqli_query($mysqli, "RENAME TABLE `service_logins` TO `service_credentials`");
|
mysqli_query($mysqli, "RENAME TABLE `service_logins` TO `service_credentials`");
|
||||||
|
|
||||||
|
// Alter service_credentials table and change login_id to credential_id
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `service_credentials`
|
||||||
|
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned service_id rows in service_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `service_credentials`
|
||||||
|
WHERE `service_id` NOT IN (SELECT `service_id` FROM `services`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned credential_id rows in service_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `service_credentials`
|
||||||
|
WHERE `credential_id` NOT IN (SELECT `credential_id` FROM `credentials`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to service_credentials
|
||||||
mysqli_query($mysqli, "
|
mysqli_query($mysqli, "
|
||||||
ALTER TABLE `service_credentials`
|
ALTER TABLE `service_credentials`
|
||||||
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL,
|
|
||||||
ADD FOREIGN KEY (`service_id`) REFERENCES `services`(`service_id`) ON DELETE CASCADE,
|
ADD FOREIGN KEY (`service_id`) REFERENCES `services`(`service_id`) ON DELETE CASCADE,
|
||||||
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
||||||
");
|
");
|
||||||
|
|
||||||
|
// Rename table software_logins to software_credentials
|
||||||
mysqli_query($mysqli, "RENAME TABLE `software_logins` TO `software_credentials`");
|
mysqli_query($mysqli, "RENAME TABLE `software_logins` TO `software_credentials`");
|
||||||
|
|
||||||
|
// Alter software_credentials table and change login_id to credential_id
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `software_credentials`
|
||||||
|
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned software_id rows in software_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `software_credentials`
|
||||||
|
WHERE `software_id` NOT IN (SELECT `software_id` FROM `software`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned credential_id rows in software_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `software_credentials`
|
||||||
|
WHERE `credential_id` NOT IN (SELECT `credential_id` FROM `credentials`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to software_credentials
|
||||||
mysqli_query($mysqli, "
|
mysqli_query($mysqli, "
|
||||||
ALTER TABLE `software_credentials`
|
ALTER TABLE `software_credentials`
|
||||||
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL,
|
|
||||||
ADD FOREIGN KEY (`software_id`) REFERENCES `software`(`software_id`) ON DELETE CASCADE,
|
ADD FOREIGN KEY (`software_id`) REFERENCES `software`(`software_id`) ON DELETE CASCADE,
|
||||||
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
||||||
");
|
");
|
||||||
|
|
||||||
|
// Rename table vendor_logins to vendor_credentials
|
||||||
mysqli_query($mysqli, "RENAME TABLE `vendor_logins` TO `vendor_credentials`");
|
mysqli_query($mysqli, "RENAME TABLE `vendor_logins` TO `vendor_credentials`");
|
||||||
|
|
||||||
|
// Alter vendor_credentials table and change login_id to credential_id
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `vendor_credentials`
|
||||||
|
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned vendor_id rows in vendor_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `vendor_credentials`
|
||||||
|
WHERE `vendor_id` NOT IN (SELECT `vendor_id` FROM `vendors`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned credential_id rows in vendor_credentials
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `vendor_credentials`
|
||||||
|
WHERE `credential_id` NOT IN (SELECT `credential_id` FROM `credentials`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to vendor_credentials
|
||||||
mysqli_query($mysqli, "
|
mysqli_query($mysqli, "
|
||||||
ALTER TABLE `vendor_credentials`
|
ALTER TABLE `vendor_credentials`
|
||||||
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL,
|
|
||||||
ADD FOREIGN KEY (`vendor_id`) REFERENCES `vendors`(`vendor_id`) ON DELETE CASCADE,
|
ADD FOREIGN KEY (`vendor_id`) REFERENCES `vendors`(`vendor_id`) ON DELETE CASCADE,
|
||||||
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
||||||
");
|
");
|
||||||
|
|
||||||
|
// Rename table login_tags to credential_tags
|
||||||
mysqli_query($mysqli, "RENAME TABLE `login_tags` TO `credential_tags`");
|
mysqli_query($mysqli, "RENAME TABLE `login_tags` TO `credential_tags`");
|
||||||
|
|
||||||
|
// Alter credential_tags table and change login_id to credential_id
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `credential_tags`
|
||||||
|
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned tag_id rows in credential_tags
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `credential_tags`
|
||||||
|
WHERE `tag_id` NOT IN (SELECT `tag_id` FROM `tags`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned credential_id rows in credential_tags
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `credential_tags`
|
||||||
|
WHERE `credential_id` NOT IN (SELECT `credential_id` FROM `credentials`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to credential_tags
|
||||||
mysqli_query($mysqli, "
|
mysqli_query($mysqli, "
|
||||||
ALTER TABLE `credential_tags`
|
ALTER TABLE `credential_tags`
|
||||||
CHANGE COLUMN `login_id` `credential_id` INT(11) NOT NULL,
|
|
||||||
ADD FOREIGN KEY (`tag_id`) REFERENCES `tags`(`tag_id`) ON DELETE CASCADE,
|
ADD FOREIGN KEY (`tag_id`) REFERENCES `tags`(`tag_id`) ON DELETE CASCADE,
|
||||||
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
ADD FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE
|
||||||
");
|
");
|
||||||
|
|
||||||
mysqli_query($mysqli,
|
// Create asset_credentials table with foreign keys
|
||||||
"CREATE TABLE `asset_credentials` (
|
mysqli_query($mysqli, "
|
||||||
|
CREATE TABLE `asset_credentials` (
|
||||||
`credential_id` INT(11) NOT NULL,
|
`credential_id` INT(11) NOT NULL,
|
||||||
`asset_id` INT(11) NOT NULL,
|
`asset_id` INT(11) NOT NULL,
|
||||||
PRIMARY KEY (`credential_id`,`asset_id`),
|
PRIMARY KEY (`credential_id`, `asset_id`),
|
||||||
FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE,
|
FOREIGN KEY (`credential_id`) REFERENCES `credentials`(`credential_id`) ON DELETE CASCADE,
|
||||||
FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
)"
|
)
|
||||||
);
|
");
|
||||||
|
|
||||||
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.0'");
|
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.0'");
|
||||||
}
|
}
|
||||||
|
|
@ -2674,10 +2806,172 @@ if (LATEST_DATABASE_VERSION > CURRENT_DATABASE_VERSION) {
|
||||||
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.1'");
|
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.1'");
|
||||||
}
|
}
|
||||||
|
|
||||||
// if (CURRENT_DATABASE_VERSION == '2.0.1') {
|
if (CURRENT_DATABASE_VERSION == '2.0.1') {
|
||||||
// // Insert queries here required to update to DB version 2.0.2
|
|
||||||
|
// Clean up orphaned data before adding foreign keys
|
||||||
|
|
||||||
|
// Clean up orphaned asset_custom_asset_id rows in asset_custom
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_custom`
|
||||||
|
WHERE `asset_custom_asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign key to asset_custom
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `asset_custom`
|
||||||
|
ADD FOREIGN KEY (`asset_custom_asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_id rows in asset_documents
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_documents`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned document_id rows in asset_documents
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_documents`
|
||||||
|
WHERE `document_id` NOT IN (SELECT `document_id` FROM `documents`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to asset_documents
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `asset_documents`
|
||||||
|
ADD FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE,
|
||||||
|
ADD FOREIGN KEY (`document_id`) REFERENCES `documents`(`document_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_id rows in asset_files
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_files`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned file_id rows in asset_files
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_files`
|
||||||
|
WHERE `file_id` NOT IN (SELECT `file_id` FROM `files`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to asset_files
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `asset_files`
|
||||||
|
ADD FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE,
|
||||||
|
ADD FOREIGN KEY (`file_id`) REFERENCES `files`(`file_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_history_asset_id rows in asset_history
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_history`
|
||||||
|
WHERE `asset_history_asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign key to asset_history
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `asset_history`
|
||||||
|
ADD FOREIGN KEY (`asset_history_asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned interface_asset_id rows in asset_interfaces
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_interfaces`
|
||||||
|
WHERE `interface_asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign key to asset_interfaces
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `asset_interfaces`
|
||||||
|
ADD FOREIGN KEY (`interface_asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_note_asset_id rows in asset_notes
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `asset_notes`
|
||||||
|
WHERE `asset_note_asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign key to asset_notes
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `asset_notes`
|
||||||
|
ADD FOREIGN KEY (`asset_note_asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned contact_id rows in contact_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `contact_assets`
|
||||||
|
WHERE `contact_id` NOT IN (SELECT `contact_id` FROM `contacts`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_id rows in contact_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `contact_assets`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to contact_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `contact_assets`
|
||||||
|
ADD FOREIGN KEY (`contact_id`) REFERENCES `contacts`(`contact_id`) ON DELETE CASCADE,
|
||||||
|
ADD FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned unit_asset_id rows in rack_units
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `rack_units`
|
||||||
|
WHERE `unit_asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign key to rack_units
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `rack_units`
|
||||||
|
ADD FOREIGN KEY (`unit_asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned service_id rows in service_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `service_assets`
|
||||||
|
WHERE `service_id` NOT IN (SELECT `service_id` FROM `services`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_id rows in service_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `service_assets`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to service_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `service_assets`
|
||||||
|
ADD FOREIGN KEY (`service_id`) REFERENCES `services`(`service_id`) ON DELETE CASCADE,
|
||||||
|
ADD FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned software_id rows in software_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `software_assets`
|
||||||
|
WHERE `software_id` NOT IN (SELECT `software_id` FROM `software`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Clean up orphaned asset_id rows in software_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
DELETE FROM `software_assets`
|
||||||
|
WHERE `asset_id` NOT IN (SELECT `asset_id` FROM `assets`);
|
||||||
|
");
|
||||||
|
|
||||||
|
// Add foreign keys to software_assets
|
||||||
|
mysqli_query($mysqli, "
|
||||||
|
ALTER TABLE `software_assets`
|
||||||
|
ADD FOREIGN KEY (`software_id`) REFERENCES `software`(`software_id`) ON DELETE CASCADE,
|
||||||
|
ADD FOREIGN KEY (`asset_id`) REFERENCES `assets`(`asset_id`) ON DELETE CASCADE
|
||||||
|
");
|
||||||
|
|
||||||
|
mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.2'");
|
||||||
|
}
|
||||||
|
|
||||||
|
// if (CURRENT_DATABASE_VERSION == '2.0.2') {
|
||||||
|
// // Insert queries here required to update to DB version 2.0.3
|
||||||
// // Then, update the database to the next sequential version
|
// // Then, update the database to the next sequential version
|
||||||
// mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.2'");
|
// mysqli_query($mysqli, "UPDATE `settings` SET `config_current_database_version` = '2.0.3'");
|
||||||
// }
|
// }
|
||||||
|
|
||||||
} else {
|
} else {
|
||||||
|
|
|
||||||
48
db.sql
48
db.sql
|
|
@ -102,7 +102,9 @@ CREATE TABLE `asset_custom` (
|
||||||
`asset_custom_field_value` int(11) NOT NULL,
|
`asset_custom_field_value` int(11) NOT NULL,
|
||||||
`asset_custom_field_id` int(11) NOT NULL,
|
`asset_custom_field_id` int(11) NOT NULL,
|
||||||
`asset_custom_asset_id` int(11) NOT NULL,
|
`asset_custom_asset_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`asset_custom_id`)
|
PRIMARY KEY (`asset_custom_id`),
|
||||||
|
KEY `asset_custom_asset_id` (`asset_custom_asset_id`),
|
||||||
|
CONSTRAINT `asset_custom_ibfk_1` FOREIGN KEY (`asset_custom_asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -116,7 +118,10 @@ DROP TABLE IF EXISTS `asset_documents`;
|
||||||
CREATE TABLE `asset_documents` (
|
CREATE TABLE `asset_documents` (
|
||||||
`asset_id` int(11) NOT NULL,
|
`asset_id` int(11) NOT NULL,
|
||||||
`document_id` int(11) NOT NULL,
|
`document_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`asset_id`,`document_id`)
|
PRIMARY KEY (`asset_id`,`document_id`),
|
||||||
|
KEY `document_id` (`document_id`),
|
||||||
|
CONSTRAINT `asset_documents_ibfk_1` FOREIGN KEY (`asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE,
|
||||||
|
CONSTRAINT `asset_documents_ibfk_2` FOREIGN KEY (`document_id`) REFERENCES `documents` (`document_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -130,7 +135,10 @@ DROP TABLE IF EXISTS `asset_files`;
|
||||||
CREATE TABLE `asset_files` (
|
CREATE TABLE `asset_files` (
|
||||||
`asset_id` int(11) NOT NULL,
|
`asset_id` int(11) NOT NULL,
|
||||||
`file_id` int(11) NOT NULL,
|
`file_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`asset_id`,`file_id`)
|
PRIMARY KEY (`asset_id`,`file_id`),
|
||||||
|
KEY `file_id` (`file_id`),
|
||||||
|
CONSTRAINT `asset_files_ibfk_1` FOREIGN KEY (`asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE,
|
||||||
|
CONSTRAINT `asset_files_ibfk_2` FOREIGN KEY (`file_id`) REFERENCES `files` (`file_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -147,7 +155,9 @@ CREATE TABLE `asset_history` (
|
||||||
`asset_history_description` varchar(255) NOT NULL,
|
`asset_history_description` varchar(255) NOT NULL,
|
||||||
`asset_history_created_at` datetime NOT NULL DEFAULT current_timestamp(),
|
`asset_history_created_at` datetime NOT NULL DEFAULT current_timestamp(),
|
||||||
`asset_history_asset_id` int(11) NOT NULL,
|
`asset_history_asset_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`asset_history_id`)
|
PRIMARY KEY (`asset_history_id`),
|
||||||
|
KEY `asset_history_asset_id` (`asset_history_asset_id`),
|
||||||
|
CONSTRAINT `asset_history_ibfk_1` FOREIGN KEY (`asset_history_asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -197,7 +207,9 @@ CREATE TABLE `asset_interfaces` (
|
||||||
`interface_archived_at` datetime DEFAULT NULL,
|
`interface_archived_at` datetime DEFAULT NULL,
|
||||||
`interface_network_id` int(11) DEFAULT NULL,
|
`interface_network_id` int(11) DEFAULT NULL,
|
||||||
`interface_asset_id` int(11) NOT NULL,
|
`interface_asset_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`interface_id`)
|
PRIMARY KEY (`interface_id`),
|
||||||
|
KEY `interface_asset_id` (`interface_asset_id`),
|
||||||
|
CONSTRAINT `asset_interfaces_ibfk_1` FOREIGN KEY (`interface_asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -217,7 +229,9 @@ CREATE TABLE `asset_notes` (
|
||||||
`asset_note_updated_at` datetime DEFAULT NULL ON UPDATE current_timestamp(),
|
`asset_note_updated_at` datetime DEFAULT NULL ON UPDATE current_timestamp(),
|
||||||
`asset_note_archived_at` datetime DEFAULT NULL,
|
`asset_note_archived_at` datetime DEFAULT NULL,
|
||||||
`asset_note_asset_id` int(11) NOT NULL,
|
`asset_note_asset_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`asset_note_id`)
|
PRIMARY KEY (`asset_note_id`),
|
||||||
|
KEY `asset_note_asset_id` (`asset_note_asset_id`),
|
||||||
|
CONSTRAINT `asset_notes_ibfk_1` FOREIGN KEY (`asset_note_asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -542,7 +556,10 @@ DROP TABLE IF EXISTS `contact_assets`;
|
||||||
CREATE TABLE `contact_assets` (
|
CREATE TABLE `contact_assets` (
|
||||||
`contact_id` int(11) NOT NULL,
|
`contact_id` int(11) NOT NULL,
|
||||||
`asset_id` int(11) NOT NULL,
|
`asset_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`contact_id`,`asset_id`)
|
PRIMARY KEY (`contact_id`,`asset_id`),
|
||||||
|
KEY `asset_id` (`asset_id`),
|
||||||
|
CONSTRAINT `contact_assets_ibfk_1` FOREIGN KEY (`contact_id`) REFERENCES `contacts` (`contact_id`) ON DELETE CASCADE,
|
||||||
|
CONSTRAINT `contact_assets_ibfk_2` FOREIGN KEY (`asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -1334,7 +1351,9 @@ CREATE TABLE `rack_units` (
|
||||||
`unit_rack_id` int(11) NOT NULL,
|
`unit_rack_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`unit_id`),
|
PRIMARY KEY (`unit_id`),
|
||||||
KEY `unit_rack_id` (`unit_rack_id`),
|
KEY `unit_rack_id` (`unit_rack_id`),
|
||||||
CONSTRAINT `rack_units_ibfk_1` FOREIGN KEY (`unit_rack_id`) REFERENCES `racks` (`rack_id`) ON DELETE CASCADE
|
KEY `unit_asset_id` (`unit_asset_id`),
|
||||||
|
CONSTRAINT `rack_units_ibfk_1` FOREIGN KEY (`unit_rack_id`) REFERENCES `racks` (`rack_id`) ON DELETE CASCADE,
|
||||||
|
CONSTRAINT `rack_units_ibfk_2` FOREIGN KEY (`unit_asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -1563,7 +1582,11 @@ DROP TABLE IF EXISTS `service_assets`;
|
||||||
/*!40101 SET character_set_client = utf8 */;
|
/*!40101 SET character_set_client = utf8 */;
|
||||||
CREATE TABLE `service_assets` (
|
CREATE TABLE `service_assets` (
|
||||||
`service_id` int(11) NOT NULL,
|
`service_id` int(11) NOT NULL,
|
||||||
`asset_id` int(11) NOT NULL
|
`asset_id` int(11) NOT NULL,
|
||||||
|
KEY `service_id` (`service_id`),
|
||||||
|
KEY `asset_id` (`asset_id`),
|
||||||
|
CONSTRAINT `service_assets_ibfk_1` FOREIGN KEY (`service_id`) REFERENCES `services` (`service_id`) ON DELETE CASCADE,
|
||||||
|
CONSTRAINT `service_assets_ibfk_2` FOREIGN KEY (`asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -1844,7 +1867,10 @@ DROP TABLE IF EXISTS `software_assets`;
|
||||||
CREATE TABLE `software_assets` (
|
CREATE TABLE `software_assets` (
|
||||||
`software_id` int(11) NOT NULL,
|
`software_id` int(11) NOT NULL,
|
||||||
`asset_id` int(11) NOT NULL,
|
`asset_id` int(11) NOT NULL,
|
||||||
PRIMARY KEY (`software_id`,`asset_id`)
|
PRIMARY KEY (`software_id`,`asset_id`),
|
||||||
|
KEY `asset_id` (`asset_id`),
|
||||||
|
CONSTRAINT `software_assets_ibfk_1` FOREIGN KEY (`software_id`) REFERENCES `software` (`software_id`) ON DELETE CASCADE,
|
||||||
|
CONSTRAINT `software_assets_ibfk_2` FOREIGN KEY (`asset_id`) REFERENCES `assets` (`asset_id`) ON DELETE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
|
||||||
/*!40101 SET character_set_client = @saved_cs_client */;
|
/*!40101 SET character_set_client = @saved_cs_client */;
|
||||||
|
|
||||||
|
|
@ -2402,4 +2428,4 @@ CREATE TABLE `vendors` (
|
||||||
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
|
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
|
||||||
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;
|
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;
|
||||||
|
|
||||||
-- Dump completed on 2025-03-13 16:33:22
|
-- Dump completed on 2025-03-13 21:33:12
|
||||||
|
|
|
||||||
|
|
@ -5,4 +5,4 @@
|
||||||
* It is used in conjunction with database_updates.php
|
* It is used in conjunction with database_updates.php
|
||||||
*/
|
*/
|
||||||
|
|
||||||
DEFINE("LATEST_DATABASE_VERSION", "2.0.1");
|
DEFINE("LATEST_DATABASE_VERSION", "2.0.2");
|
||||||
|
|
|
||||||
|
|
@ -186,21 +186,6 @@ if (isset($_GET['delete_asset'])) {
|
||||||
$client_id = intval($row['asset_client_id']);
|
$client_id = intval($row['asset_client_id']);
|
||||||
|
|
||||||
mysqli_query($mysqli,"DELETE FROM assets WHERE asset_id = $asset_id");
|
mysqli_query($mysqli,"DELETE FROM assets WHERE asset_id = $asset_id");
|
||||||
// Delete Interfaces
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_interfaces WHERE interface_asset_id = $asset_id");
|
|
||||||
// Delete History
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_history WHERE asset_history_asset_id = $asset_id");
|
|
||||||
// Delete Notes
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_notes WHERE asset_note_asset_id = $asset_id");
|
|
||||||
// Rack Units
|
|
||||||
mysqli_query($mysqli,"DELETE FROM rack_units WHERE unit_asset_id = $asset_id");
|
|
||||||
|
|
||||||
// Delete Links
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_documents WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_files WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM contact_assets WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM service_assets WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM software_assets WHERE asset_id = $asset_id");
|
|
||||||
|
|
||||||
// Logging
|
// Logging
|
||||||
logAction("Asset", "Delete", "$session_name deleted asset $asset_name", $client_id);
|
logAction("Asset", "Delete", "$session_name deleted asset $asset_name", $client_id);
|
||||||
|
|
@ -526,21 +511,6 @@ if (isset($_POST['bulk_delete_assets'])) {
|
||||||
$client_id = intval($row['asset_client_id']);
|
$client_id = intval($row['asset_client_id']);
|
||||||
|
|
||||||
mysqli_query($mysqli,"DELETE FROM assets WHERE asset_id = $asset_id");
|
mysqli_query($mysqli,"DELETE FROM assets WHERE asset_id = $asset_id");
|
||||||
// Delete Interfaces
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_interfaces WHERE interface_asset_id = $asset_id");
|
|
||||||
// Delete History
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_history WHERE asset_history_asset_id = $asset_id");
|
|
||||||
// Delete Notes
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_notes WHERE asset_note_asset_id = $asset_id");
|
|
||||||
// Rack Units
|
|
||||||
mysqli_query($mysqli,"DELETE FROM rack_units WHERE unit_asset_id = $asset_id");
|
|
||||||
|
|
||||||
// Delete Links
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_documents WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM asset_files WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM contact_assets WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM service_assets WHERE asset_id = $asset_id");
|
|
||||||
mysqli_query($mysqli,"DELETE FROM software_assets WHERE asset_id = $asset_id");
|
|
||||||
|
|
||||||
// Individual Asset logging
|
// Individual Asset logging
|
||||||
logAction("Asset", "Delete", "$session_name deleted asset $asset_name", $client_id, $asset_id);
|
logAction("Asset", "Delete", "$session_name deleted asset $asset_name", $client_id, $asset_id);
|
||||||
|
|
|
||||||
Loading…
Reference in New Issue