@ -63,7 +63,10 @@ postgresModule.init = function (callback) {
postgresModule . pool = db ;
postgresModule . client = db ;
checkUpgrade ( client , function ( err ) {
checkUpgrade ( client ) . then ( function ( ) {
release ( ) ;
callback ( null ) ;
} , function ( err ) {
release ( ) ;
callback ( err ) ;
} ) ;
@ -71,8 +74,8 @@ postgresModule.init = function (callback) {
} ;
function checkUpgrade ( client , callback ) {
client . query ( `
async function checkUpgrade ( client ) {
var res = await client . query ( `
SELECT EXISTS ( SELECT *
FROM "information_schema" . "columns"
WHERE "table_schema" = 'public'
@ -82,32 +85,32 @@ SELECT EXISTS(SELECT *
FROM "information_schema" . "columns"
WHERE "table_schema" = 'public'
AND "table_name" = 'legacy_hash'
AND "column_name" = '_key' ) b ` , function (err, res) {
if ( err ) {
return callback ( err ) ;
}
if ( res . rows [ 0 ] . b ) {
return callback ( null ) ;
}
AND "column_name" = '_key' ) b ,
EXISTS ( SELECT *
FROM "information_schema" . "routines"
WHERE "routine_schema" = 'public'
AND "routine_name" = 'nodebb_get_sorted_set_members' ) c ` );
var query = client . query . bind ( client ) ;
if ( res . rows [ 0 ] . a && res . rows [ 0 ] . b && res . rows [ 0 ] . c ) {
return ;
}
async . series ( [
async . apply ( query , ` BEGIN ` ) ,
async . apply ( query , `
await client . query ( ` BEGIN ` ) ;
try {
if ( ! res . rows [ 0 ] . b ) {
await client . query ( `
CREATE TYPE LEGACY _OBJECT _TYPE AS ENUM (
'hash' , 'zset' , 'set' , 'list' , 'string'
) ` ) ,
a sync. apply ( query , `
) ` ) ;
a wait client . query ( `
CREATE TABLE "legacy_object" (
"_key" TEXT NOT NULL
PRIMARY KEY ,
"type" LEGACY _OBJECT _TYPE NOT NULL ,
"expireAt" TIMESTAMPTZ DEFAULT NULL ,
UNIQUE ( "_key" , "type" )
) ` ) ,
a sync. apply ( query , `
) ` ) ;
a wait client . query ( `
CREATE TABLE "legacy_hash" (
"_key" TEXT NOT NULL
PRIMARY KEY ,
@ -120,8 +123,8 @@ CREATE TABLE "legacy_hash" (
REFERENCES "legacy_object" ( "_key" , "type" )
ON UPDATE CASCADE
ON DELETE CASCADE
) ` ) ,
a sync. apply ( query , `
) ` ) ;
a wait client . query ( `
CREATE TABLE "legacy_zset" (
"_key" TEXT NOT NULL ,
"value" TEXT NOT NULL ,
@ -135,8 +138,8 @@ CREATE TABLE "legacy_zset" (
REFERENCES "legacy_object" ( "_key" , "type" )
ON UPDATE CASCADE
ON DELETE CASCADE
) ` ) ,
a sync. apply ( query , `
) ` ) ;
a wait client . query ( `
CREATE TABLE "legacy_set" (
"_key" TEXT NOT NULL ,
"member" TEXT NOT NULL ,
@ -149,8 +152,8 @@ CREATE TABLE "legacy_set" (
REFERENCES "legacy_object" ( "_key" , "type" )
ON UPDATE CASCADE
ON DELETE CASCADE
) ` ) ,
a sync. apply ( query , `
) ` ) ;
a wait client . query ( `
CREATE TABLE "legacy_list" (
"_key" TEXT NOT NULL
PRIMARY KEY ,
@ -163,8 +166,8 @@ CREATE TABLE "legacy_list" (
REFERENCES "legacy_object" ( "_key" , "type" )
ON UPDATE CASCADE
ON DELETE CASCADE
) ` ) ,
a sync. apply ( query , `
) ` ) ;
a wait client . query ( `
CREATE TABLE "legacy_string" (
"_key" TEXT NOT NULL
PRIMARY KEY ,
@ -177,13 +180,10 @@ CREATE TABLE "legacy_string" (
REFERENCES "legacy_object" ( "_key" , "type" )
ON UPDATE CASCADE
ON DELETE CASCADE
) ` ),
function ( next ) {
if ( ! res . rows [ 0 ] . a ) {
return next ( ) ;
}
async . series ( [
async . apply ( query , `
) ` );
if ( res . rows [ 0 ] . a ) {
await client . query ( `
INSERT INTO "legacy_object" ( "_key" , "type" , "expireAt" )
SELECT DISTINCT "data" - >> '_key' ,
CASE WHEN ( SELECT COUNT ( * )
@ -210,8 +210,8 @@ SELECT DISTINCT "data"->>'_key',
THEN to _timestamp ( ( "data" - >> 'expireAt' ) : : double precision / 1000 )
ELSE NULL
END
FROM "objects" ` ) ,
async . apply ( query , `
FROM "objects" ` ) ;
await client . query ( `
INSERT INTO "legacy_hash" ( "_key" , "data" )
SELECT "data" - >> '_key' ,
"data" - '_key' - 'expireAt'
@ -227,8 +227,8 @@ SELECT "data"->>'_key',
THEN NOT ( ( "data" ? 'value' )
AND ( "data" ? 'score' ) )
ELSE TRUE
END ` ) ,
async . apply ( query , `
END ` ) ;
await client . query ( `
INSERT INTO "legacy_zset" ( "_key" , "value" , "score" )
SELECT "data" - >> '_key' ,
"data" - >> 'value' ,
@ -237,16 +237,16 @@ SELECT "data"->>'_key',
WHERE ( SELECT COUNT ( * )
FROM jsonb _object _keys ( "data" - 'expireAt' ) ) = 3
AND ( "data" ? 'value' )
AND ( "data" ? 'score' ) ` ) ,
async . apply ( query , `
AND ( "data" ? 'score' ) ` ) ;
await client . query ( `
INSERT INTO "legacy_set" ( "_key" , "member" )
SELECT "data" - >> '_key' ,
jsonb _array _elements _text ( "data" - > 'members' )
FROM "objects"
WHERE ( SELECT COUNT ( * )
FROM jsonb _object _keys ( "data" - 'expireAt' ) ) = 2
AND ( "data" ? 'members' ) ` ) ,
async . apply ( query , `
AND ( "data" ? 'members' ) ` ) ;
await client . query ( `
INSERT INTO "legacy_list" ( "_key" , "array" )
SELECT "data" - >> '_key' ,
ARRAY ( SELECT t
@ -255,8 +255,8 @@ SELECT "data"->>'_key',
FROM "objects"
WHERE ( SELECT COUNT ( * )
FROM jsonb _object _keys ( "data" - 'expireAt' ) ) = 2
AND ( "data" ? 'array' ) ` ) ,
async . apply ( query , `
AND ( "data" ? 'array' ) ` ) ;
await client . query ( `
INSERT INTO "legacy_string" ( "_key" , "data" )
SELECT "data" - >> '_key' ,
CASE WHEN "data" ? 'value'
@ -267,23 +267,37 @@ SELECT "data"->>'_key',
WHERE ( SELECT COUNT ( * )
FROM jsonb _object _keys ( "data" - 'expireAt' ) ) = 2
AND ( ( "data" ? 'value' )
OR ( "data" ? 'data' ) ) ` ),
async . apply ( query , ` DROP TABLE "objects" CASCADE ` ) ,
async . apply ( query , ` DROP FUNCTION "fun__objects__expireAt"() CASCADE ` ) ,
] , next ) ;
} ,
async . apply ( query , `
OR ( "data" ? 'data' ) ) ` );
await client . query ( ` DROP TABLE "objects" CASCADE ` ) ;
await client . query ( ` DROP FUNCTION "fun__objects__expireAt"() CASCADE ` ) ;
}
await client . query ( `
CREATE VIEW "legacy_object_live" AS
SELECT "_key" , "type"
FROM "legacy_object"
WHERE "expireAt" IS NULL
OR "expireAt" > CURRENT _TIMESTAMP ` ),
] , function ( err ) {
query ( err ? ` ROLLBACK ` : ` COMMIT ` , function ( err1 ) {
callback ( err1 || err ) ;
} ) ;
} ) ;
} ) ;
OR "expireAt" > CURRENT _TIMESTAMP ` );
}
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 ) {