From 79ab6bb47c7ad83da379bf110d790cf04aef00ff Mon Sep 17 00:00:00 2001 From: Holger Weiss Date: Tue, 24 Aug 2021 07:07:44 +0200 Subject: [PATCH] PubSub: Use integer type for timestamps (SQL) 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. --- sql/lite.new.sql | 4 ++-- sql/lite.sql | 4 ++-- sql/mssql.sql | 4 ++-- sql/mysql.new.sql | 4 ++-- sql/mysql.sql | 4 ++-- sql/pg.new.sql | 4 ++-- sql/pg.sql | 4 ++-- src/node_flat_sql.erl | 31 +++++++++++++++++++------------ src/pubsub_db_sql.erl | 11 +++-------- 9 files changed, 36 insertions(+), 34 deletions(-) diff --git a/sql/lite.new.sql b/sql/lite.new.sql index 96c880358..9ea674980 100644 --- a/sql/lite.new.sql +++ b/sql/lite.new.sql @@ -262,8 +262,8 @@ CREATE TABLE pubsub_item ( nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE, itemid text NOT NULL, publisher text NOT NULL, - creation varchar(32) NOT NULL, - modification varchar(32) NOT NULL, + creation BIGINT UNSIGNED NOT NULL, + modification BIGINT UNSIGNED NOT NULL, payload text NOT NULL DEFAULT '' ); CREATE INDEX i_pubsub_item_itemid ON pubsub_item (itemid); diff --git a/sql/lite.sql b/sql/lite.sql index 087035d7f..11479d085 100644 --- a/sql/lite.sql +++ b/sql/lite.sql @@ -238,8 +238,8 @@ CREATE TABLE pubsub_item ( nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE, itemid text NOT NULL, publisher text NOT NULL, - creation varchar(32) NOT NULL, - modification varchar(32) NOT NULL, + creation BIGINT UNSIGNED NOT NULL, + modification BIGINT UNSIGNED NOT NULL, payload text NOT NULL DEFAULT '' ); CREATE INDEX i_pubsub_item_itemid ON pubsub_item (itemid); diff --git a/sql/mssql.sql b/sql/mssql.sql index bb7861527..db552e25a 100644 --- a/sql/mssql.sql +++ b/sql/mssql.sql @@ -210,8 +210,8 @@ CREATE TABLE [dbo].[pubsub_item] ( [nodeid] [bigint] NULL, [itemid] [varchar] (255) NOT NULL, [publisher] [varchar] (250) NOT NULL, - [creation] [varchar] (32) NOT NULL, - [modification] [varchar] (32) NOT NULL, + [creation] [bigint] NOT NULL, + [modification] [bigint] NOT NULL, [payload] [text] NOT NULL DEFAULT '' ) TEXTIMAGE_ON [PRIMARY]; diff --git a/sql/mysql.new.sql b/sql/mysql.new.sql index 01aeffbc5..f3bf0a21b 100644 --- a/sql/mysql.new.sql +++ b/sql/mysql.new.sql @@ -277,8 +277,8 @@ CREATE TABLE pubsub_item ( nodeid bigint, itemid text NOT NULL, publisher text NOT NULL, - creation varchar(32) NOT NULL, - modification varchar(32) NOT NULL, + creation BIGINT UNSIGNED NOT NULL, + modification BIGINT UNSIGNED NOT NULL, payload mediumtext NOT NULL ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE INDEX i_pubsub_item_itemid ON pubsub_item(itemid(36)); diff --git a/sql/mysql.sql b/sql/mysql.sql index 7feaf5d0a..a6e2c06b7 100644 --- a/sql/mysql.sql +++ b/sql/mysql.sql @@ -253,8 +253,8 @@ CREATE TABLE pubsub_item ( nodeid bigint, itemid text NOT NULL, publisher text NOT NULL, - creation varchar(32) NOT NULL, - modification varchar(32) NOT NULL, + creation BIGINT UNSIGNED NOT NULL, + modification BIGINT UNSIGNED NOT NULL, payload mediumtext NOT NULL ) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE INDEX i_pubsub_item_itemid ON pubsub_item(itemid(36)); diff --git a/sql/pg.new.sql b/sql/pg.new.sql index b3473a1a0..332f937ea 100644 --- a/sql/pg.new.sql +++ b/sql/pg.new.sql @@ -427,8 +427,8 @@ CREATE TABLE pubsub_item ( nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE, itemid text NOT NULL, publisher text NOT NULL, - creation varchar(32) NOT NULL, - modification varchar(32) NOT NULL, + creation BIGINT NOT NULL, + modification BIGINT NOT NULL, payload text NOT NULL DEFAULT '' ); CREATE INDEX i_pubsub_item_itemid ON pubsub_item USING btree (itemid); diff --git a/sql/pg.sql b/sql/pg.sql index 0e3d4c8b8..bc86adabd 100644 --- a/sql/pg.sql +++ b/sql/pg.sql @@ -256,8 +256,8 @@ CREATE TABLE pubsub_item ( nodeid bigint REFERENCES pubsub_node(nodeid) ON DELETE CASCADE, itemid text NOT NULL, publisher text NOT NULL, - creation varchar(32) NOT NULL, - modification varchar(32) NOT NULL, + creation BIGINT NOT NULL, + modification BIGINT NOT NULL, payload text NOT NULL DEFAULT '' ); CREATE INDEX i_pubsub_item_itemid ON pubsub_item USING btree (itemid); diff --git a/src/node_flat_sql.erl b/src/node_flat_sql.erl index 240dc3760..062d6111d 100644 --- a/src/node_flat_sql.erl +++ b/src/node_flat_sql.erl @@ -820,16 +820,16 @@ set_item(Item) -> P = encode_jid(JID), Payload = Item#pubsub_item.payload, XML = str:join([fxml:element_to_binary(X) || X<-Payload], <<>>), - SM = encode_now(M), - SC = encode_now(C), + SM = misc:now_to_usec(M), + SC = misc:now_to_usec(C), ?SQL_UPSERT_T( "pubsub_item", ["!nodeid=%(Nidx)d", "!itemid=%(ItemId)s", "publisher=%(P)s", - "modification=%(SM)s", + "modification=%(SM)d", "payload=%(XML)s", - "-creation=%(SC)s" + "-creation=%(SC)d" ]), ok. @@ -1063,20 +1063,27 @@ rsm_page(Count, Index, Offset, Items) -> first = #rsm_first{index = Offset, data = First}, last = Last}. +%% Convert <<"2021-08-22T19:25:52.817368Z">> to <<"1629660352817368">>. +-spec encode_stamp(binary()) -> binary(). encode_stamp(Stamp) -> try xmpp_util:decode_timestamp(Stamp) of Now -> encode_now(Now) catch _:{bad_timestamp, _} -> - Stamp % We should return a proper error to the client instead. + <<"0">> % We should return a proper error to the client instead. end. + +%% Convert <<"1629660352817368">> to <<"2021-08-22T19:25:52.817368Z">>. +-spec decode_stamp(binary()) -> binary(). decode_stamp(Stamp) -> xmpp_util:encode_timestamp(decode_now(Stamp)). -encode_now({T1, T2, T3}) -> - <<(misc:i2l(T1, 6))/binary, ":", - (misc:i2l(T2, 6))/binary, ":", - (misc:i2l(T3, 6))/binary>>. -decode_now(NowStr) -> - [MS, S, US] = binary:split(NowStr, <<":">>, [global]), - {binary_to_integer(MS), binary_to_integer(S), binary_to_integer(US)}. +%% Convert {1629, 660352, 817368} to <<"1629660352817368">>. +-spec encode_now(erlang:timestamp()) -> binary(). +encode_now(Now) -> + integer_to_binary(misc:now_to_usec(Now)). + +%% Convert <<"1629660352817368">> to {1629, 660352, 817368}. +-spec decode_now(binary()) -> erlang:timestamp(). +decode_now(Str) -> + misc:usec_to_now(binary_to_integer(Str)). diff --git a/src/pubsub_db_sql.erl b/src/pubsub_db_sql.erl index 6c1e3b162..a05e04725 100644 --- a/src/pubsub_db_sql.erl +++ b/src/pubsub_db_sql.erl @@ -184,15 +184,10 @@ export(_Server) -> payload = Payload}) -> P = jid:encode(JID), XML = str:join([fxml:element_to_binary(X) || X<-Payload], <<>>), - SM = encode_now(M), - SC = encode_now(C), + SM = misc:now_to_usec(M), + SC = misc:now_to_usec(C), [?SQL("insert into pubsub_item(itemid,nodeid,creation,modification,publisher,payload)" - " values (%(ItemId)s, %(Nidx)d, %(SC)s, %(SM)s, %(P)s, %(XML)s);")]; + " values (%(ItemId)s, %(Nidx)d, %(SC)d, %(SM)d, %(P)s, %(XML)s);")]; (_Host, _R) -> [] end}]. - -encode_now({T1, T2, T3}) -> - <<(misc:i2l(T1, 6))/binary, ":", - (misc:i2l(T2, 6))/binary, ":", - (misc:i2l(T3, 6))/binary>>.