Skip to content

Commit

Permalink
migration (DefiLlama#295)
Browse files Browse the repository at this point in the history
* migration

* remove balancer pools from exclusion list

* bug fix serverless

* remove timestamp from median, update for tests

* update get distinct id controller

* update distinctID controller, remove dep

* move confirm into scripts

* testing url

* remove Pg suffix from lambda names

* change to existing api host

* add comments

* revert service name, bucketsg

* put pack fantom rpc
  • Loading branch information
slasher125 authored Sep 6, 2022
1 parent 021f41c commit 2ee397f
Show file tree
Hide file tree
Showing 42 changed files with 1,975 additions and 1,831 deletions.
1 change: 1 addition & 0 deletions .github/workflows/master.yml
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,7 @@ jobs:
env:
AWS_ACCESS_KEY_ID: ${{ secrets.AWS_ACCESS_KEY_ID }}
AWS_SECRET_ACCESS_KEY: ${{ secrets.AWS_SECRET_ACCESS_KEY }}
DATABASE_URL: ${{ secrets.DATABASE_URL }}
INFURA_CONNECTION: ${{ secrets.INFURA_CONNECTION }}
ALCHEMY_CONNECTION_POLYGON: ${{ secrets.ALCHEMY_CONNECTION_POLYGON }}
ALCHEMY_CONNECTION_ARBITRUM: ${{ secrets.ALCHEMY_CONNECTION_ARBITRUM }}
Expand Down
2 changes: 2 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -8,3 +8,5 @@ ccImages
.idea/
*output.json
*.csv
*.sql
scripts/*.json
4 changes: 2 additions & 2 deletions beforeTests.js
Original file line number Diff line number Diff line change
Expand Up @@ -35,9 +35,9 @@ module.exports = async function () {
global.uniquePoolIdentifiersDB = new Set(
(
await axios.get(
'https://1rwmj4tky9.execute-api.eu-central-1.amazonaws.com/simplePools'
'https://1rwmj4tky9.execute-api.eu-central-1.amazonaws.com/distinctID'
)
).data.data
).data
.filter((p) => p.project !== global.apy[0].project)
.map((p) => p.pool)
);
Expand Down
2 changes: 2 additions & 0 deletions env.js
Original file line number Diff line number Diff line change
Expand Up @@ -19,4 +19,6 @@ module.exports = {
.readdirSync('./src/adaptors')
.filter((el) => !el.includes('js') && el !== '.DS_Store')
),
// DB
DATABASE_URL: process.env.DATABASE_URL,
};
138 changes: 138 additions & 0 deletions migrations/1661488110733_init.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,138 @@
const { PgLiteral } = require('node-pg-migrate');

exports.up = (pgm) => {
// ----- ADD UUID EXTENSION
pgm.createExtension('uuid-ossp', {
ifNotExists: true,
});
// ----- CREATE TABLES
// --- config
// table with static/semi-static information and consists of 1 row per unique pool.
// operations on this table: insert for new pools, update for existing pools
pgm.createTable('config', {
config_id: {
type: 'uuid', // uuid is created in the application
primaryKey: true,
},
updated_at: {
type: 'timestamptz',
notNull: true,
default: pgm.func('current_timestamp'),
},
pool: { type: 'text', notNull: true, unique: true },
project: { type: 'text', notNull: true },
chain: { type: 'text', notNull: true },
symbol: { type: 'text', notNull: true },
poolMeta: 'text',
underlyingTokens: { type: 'text[]' },
rewardTokens: { type: 'text[]' },
url: { type: 'text', notNull: true },
});

// --- yield
// our timeseries table. insert only on hourly granularity
pgm.createTable('yield', {
yield_id: {
type: 'uuid',
default: new PgLiteral('uuid_generate_v4()'),
primaryKey: true,
},
// configID is a FK in this table and references the PK (config_id) in config
configID: {
type: 'uuid',
notNull: true,
references: '"config"',
onDelete: 'cascade',
},
timestamp: {
type: 'timestamptz',
notNull: true,
},
tvlUsd: { type: 'bigint', notNull: true },
apy: { type: 'numeric', notNull: true },
apyBase: 'numeric',
apyReward: 'numeric',
});

// --- stat
// table which contains rolling statistics required to calculate ML features values
// and other things we use for plotting on the /overview page
pgm.createTable('stat', {
stat_id: {
type: 'uuid',
default: new PgLiteral('uuid_generate_v4()'),
primaryKey: true,
},
// configID is a FK in this table and references the PK (config_id) in config
configID: {
type: 'uuid',
notNull: true,
references: '"config"',
unique: true,
onDelete: 'cascade',
},
updated_at: {
type: 'timestamptz',
notNull: true,
default: pgm.func('current_timestamp'),
},
count: { type: 'smallint', notNull: true },
meanAPY: { type: 'numeric', notNull: true },
mean2APY: { type: 'numeric', notNull: true },
meanDR: { type: 'numeric', notNull: true },
mean2DR: { type: 'numeric', notNull: true },
productDR: { type: 'numeric', notNull: true },
});

// --- median
// median table content is used for the median chart on /overview (append only)
pgm.createTable('median', {
median_id: {
type: 'uuid',
default: new PgLiteral('uuid_generate_v4()'),
primaryKey: true,
},
timestamp: {
type: 'timestamptz',
notNull: true,
unique: true,
},
uniquePools: { type: 'integer', notNull: true },
medianAPY: { type: 'numeric', notNull: true },
});

// ----- FUNCTION
// for creating the updated_at timestamp field
pgm.createFunction(
'update_updated_at',
[], // no params
// options
{
language: 'plpgsql',
returns: 'TRIGGER',
replace: true,
},
// function body
`
BEGIN
NEW.updated_at = now();
RETURN NEW;
END
`
);

// ----- TRIGGERS;
// to trigger the defined function
pgm.createTrigger('config', 'update_updated_at', {
when: 'BEFORE',
operation: 'UPDATE',
function: 'update_updated_at',
level: 'ROW',
});
pgm.createTrigger('stat', 'update_updated_at', {
when: 'BEFORE',
operation: 'UPDATE',
function: 'update_updated_at',
level: 'ROW',
});
};
8 changes: 8 additions & 0 deletions migrations/1662350452113_add-yield-index.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
exports.up = (pgm) => {
// composite index for yield;
// added after ingestion of historical data
pgm.createIndex('yield', [
{ name: 'configID', sort: 'ASC' },
{ name: 'timestamp', sort: 'DESC' },
]);
};
Loading

0 comments on commit 2ee397f

Please sign in to comment.