-
Notifications
You must be signed in to change notification settings - Fork 1.5k
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
PubSub: Use integer type for timestamps (SQL) #3667
base: master
Are you sure you want to change the base?
Conversation
Store PubSub item creation/modification timestamps as integers instead of "$megasec:$sec:$microsec" strings. This can improve the performance of certain SQL queries significantly. Thanks to Ammonit Measurement GmbH for sponsoring this work.
@weiss The migration would require a downtime, right ? |
Yes, it would. |
We did a quick and dirty test:
The first The second My conclusion is, that this is a significant performance win for IoT and maybe also interesting to social network applications, but probably not so relevant for instant messaging. In our case, the old timestamp format is just too slow. We get one Side note: If the item contents are very small, e.g. only one or two measurement values from IoT sensors, and there are a lot of messages, size might be of concern, too. A |
Have you planned a merging like other PRs? Thanks to Ammonit Measurement GmbH and @weiss about all PRs! |
When I first saw this I wrote some pure-SQL scripts that could also be used to perform the migration, but forgot to share them. Enjoy! PostgreSQLALTER TABLE pubsub_item ALTER creation TYPE BIGINT USING
(TO_NUMBER(substring(creation from 1 for position(':' in creation)-1), '999999999999') * 1000000 +
TO_NUMBER(substring(creation from position(':' in creation)+1 for position(':' in substring(creation from position(':' in creation)+1))-1), '999999')) * 1000000 +
TO_NUMBER(substring(creation from position(':' in substring(creation from position(':' in creation)+1)) + position(':' in creation)+1), '999999');
ALTER TABLE pubsub_item ALTER modification TYPE BIGINT USING
(TO_NUMBER(substring(modification from 1 for position(':' in modification)-1), '999999999999') * 1000000 +
TO_NUMBER(substring(modification from position(':' in modification)+1 for position(':' in substring(modification from position(':' in modification)+1))-1), '999999')) * 1000000 +
TO_NUMBER(substring(modification from position(':' in substring(modification from position(':' in modification)+1)) + position(':' in modification)+1), '999999'); SQLiteUPDATE pubsub_item SET
creation =
(SUBSTR(creation, 1, INSTR(creation, ':')-1) * 1000000 +
SUBSTR(creation, INSTR(creation, ':')+1, INSTR(SUBSTR(creation, INSTR(creation, ':')+1), ':')-1)) * 1000000 +
SUBSTR(creation, INSTR(SUBSTR(creation, INSTR(creation, ':')+1), ':') + INSTR(creation, ':')+1),
modification =
(SUBSTR(modification, 1, INSTR(modification, ':')-1) * 1000000 +
SUBSTR(modification, INSTR(modification, ':')+1, INSTR(SUBSTR(modification, INSTR(modification, ':')+1), ':')-1)) * 1000000 +
SUBSTR(modification, INSTR(SUBSTR(modification, INSTR(modification, ':')+1), ':') + INSTR(modification, ':')+1); MySQL/MariaDBOption 1 - using temporary table: CREATE TABLE pubsub_item_temp (
nodeid bigint,
itemid text NOT NULL,
publisher text NOT NULL,
creation bigint,
modification bigint,
payload mediumtext NOT NULL
) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci as SELECT
nodeid, itemid, publisher,
(CAST(substring(creation from 1 for position(':' in creation)-1) AS UNSIGNED) * 1000000 + CAST(substring(creation from position(':' in creation)+1 for position(':' in substring(creation from position(':' in creation)+1))-1) AS UNSIGNED)) * 1000000 + CAST(substring(creation from position(':' in substring(creation from position(':' in creation)+1)) + position(':' in creation)+1) AS UNSIGNED) creation,
(CAST(substring(modification from 1 for position(':' in modification)-1) AS UNSIGNED) * 1000000 + CAST(substring(modification from position(':' in modification)+1 for position(':' in substring(modification from position(':' in modification)+1))-1) AS UNSIGNED)) * 1000000 + CAST(substring(modification from position(':' in substring(modification from position(':' in modification)+1)) + position(':' in modification)+1) AS UNSIGNED) modification,
payload
from pubsub_item;
ALTER TABLE pubsub_item DROP FOREIGN KEY (`nodeid`);
DROP TABLE pubsub_item;
DROP INDEX i_pubsub_item_itemid;
DROP INDEX i_pubsub_item_tuple;
RENAME TABLE pubsub_item_temp TO pubsub_item;
CREATE INDEX i_pubsub_item_itemid ON pubsub_item(itemid(36));
CREATE UNIQUE INDEX i_pubsub_item_tuple ON pubsub_item(nodeid, itemid(36));
ALTER TABLE `pubsub_item` ADD FOREIGN KEY (`nodeid`) REFERENCES `pubsub_node` (`nodeid`) ON DELETE CASCADE; Option 2 - using temporary column: ALTER TABLE pubsub_item ADD creation_temp BIGINT;
ALTER TABLE pubsub_item ADD modification_temp BIGINT;
UPDATE pubsub_item set creation_temp =
(CAST(substring(creation from 1 for position(':' in creation)-1) AS UNSIGNED) * 1000000 + CAST(substring(creation from position(':' in creation)+1 for position(':' in substring(creation from position(':' in creation)+1))-1) AS UNSIGNED)) * 1000000 + CAST(substring(creation from position(':' in substring(creation from position(':' in creation)+1)) + position(':' in creation)+1) AS UNSIGNED),
modification_temp = (CAST(substring(modification from 1 for position(':' in modification)-1) AS UNSIGNED) * 1000000 + CAST(substring(modification from position(':' in modification)+1 for position(':' in substring(modification from position(':' in modification)+1))-1) AS UNSIGNED)) * 1000000 + CAST(substring(modification from position(':' in substring(modification from position(':' in modification)+1)) + position(':' in modification)+1) AS UNSIGNED);
ALTER TABLE pubsub_item DROP creation;
ALTER TABLE pubsub_item DROP modification;
ALTER TABLE pubsub_item CHANGE COLUMN creation_temp creation BIGINT;
ALTER TABLE pubsub_item CHANGE COLUMN modification_temp modification BIGINT; |
Store PubSub item creation/modification timestamps as integers instead of
"$megasec:$sec:$microsec"
strings. This can improve the performance of certain SQL queries significantly.This change requires a non-trivial conversion of the
pubsub_item
table, but I think the potential performance improvements are worth the hassle. The upgrade notes could suggest conversion scripts such as the following one, which I tested successfully with PostgreSQL. If everyone agrees with this change, I'll look into MySQL and SQLite as well.Thanks to Ammonit Measurement GmbH for sponsoring this work.