-
Notifications
You must be signed in to change notification settings - Fork 411
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
refactor(balance): create tables to store balance separately
Create three tables to separately store content TabCoins, user TabCoins and user TabCash operations.
- Loading branch information
Showing
1 changed file
with
257 additions
and
0 deletions.
There are no files selected for viewing
257 changes: 257 additions & 0 deletions
257
infra/migrations/1711833444337_create-separate-balance-operations-tables.js
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,257 @@ | ||
exports.up = (pgm) => { | ||
pgm.createTable('content_tabcoin_operations', { | ||
id: { | ||
type: 'uuid', | ||
default: pgm.func('gen_random_uuid()'), | ||
notNull: true, | ||
primaryKey: true, | ||
}, | ||
|
||
sequence: { | ||
type: 'serial', | ||
notNull: true, | ||
}, | ||
|
||
balance_type: { | ||
type: 'text', | ||
notNull: true, | ||
}, | ||
|
||
recipient_id: { | ||
type: 'uuid', | ||
notNull: true, | ||
}, | ||
|
||
amount: { | ||
type: 'integer', | ||
notNull: true, | ||
}, | ||
|
||
originator_type: { | ||
type: 'text', | ||
notNull: true, | ||
}, | ||
|
||
originator_id: { | ||
type: 'uuid', | ||
notNull: true, | ||
}, | ||
|
||
created_at: { | ||
type: 'timestamp with time zone', | ||
notNull: true, | ||
default: pgm.func("(now() at time zone 'utc')"), | ||
}, | ||
}); | ||
|
||
pgm.createTable('user_tabcoin_operations', { | ||
id: { | ||
type: 'uuid', | ||
default: pgm.func('gen_random_uuid()'), | ||
notNull: true, | ||
primaryKey: true, | ||
}, | ||
|
||
sequence: { | ||
type: 'serial', | ||
notNull: true, | ||
}, | ||
|
||
recipient_id: { | ||
type: 'uuid', | ||
notNull: true, | ||
}, | ||
|
||
amount: { | ||
type: 'integer', | ||
notNull: true, | ||
}, | ||
|
||
originator_type: { | ||
type: 'text', | ||
notNull: true, | ||
}, | ||
|
||
originator_id: { | ||
type: 'uuid', | ||
notNull: true, | ||
}, | ||
|
||
created_at: { | ||
type: 'timestamp with time zone', | ||
notNull: true, | ||
default: pgm.func("(now() at time zone 'utc')"), | ||
}, | ||
}); | ||
|
||
pgm.createTable('user_tabcash_operations', { | ||
id: { | ||
type: 'uuid', | ||
default: pgm.func('gen_random_uuid()'), | ||
notNull: true, | ||
primaryKey: true, | ||
}, | ||
|
||
sequence: { | ||
type: 'serial', | ||
notNull: true, | ||
}, | ||
|
||
recipient_id: { | ||
type: 'uuid', | ||
notNull: true, | ||
}, | ||
|
||
amount: { | ||
type: 'integer', | ||
notNull: true, | ||
}, | ||
|
||
originator_type: { | ||
type: 'text', | ||
notNull: true, | ||
}, | ||
|
||
originator_id: { | ||
type: 'uuid', | ||
notNull: true, | ||
}, | ||
|
||
created_at: { | ||
type: 'timestamp with time zone', | ||
notNull: true, | ||
default: pgm.func("(now() at time zone 'utc')"), | ||
}, | ||
}); | ||
|
||
pgm.createFunction( | ||
'get_content_current_tabcoins', | ||
[ | ||
{ | ||
name: 'recipient_id_input', | ||
mode: 'IN', | ||
type: 'uuid', | ||
}, | ||
], | ||
{ | ||
returns: 'integer', | ||
language: 'plpgsql', | ||
replace: true, | ||
}, | ||
` | ||
DECLARE | ||
total_tabcoins integer; | ||
BEGIN | ||
SELECT COALESCE(SUM(amount), 0) | ||
INTO total_tabcoins | ||
FROM content_tabcoin_operations | ||
WHERE | ||
recipient_id = recipient_id_input; | ||
RETURN total_tabcoins; | ||
END; | ||
`, | ||
); | ||
|
||
pgm.createFunction( | ||
'get_user_current_tabcoins', | ||
[ | ||
{ | ||
name: 'recipient_id_input', | ||
mode: 'IN', | ||
type: 'uuid', | ||
}, | ||
], | ||
{ | ||
returns: 'integer', | ||
language: 'plpgsql', | ||
replace: true, | ||
}, | ||
` | ||
DECLARE | ||
total_tabcoins integer; | ||
BEGIN | ||
SELECT COALESCE(SUM(amount), 0) | ||
INTO total_tabcoins | ||
FROM user_tabcoin_operations | ||
WHERE | ||
recipient_id = recipient_id_input; | ||
RETURN total_tabcoins; | ||
END; | ||
`, | ||
); | ||
|
||
pgm.createFunction( | ||
'get_user_current_tabcash', | ||
[ | ||
{ | ||
name: 'recipient_id_input', | ||
mode: 'IN', | ||
type: 'uuid', | ||
}, | ||
], | ||
{ | ||
returns: 'integer', | ||
language: 'plpgsql', | ||
replace: true, | ||
}, | ||
` | ||
DECLARE | ||
total_tabcash integer; | ||
BEGIN | ||
SELECT COALESCE(SUM(amount), 0) | ||
INTO total_tabcash | ||
FROM user_tabcash_operations | ||
WHERE | ||
recipient_id = recipient_id_input; | ||
RETURN total_tabcash; | ||
END; | ||
`, | ||
); | ||
|
||
pgm.createIndex('content_tabcoin_operations', ['recipient_id', 'balance_type']); | ||
pgm.createIndex('user_tabcoin_operations', ['recipient_id']); | ||
pgm.createIndex('user_tabcash_operations', ['recipient_id']); | ||
}; | ||
|
||
exports.down = (pgm) => { | ||
// Do not drop the created tables to avoid accidentally losing data. | ||
|
||
pgm.dropFunction( | ||
'get_content_current_tabcoins', | ||
[ | ||
{ | ||
name: 'recipient_id_input', | ||
mode: 'IN', | ||
type: 'uuid', | ||
}, | ||
], | ||
{ ifExists: true }, | ||
); | ||
|
||
pgm.dropFunction( | ||
'get_user_current_tabcoins', | ||
[ | ||
{ | ||
name: 'recipient_id_input', | ||
mode: 'IN', | ||
type: 'uuid', | ||
}, | ||
], | ||
{ ifExists: true }, | ||
); | ||
|
||
pgm.dropFunction( | ||
'get_user_current_tabcash', | ||
[ | ||
{ | ||
name: 'recipient_id_input', | ||
mode: 'IN', | ||
type: 'uuid', | ||
}, | ||
], | ||
{ ifExists: true }, | ||
); | ||
}; |