Skip to content

Commit

Permalink
Switch itemIDs to bigints [DB update]
Browse files Browse the repository at this point in the history
  • Loading branch information
dstillman committed Nov 9, 2022
1 parent cd31c47 commit 68590f7
Show file tree
Hide file tree
Showing 2 changed files with 104 additions and 22 deletions.
82 changes: 82 additions & 0 deletions misc/db-updates/2022-11-05/convertItemIDToBigInt
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
#!/usr/bin/php -d mysqlnd.net_read_timeout=86400
<?php
set_include_path("../../../include");
require("header.inc.php");

$shardHostID = $argv[1];
$startShard = $argv[2];
$stopShard = $argv[3];

Z_Core::$debug = true;

$shardIDs = Zotero_DB::columnQuery("SELECT shardID FROM shards WHERE shardHostID=? AND shardID >= ? AND shardID <= ? ORDER BY shardID", [$shardHostID, $startShard, $stopShard]);

foreach ($shardIDs as $shardID) {
echo "Shard: $shardID\n";

echo "Setting shard to read-only\n";
Zotero_DB::query("UPDATE shards SET state='readonly' WHERE shardID=?", $shardID);

echo "Waiting 10 seconds for requests to stop\n";
sleep(10);

// Drop foreign keys
echo "\n";
Zotero_Admin_DB::query("ALTER TABLE `collectionItems` DROP FOREIGN KEY `collectionItems_ibfk_2`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `deletedItems` DROP FOREIGN KEY `deletedItems_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `groupItems` DROP FOREIGN KEY `groupItems_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `publicationsItems` DROP FOREIGN KEY `publicationsItems_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemAnnotations` DROP FOREIGN KEY `itemAnnotations_ibfk_1`, DROP FOREIGN KEY `itemAnnotations_ibfk_2`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemAttachments` DROP FOREIGN KEY `itemAttachments_ibfk_1`, DROP FOREIGN KEY `itemAttachments_ibfk_2`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemCreators` DROP FOREIGN KEY `itemCreators_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemFulltext` DROP FOREIGN KEY `itemFulltext_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemData` DROP FOREIGN KEY `itemData_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemNotes` DROP FOREIGN KEY `itemNotes_ibfk_1`, DROP FOREIGN KEY `itemNotes_ibfk_2`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemRelated` DROP FOREIGN KEY `itemRelated_ibfk_1`, DROP FOREIGN KEY `itemRelated_ibfk_2`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemSortFields` DROP FOREIGN KEY `itemSortFields_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemTags` DROP FOREIGN KEY `itemTags_ibfk_1`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemTopLevel` DROP FOREIGN KEY `itemTopLevel_ibfk_1`, DROP FOREIGN KEY `itemTopLevel_ibfk_2`", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `storageFileItems` DROP FOREIGN KEY `storageFileItems_ibfk_2`", false, $shardID);

// Change itemID columns
echo "Changing columns for $shardID\n";
Zotero_Admin_DB::query("ALTER TABLE `collectionItems` CHANGE `itemID` `itemID` bigint unsigned NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `deletedItems` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `groupItems` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `publicationsItems` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemAttachments` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL, CHANGE `sourceItemID` `sourceItemID` BIGINT UNSIGNED DEFAULT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemAnnotations` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL, CHANGE `parentItemID` `parentItemID` BIGINT UNSIGNED DEFAULT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemCreators` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemData` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemFulltext` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemNotes` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL, CHANGE `sourceItemID` `sourceItemID` BIGINT UNSIGNED DEFAULT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemRelated` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL, CHANGE `linkedItemID` `linkedItemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `items` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemSortFields` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemTags` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemTopLevel` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL, CHANGE `topLevelItemID` `topLevelItemID` BIGINT UNSIGNED NOT NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `storageFileItems` CHANGE `itemID` `itemID` BIGINT UNSIGNED NOT NULL", false, $shardID);

// Add foreign keys back
echo "\n";
Zotero_Admin_DB::query("ALTER TABLE `collectionItems` ADD CONSTRAINT `collectionItems_ibfk_2` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `deletedItems` ADD CONSTRAINT `deletedItems_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `groupItems` ADD CONSTRAINT `groupItems_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `publicationsItems` ADD CONSTRAINT `publicationsItems_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemAnnotations` ADD CONSTRAINT `itemAnnotations_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE, ADD CONSTRAINT `itemAnnotations_ibfk_2` FOREIGN KEY (`parentItemID`) REFERENCES `itemAttachments` (`itemID`)", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemAttachments` ADD CONSTRAINT `itemAttachments_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE, ADD CONSTRAINT `itemAttachments_ibfk_2` FOREIGN KEY (`sourceItemID`) REFERENCES `items` (`itemID`) ON DELETE SET NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemCreators` ADD CONSTRAINT `itemCreators_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemFulltext` ADD CONSTRAINT `itemFulltext_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `itemAttachments` (`itemID`)", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemData` ADD CONSTRAINT `itemData_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemNotes` ADD CONSTRAINT `itemNotes_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE, ADD CONSTRAINT `itemNotes_ibfk_2` FOREIGN KEY (`sourceItemID`) REFERENCES `items` (`itemID`) ON DELETE SET NULL", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemRelated` ADD CONSTRAINT `itemRelated_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE, ADD CONSTRAINT `itemRelated_ibfk_2` FOREIGN KEY (`linkedItemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemSortFields` ADD CONSTRAINT `itemSortFields_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemTags` ADD CONSTRAINT `itemTags_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `itemTopLevel` ADD CONSTRAINT `itemTopLevel_ibfk_1` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE, ADD CONSTRAINT `itemTopLevel_ibfk_2` FOREIGN KEY (`topLevelItemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE", false, $shardID);
Zotero_Admin_DB::query("ALTER TABLE `storageFileItems` ADD CONSTRAINT `storageFileItems_ibfk_2` FOREIGN KEY (`itemID`) REFERENCES `items` (`itemID`) ON DELETE CASCADE ON UPDATE CASCADE", false, $shardID);

echo "Bringing shard back up\n";
Zotero_DB::query("UPDATE shards SET state='up' WHERE shardID=?", $shardID);
echo "Done with shard $shardID\n\n";
sleep(1);
}
44 changes: 22 additions & 22 deletions misc/shard.sql
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@

CREATE TABLE `collectionItems` (
`collectionID` int(10) unsigned NOT NULL,
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`orderIndex` mediumint(8) unsigned DEFAULT NULL,
PRIMARY KEY (`collectionID`,`itemID`),
KEY `itemID` (`itemID`)
Expand Down Expand Up @@ -82,7 +82,7 @@ CREATE TABLE `deletedCollections` (


CREATE TABLE `deletedItems` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`dateDeleted` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (`itemID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
Expand All @@ -96,7 +96,7 @@ CREATE TABLE `deletedSearches` (


CREATE TABLE `groupItems` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`createdByUserID` int(10) unsigned DEFAULT NULL,
`lastModifiedByUserID` int(10) unsigned DEFAULT NULL,
PRIMARY KEY (`itemID`),
Expand All @@ -106,14 +106,14 @@ CREATE TABLE `groupItems` (


CREATE TABLE `publicationsItems` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
PRIMARY KEY (`itemID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;


CREATE TABLE `itemAttachments` (
`itemID` int(10) unsigned NOT NULL,
`sourceItemID` int(10) unsigned DEFAULT NULL,
`itemID` bigint unsigned NOT NULL,
`sourceItemID` bigint unsigned DEFAULT NULL,
`linkMode` enum('IMPORTED_FILE','IMPORTED_URL','LINKED_FILE','LINKED_URL','EMBEDDED_IMAGE'),
`mimeType` varchar(255) NOT NULL,
`charsetID` tinyint(3) unsigned DEFAULT NULL,
Expand All @@ -127,8 +127,8 @@ CREATE TABLE `itemAttachments` (


CREATE TABLE `itemAnnotations` (
`itemID` int(10) unsigned NOT NULL,
`parentItemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`parentItemID` bigint unsigned NOT NULL,
`type` enum('highlight','note','image', 'ink') CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
`authorName` varchar(80) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NOT NULL DEFAULT '',
`text` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NOT NULL,
Expand All @@ -143,7 +143,7 @@ CREATE TABLE `itemAnnotations` (


CREATE TABLE `itemCreators` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`creatorID` bigint unsigned NOT NULL,
`creatorTypeID` smallint(5) unsigned NOT NULL,
`orderIndex` smallint(5) unsigned NOT NULL,
Expand All @@ -155,7 +155,7 @@ CREATE TABLE `itemCreators` (


CREATE TABLE `itemData` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`fieldID` smallint(5) unsigned NOT NULL,
`itemDataValueHash` char(32) CHARACTER SET ascii DEFAULT NULL,
`value` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci,
Expand All @@ -165,18 +165,18 @@ CREATE TABLE `itemData` (


CREATE TABLE `itemFulltext` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`libraryID` int(10) unsigned NOT NULL,
`version` int(10) unsigned NOT NULL DEFAULT '0',
`timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (`itemID`),
KEY `libraryVersion` (`libraryID`,`version`),
KEY `libraryVersion` (`libraryID`,`version`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;


CREATE TABLE `itemNotes` (
`itemID` int(10) unsigned NOT NULL,
`sourceItemID` int(10) unsigned DEFAULT NULL,
`itemID` bigint unsigned NOT NULL,
`sourceItemID` bigint unsigned DEFAULT NULL,
`note` mediumtext CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NOT NULL,
`noteSanitized` mediumtext CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NULL,
`title` varchar(80) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NOT NULL,
Expand All @@ -188,16 +188,16 @@ CREATE TABLE `itemNotes` (


CREATE TABLE `itemRelated` (
`itemID` int(10) unsigned NOT NULL,
`linkedItemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`linkedItemID` bigint unsigned NOT NULL,
PRIMARY KEY (`itemID`,`linkedItemID`),
KEY `linkedItemID` (`linkedItemID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;



CREATE TABLE `itemSortFields` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`sortTitle` varchar(79) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NULL DEFAULT NULL,
`creatorSummary` varchar(50) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_520_ci NULL DEFAULT NULL,
PRIMARY KEY (`itemID`),
Expand All @@ -208,7 +208,7 @@ CREATE TABLE `itemSortFields` (


CREATE TABLE `items` (
`itemID` int(10) unsigned NOT NULL AUTO_INCREMENT,
`itemID` bigint unsigned NOT NULL AUTO_INCREMENT,
`libraryID` int(10) unsigned NOT NULL,
`itemTypeID` smallint(5) unsigned NOT NULL,
`dateAdded` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
Expand All @@ -225,7 +225,7 @@ CREATE TABLE `items` (


CREATE TABLE `itemTags` (
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`tagID` int(10) unsigned NOT NULL,
PRIMARY KEY (`itemID`,`tagID`),
KEY `tagID` (`tagID`)
Expand All @@ -234,8 +234,8 @@ CREATE TABLE `itemTags` (


CREATE TABLE `itemTopLevel` (
`itemID` int(10) unsigned NOT NULL,
`topLevelItemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`topLevelItemID` bigint unsigned NOT NULL,
PRIMARY KEY (`itemID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;

Expand Down Expand Up @@ -306,7 +306,7 @@ CREATE TABLE `shardLibraries` (

CREATE TABLE `storageFileItems` (
`storageFileID` int(10) unsigned NOT NULL,
`itemID` int(10) unsigned NOT NULL,
`itemID` bigint unsigned NOT NULL,
`mtime` bigint(13) unsigned NOT NULL,
`size` int(10) unsigned NOT NULL,
PRIMARY KEY (`storageFileID`,`itemID`),
Expand Down

0 comments on commit 68590f7

Please sign in to comment.