Optimize PostgreSQL session store.

- Sets session ID to be a constant-sized character field inline in the
  table instead of a variable-length character field compressed outside
  of the row.
- Changes the session data from "json" to "jsonb" which is faster and
  smaller on disk with the drawback of not maintaining key order and
  whitespace (which we don't care about at all)
- Adds a clustered index on the session expiration timestamp, which will
  make periodic session purging much faster.

(For an example, WTDWTF currently has 482355 sessions in the table, and
 because there is no index on the expiration timestamp, PostgreSQL must
 check all the rows in the table every time.)

This upgrade script can run concurrently with a live NodeBB instance,
but any action that touches sessions will wait until the upgrade script
is done.

Does not touch the database if the database driver is not set to
PostgreSQL or if there is a Redis database configured.
v1.18.x
Ben Lubar 7 years ago committed by Julian Lam
parent cc532d2c8b
commit 97a3079bc0

@ -366,15 +366,18 @@ postgresModule.initSessionStore = function (callback) {
db.query(`
CREATE TABLE IF NOT EXISTS "session" (
"sid" VARCHAR NOT NULL
COLLATE "default",
"sess" JSON NOT NULL,
"expire" TIMESTAMP(6) NOT NULL,
CONSTRAINT "session_pkey"
PRIMARY KEY ("sid")
NOT DEFERRABLE
INITIALLY IMMEDIATE
) WITH (OIDS=FALSE)`, function (err) {
"sid" CHAR(32) NOT NULL
COLLATE "C"
PRIMARY KEY,
"sess" JSONB NOT NULL,
"expire" TIMESTAMPTZ NOT NULL
) WITHOUT OIDS;
CREATE INDEX IF NOT EXISTS "session_expire_idx" ON "session"("expire");
ALTER TABLE "session"
ALTER "sid" SET STORAGE MAIN,
CLUSTER ON "session_expire_idx";`, function (err) {
if (err) {
return callback(err);
}

@ -0,0 +1,41 @@
'use strict';
var db = require('../../database');
var nconf = require('nconf');
module.exports = {
name: 'Optimize PostgreSQL sessions',
timestamp: Date.UTC(2018, 9, 1),
method: function (callback) {
if (nconf.get('database') !== 'postgres' || nconf.get('redis')) {
return callback();
}
db.pool.query(`
BEGIN TRANSACTION;
CREATE TABLE IF NOT EXISTS "session" (
"sid" CHAR(32) NOT NULL
COLLATE "C"
PRIMARY KEY,
"sess" JSONB NOT NULL,
"expire" TIMESTAMPTZ NOT NULL
) WITHOUT OIDS;
CREATE INDEX IF NOT EXISTS "session_expire_idx" ON "session"("expire");
ALTER TABLE "session"
ALTER "sid" TYPE CHAR(32) COLLATE "C",
ALTER "sid" SET STORAGE PLAIN,
ALTER "sess" TYPE JSONB,
ALTER "expire" TYPE TIMESTAMPTZ,
CLUSTER ON "session_expire_idx";
CLUSTER "session";
ANALYZE "session";
COMMIT;`, function (err) {
callback(err);
});
},
};
Loading…
Cancel
Save