mirror of
https://github.com/NodeBB/NodeBB.git
synced 2025-11-01 11:35:55 +01:00
fix abysmal postgresql performance in getSortedSetsMembers (#8030)
* refactor postgres upgrade function to use async * add function wrapper for getting the elements of a sorted set to avoid postgres planning the query with a nested sequential scan * fix fatal(?!) lint errors * add missing await * bump PostgreSQL version on Travis CI to one that isn't over 3 years out of date
This commit is contained in:
committed by
Barış Soner Uşaklı
parent
b47f1769e4
commit
f65922297d
@@ -28,7 +28,7 @@ addons:
|
|||||||
packages:
|
packages:
|
||||||
- g++-4.8
|
- g++-4.8
|
||||||
- mongodb-org-server
|
- mongodb-org-server
|
||||||
postgresql: "9.5"
|
postgresql: "12"
|
||||||
node_js:
|
node_js:
|
||||||
- "12"
|
- "12"
|
||||||
- "10"
|
- "10"
|
||||||
|
|||||||
@@ -63,7 +63,10 @@ postgresModule.init = function (callback) {
|
|||||||
postgresModule.pool = db;
|
postgresModule.pool = db;
|
||||||
postgresModule.client = db;
|
postgresModule.client = db;
|
||||||
|
|
||||||
checkUpgrade(client, function (err) {
|
checkUpgrade(client).then(function () {
|
||||||
|
release();
|
||||||
|
callback(null);
|
||||||
|
}, function (err) {
|
||||||
release();
|
release();
|
||||||
callback(err);
|
callback(err);
|
||||||
});
|
});
|
||||||
@@ -71,8 +74,8 @@ postgresModule.init = function (callback) {
|
|||||||
};
|
};
|
||||||
|
|
||||||
|
|
||||||
function checkUpgrade(client, callback) {
|
async function checkUpgrade(client) {
|
||||||
client.query(`
|
var res = await client.query(`
|
||||||
SELECT EXISTS(SELECT *
|
SELECT EXISTS(SELECT *
|
||||||
FROM "information_schema"."columns"
|
FROM "information_schema"."columns"
|
||||||
WHERE "table_schema" = 'public'
|
WHERE "table_schema" = 'public'
|
||||||
@@ -82,32 +85,32 @@ SELECT EXISTS(SELECT *
|
|||||||
FROM "information_schema"."columns"
|
FROM "information_schema"."columns"
|
||||||
WHERE "table_schema" = 'public'
|
WHERE "table_schema" = 'public'
|
||||||
AND "table_name" = 'legacy_hash'
|
AND "table_name" = 'legacy_hash'
|
||||||
AND "column_name" = '_key') b`, function (err, res) {
|
AND "column_name" = '_key') b,
|
||||||
if (err) {
|
EXISTS(SELECT *
|
||||||
return callback(err);
|
FROM "information_schema"."routines"
|
||||||
}
|
WHERE "routine_schema" = 'public'
|
||||||
|
AND "routine_name" = 'nodebb_get_sorted_set_members') c`);
|
||||||
|
|
||||||
if (res.rows[0].b) {
|
if (res.rows[0].a && res.rows[0].b && res.rows[0].c) {
|
||||||
return callback(null);
|
return;
|
||||||
}
|
}
|
||||||
|
|
||||||
var query = client.query.bind(client);
|
await client.query(`BEGIN`);
|
||||||
|
try {
|
||||||
async.series([
|
if (!res.rows[0].b) {
|
||||||
async.apply(query, `BEGIN`),
|
await client.query(`
|
||||||
async.apply(query, `
|
|
||||||
CREATE TYPE LEGACY_OBJECT_TYPE AS ENUM (
|
CREATE TYPE LEGACY_OBJECT_TYPE AS ENUM (
|
||||||
'hash', 'zset', 'set', 'list', 'string'
|
'hash', 'zset', 'set', 'list', 'string'
|
||||||
)`),
|
)`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
CREATE TABLE "legacy_object" (
|
CREATE TABLE "legacy_object" (
|
||||||
"_key" TEXT NOT NULL
|
"_key" TEXT NOT NULL
|
||||||
PRIMARY KEY,
|
PRIMARY KEY,
|
||||||
"type" LEGACY_OBJECT_TYPE NOT NULL,
|
"type" LEGACY_OBJECT_TYPE NOT NULL,
|
||||||
"expireAt" TIMESTAMPTZ DEFAULT NULL,
|
"expireAt" TIMESTAMPTZ DEFAULT NULL,
|
||||||
UNIQUE ( "_key", "type" )
|
UNIQUE ( "_key", "type" )
|
||||||
)`),
|
)`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
CREATE TABLE "legacy_hash" (
|
CREATE TABLE "legacy_hash" (
|
||||||
"_key" TEXT NOT NULL
|
"_key" TEXT NOT NULL
|
||||||
PRIMARY KEY,
|
PRIMARY KEY,
|
||||||
@@ -120,8 +123,8 @@ CREATE TABLE "legacy_hash" (
|
|||||||
REFERENCES "legacy_object"("_key", "type")
|
REFERENCES "legacy_object"("_key", "type")
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE
|
ON DELETE CASCADE
|
||||||
)`),
|
)`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
CREATE TABLE "legacy_zset" (
|
CREATE TABLE "legacy_zset" (
|
||||||
"_key" TEXT NOT NULL,
|
"_key" TEXT NOT NULL,
|
||||||
"value" TEXT NOT NULL,
|
"value" TEXT NOT NULL,
|
||||||
@@ -135,8 +138,8 @@ CREATE TABLE "legacy_zset" (
|
|||||||
REFERENCES "legacy_object"("_key", "type")
|
REFERENCES "legacy_object"("_key", "type")
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE
|
ON DELETE CASCADE
|
||||||
)`),
|
)`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
CREATE TABLE "legacy_set" (
|
CREATE TABLE "legacy_set" (
|
||||||
"_key" TEXT NOT NULL,
|
"_key" TEXT NOT NULL,
|
||||||
"member" TEXT NOT NULL,
|
"member" TEXT NOT NULL,
|
||||||
@@ -149,8 +152,8 @@ CREATE TABLE "legacy_set" (
|
|||||||
REFERENCES "legacy_object"("_key", "type")
|
REFERENCES "legacy_object"("_key", "type")
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE
|
ON DELETE CASCADE
|
||||||
)`),
|
)`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
CREATE TABLE "legacy_list" (
|
CREATE TABLE "legacy_list" (
|
||||||
"_key" TEXT NOT NULL
|
"_key" TEXT NOT NULL
|
||||||
PRIMARY KEY,
|
PRIMARY KEY,
|
||||||
@@ -163,8 +166,8 @@ CREATE TABLE "legacy_list" (
|
|||||||
REFERENCES "legacy_object"("_key", "type")
|
REFERENCES "legacy_object"("_key", "type")
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE
|
ON DELETE CASCADE
|
||||||
)`),
|
)`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
CREATE TABLE "legacy_string" (
|
CREATE TABLE "legacy_string" (
|
||||||
"_key" TEXT NOT NULL
|
"_key" TEXT NOT NULL
|
||||||
PRIMARY KEY,
|
PRIMARY KEY,
|
||||||
@@ -177,13 +180,10 @@ CREATE TABLE "legacy_string" (
|
|||||||
REFERENCES "legacy_object"("_key", "type")
|
REFERENCES "legacy_object"("_key", "type")
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE
|
ON DELETE CASCADE
|
||||||
)`),
|
)`);
|
||||||
function (next) {
|
|
||||||
if (!res.rows[0].a) {
|
if (res.rows[0].a) {
|
||||||
return next();
|
await client.query(`
|
||||||
}
|
|
||||||
async.series([
|
|
||||||
async.apply(query, `
|
|
||||||
INSERT INTO "legacy_object" ("_key", "type", "expireAt")
|
INSERT INTO "legacy_object" ("_key", "type", "expireAt")
|
||||||
SELECT DISTINCT "data"->>'_key',
|
SELECT DISTINCT "data"->>'_key',
|
||||||
CASE WHEN (SELECT COUNT(*)
|
CASE WHEN (SELECT COUNT(*)
|
||||||
@@ -210,8 +210,8 @@ SELECT DISTINCT "data"->>'_key',
|
|||||||
THEN to_timestamp(("data"->>'expireAt')::double precision / 1000)
|
THEN to_timestamp(("data"->>'expireAt')::double precision / 1000)
|
||||||
ELSE NULL
|
ELSE NULL
|
||||||
END
|
END
|
||||||
FROM "objects"`),
|
FROM "objects"`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
INSERT INTO "legacy_hash" ("_key", "data")
|
INSERT INTO "legacy_hash" ("_key", "data")
|
||||||
SELECT "data"->>'_key',
|
SELECT "data"->>'_key',
|
||||||
"data" - '_key' - 'expireAt'
|
"data" - '_key' - 'expireAt'
|
||||||
@@ -227,8 +227,8 @@ SELECT "data"->>'_key',
|
|||||||
THEN NOT (("data" ? 'value')
|
THEN NOT (("data" ? 'value')
|
||||||
AND ("data" ? 'score'))
|
AND ("data" ? 'score'))
|
||||||
ELSE TRUE
|
ELSE TRUE
|
||||||
END`),
|
END`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
INSERT INTO "legacy_zset" ("_key", "value", "score")
|
INSERT INTO "legacy_zset" ("_key", "value", "score")
|
||||||
SELECT "data"->>'_key',
|
SELECT "data"->>'_key',
|
||||||
"data"->>'value',
|
"data"->>'value',
|
||||||
@@ -237,16 +237,16 @@ SELECT "data"->>'_key',
|
|||||||
WHERE (SELECT COUNT(*)
|
WHERE (SELECT COUNT(*)
|
||||||
FROM jsonb_object_keys("data" - 'expireAt')) = 3
|
FROM jsonb_object_keys("data" - 'expireAt')) = 3
|
||||||
AND ("data" ? 'value')
|
AND ("data" ? 'value')
|
||||||
AND ("data" ? 'score')`),
|
AND ("data" ? 'score')`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
INSERT INTO "legacy_set" ("_key", "member")
|
INSERT INTO "legacy_set" ("_key", "member")
|
||||||
SELECT "data"->>'_key',
|
SELECT "data"->>'_key',
|
||||||
jsonb_array_elements_text("data"->'members')
|
jsonb_array_elements_text("data"->'members')
|
||||||
FROM "objects"
|
FROM "objects"
|
||||||
WHERE (SELECT COUNT(*)
|
WHERE (SELECT COUNT(*)
|
||||||
FROM jsonb_object_keys("data" - 'expireAt')) = 2
|
FROM jsonb_object_keys("data" - 'expireAt')) = 2
|
||||||
AND ("data" ? 'members')`),
|
AND ("data" ? 'members')`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
INSERT INTO "legacy_list" ("_key", "array")
|
INSERT INTO "legacy_list" ("_key", "array")
|
||||||
SELECT "data"->>'_key',
|
SELECT "data"->>'_key',
|
||||||
ARRAY(SELECT t
|
ARRAY(SELECT t
|
||||||
@@ -255,8 +255,8 @@ SELECT "data"->>'_key',
|
|||||||
FROM "objects"
|
FROM "objects"
|
||||||
WHERE (SELECT COUNT(*)
|
WHERE (SELECT COUNT(*)
|
||||||
FROM jsonb_object_keys("data" - 'expireAt')) = 2
|
FROM jsonb_object_keys("data" - 'expireAt')) = 2
|
||||||
AND ("data" ? 'array')`),
|
AND ("data" ? 'array')`);
|
||||||
async.apply(query, `
|
await client.query(`
|
||||||
INSERT INTO "legacy_string" ("_key", "data")
|
INSERT INTO "legacy_string" ("_key", "data")
|
||||||
SELECT "data"->>'_key',
|
SELECT "data"->>'_key',
|
||||||
CASE WHEN "data" ? 'value'
|
CASE WHEN "data" ? 'value'
|
||||||
@@ -267,23 +267,37 @@ SELECT "data"->>'_key',
|
|||||||
WHERE (SELECT COUNT(*)
|
WHERE (SELECT COUNT(*)
|
||||||
FROM jsonb_object_keys("data" - 'expireAt')) = 2
|
FROM jsonb_object_keys("data" - 'expireAt')) = 2
|
||||||
AND (("data" ? 'value')
|
AND (("data" ? 'value')
|
||||||
OR ("data" ? 'data'))`),
|
OR ("data" ? 'data'))`);
|
||||||
async.apply(query, `DROP TABLE "objects" CASCADE`),
|
await client.query(`DROP TABLE "objects" CASCADE`);
|
||||||
async.apply(query, `DROP FUNCTION "fun__objects__expireAt"() CASCADE`),
|
await client.query(`DROP FUNCTION "fun__objects__expireAt"() CASCADE`);
|
||||||
], next);
|
}
|
||||||
},
|
await client.query(`
|
||||||
async.apply(query, `
|
|
||||||
CREATE VIEW "legacy_object_live" AS
|
CREATE VIEW "legacy_object_live" AS
|
||||||
SELECT "_key", "type"
|
SELECT "_key", "type"
|
||||||
FROM "legacy_object"
|
FROM "legacy_object"
|
||||||
WHERE "expireAt" IS NULL
|
WHERE "expireAt" IS NULL
|
||||||
OR "expireAt" > CURRENT_TIMESTAMP`),
|
OR "expireAt" > CURRENT_TIMESTAMP`);
|
||||||
], function (err) {
|
}
|
||||||
query(err ? `ROLLBACK` : `COMMIT`, function (err1) {
|
|
||||||
callback(err1 || err);
|
if (!res.rows[0].c) {
|
||||||
});
|
await client.query(`
|
||||||
});
|
CREATE FUNCTION "nodebb_get_sorted_set_members"(TEXT) RETURNS TEXT[] AS $$
|
||||||
});
|
SELECT array_agg(z."value" ORDER BY z."score" ASC)
|
||||||
|
FROM "legacy_object_live" o
|
||||||
|
INNER JOIN "legacy_zset" z
|
||||||
|
ON o."_key" = z."_key"
|
||||||
|
AND o."type" = z."type"
|
||||||
|
WHERE o."_key" = $1
|
||||||
|
$$ LANGUAGE sql
|
||||||
|
STABLE
|
||||||
|
STRICT
|
||||||
|
PARALLEL SAFE`);
|
||||||
|
}
|
||||||
|
} catch (ex) {
|
||||||
|
await client.query(`ROLLBACK`);
|
||||||
|
throw ex;
|
||||||
|
}
|
||||||
|
await client.query(`COMMIT`);
|
||||||
}
|
}
|
||||||
|
|
||||||
postgresModule.createSessionStore = function (options, callback) {
|
postgresModule.createSessionStore = function (options, callback) {
|
||||||
|
|||||||
@@ -463,19 +463,14 @@ SELECT o."_key" k
|
|||||||
const res = await module.pool.query({
|
const res = await module.pool.query({
|
||||||
name: 'getSortedSetsMembers',
|
name: 'getSortedSetsMembers',
|
||||||
text: `
|
text: `
|
||||||
SELECT o."_key" k,
|
SELECT "_key" k,
|
||||||
array_agg(z."value" ORDER BY z."score" ASC) m
|
"nodebb_get_sorted_set_members"("_key") m
|
||||||
FROM "legacy_object_live" o
|
FROM UNNEST($1::TEXT[]) "_key";`,
|
||||||
INNER JOIN "legacy_zset" z
|
|
||||||
ON o."_key" = z."_key"
|
|
||||||
AND o."type" = z."type"
|
|
||||||
WHERE o."_key" = ANY($1::TEXT[])
|
|
||||||
GROUP BY o."_key"`,
|
|
||||||
values: [keys],
|
values: [keys],
|
||||||
});
|
});
|
||||||
|
|
||||||
return keys.map(function (k) {
|
return keys.map(function (k) {
|
||||||
return (res.rows.find(r => r.k === k) || { m: [] }).m;
|
return (res.rows.find(r => r.k === k) || {}).m || [];
|
||||||
});
|
});
|
||||||
};
|
};
|
||||||
|
|
||||||
|
|||||||
Reference in New Issue
Block a user