Skip to content

Commit

Permalink
docs: Added script to push sql functions to db for prototyping, updat…
Browse files Browse the repository at this point in the history
…ed README.md
  • Loading branch information
tmrdlt committed Nov 4, 2024
1 parent f8e824c commit c257df3
Show file tree
Hide file tree
Showing 6 changed files with 161 additions and 42 deletions.
101 changes: 63 additions & 38 deletions README.md
Original file line number Diff line number Diff line change
@@ -1,69 +1,94 @@

## Description
# Dex Backend

[Dex-Backend](https://github.com/aeternity/dex-backend)
## Local development

## Installation
### Prerequisites
- [Node.js](https://nodejs.org/)
- Docker

### Setup DB & run the application
1. Install dependencies:
```bash
$ npm install
npm install
```
2. Run docker container with DB locally, will also run DB migrations
```bash
npm run db:start
```

## Database
3. Start the development server:
```bash
npm run serve:dev
```
# after any schema definition change run
$ npm install

# or
### Database
#### Schema changes
This application uses Prisma as an ORM. To make changes to the DB schema, you need to update the schema in `prisma/schema.prisma`.
- For prototyping during development you can push the schema changes to the DB using:
```bash
npm run db:push-schema
```
- Once the schema changes are ready to deploy, you can generate and apply a prisma migration file with the change using:
```bash
prisma migrate dev --name <NAME_OF_YOUR_MIGRATION>
```

#### User defined PostgreSQL functions
This application uses user defined functions in the PostgreSQL database. These functions are defined in the `sql-functions` directory.
- For prototyping during development you can push the functions to the DB using:
```bash
npm run db:deploy-functions
```
- Once the functions are ready to deploy you have to manually create an empty prisma migration for them using:
```bash
prisma migrate dev --create-only --name <NAME_OF_YOUR_MIGRATION>
```
Then, copy your sql code into the newly created migration file. Afterwards, apply the changes using `prisma migrate dev`

### Testing

$ npx prisma generate
```
```bash
# unit tests
npm run test
## Container
# e2e tests
npm run test:e2e
# test coverage
npm run test:cov
```
# to deploy
npm run db:deploy

### Further commands for interacting with the DB container

```bash
# to start
npm run db:start
# to stop container
npm run db:stop
#to remove / reset container (this helps to erase db also)
# to remove (will delete all db data)
npm run db:remove
#if you want to run the container into interactive mode
npm run db
#WARNING: if container runs in interactive mode for the first time run from other terminal :
$ npm run db:push-schema
# to reset (delete all data and recreate db)
npm run db:reset
```

## Running the app
### Further commands for running the app

```bash
# development
$ npm run serve
npm run serve
# watch mode
$ npm run serve:dev
npm run serve:dev
# debug mode
$ npm run serve:debug
npm run serve:debug
# production mode
$ npm run build
$ npm run serve:prod
npm run build
npm run serve:prod
```

## Test

```bash
# unit tests
$ npm run test

# e2e tests
$ npm run test:e2e

# test coverage
$ npm run test:cov
```
9 changes: 5 additions & 4 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -23,13 +23,14 @@
"test:debug": "node --inspect-brk -r tsconfig-paths/register -r ts-node/register node_modules/.bin/jest --runInBand",
"test:e2e": "npm run test -- --runInBand --config ./test/e2e/jest-e2e.json --forceExit",
"db": "docker compose up",
"db:deploy": "docker compose up -d",
"db:start": "docker compose up -d",
"db:stop": "docker compose stop",
"db:remove": "docker compose down -v",
"db:redeploy": "npm run db:remove; npm run db:deploy",
"db:stop": "docker compose stop ",
"db:reset": "npm run db:remove; npm run db:start",
"db:push-schema": "npx prisma db push",
"db:migrate": "npx prisma migrate deploy",
"postdb:deploy": "sleep 1.5; npm run db:migrate",
"db:push-sql-functions": "ts-node script/push-sql-functions.ts",
"postdb:start": "sleep 1.5; npm run db:migrate",
"pretest:e2e": "dotenv -e .env.test npx prisma migrate dev",
"prisma:test-studio": "dotenv -e .env.test npx prisma studio",
"prisma:studio": "npx prisma studio"
Expand Down
34 changes: 34 additions & 0 deletions script/push-sql-functions.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
import { PrismaClient } from '@prisma/client';
import * as fs from 'fs';
import * as path from 'path';

const prisma = new PrismaClient();

async function loadAndExecuteSQLFiles() {
const sqlDir = path.join(__dirname, '..', 'sql-functions');

const files = fs.readdirSync(sqlDir);
for (const file of files) {
const filePath = path.join(sqlDir, file);
const sql = fs.readFileSync(filePath, 'utf-8');

try {
await prisma.$executeRawUnsafe(sql);
console.log(`Executed SQL from file: ${file}`);
} catch (error) {
console.error(`Failed to execute SQL from file: ${file}`, error);
}
}
}

// Execute the function and handle cleanup
loadAndExecuteSQLFiles()
.then(() => {
console.log('SQL functions loaded successfully.');
})
.catch((error) => {
console.error('Error loading SQL functions:', error);
})
.finally(() => {
prisma.$disconnect();
});
16 changes: 16 additions & 0 deletions sql-functions/historic_price.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
CREATE
OR REPLACE FUNCTION historic_price (integer, interval) RETURNS numeric AS 'SELECT SUM(CASE
WHEN t.id = p.t0 THEN (latest_liquidity_info."token0AePrice") *
(latest_liquidity_info."reserve0" / POW(10, t.decimals))
ELSE (latest_liquidity_info."token1AePrice") *
(latest_liquidity_info."reserve1" / POW(10, t.decimals)) END /
total_reserve(t.id, $2))
FROM "Token" t
LEFT JOIN "Pair" p on t.id = p.t0 OR t.id = p.t1
LEFT JOIN LATERAL (SELECT *
FROM "PairLiquidityInfoHistory"
WHERE p.id = "pairId"
AND "microBlockTime" <= extract(epoch from NOW() - $2) * 1000
ORDER BY "microBlockTime" DESC, "logIndex" DESC
LIMIT 1) latest_liquidity_info ON TRUE
WHERE $1 = t.id' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT;
16 changes: 16 additions & 0 deletions sql-functions/total_reserve.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
CREATE
OR REPLACE FUNCTION total_reserve (integer, interval) RETURNS numeric AS 'SELECT SUM(CASE
WHEN t.id = p.t0 THEN
(latest_liquidity_info."reserve0" / POW(10, t.decimals))
ELSE (latest_liquidity_info."reserve1" / POW(10, t.decimals)) END
)
FROM "Token" t
LEFT JOIN "Pair" p on t.id = p.t0 OR t.id = p.t1
LEFT JOIN LATERAL (SELECT *
FROM "PairLiquidityInfoHistory"
WHERE p.id = "pairId"
AND "microBlockTime" <= extract(epoch from NOW() - $2) * 1000
ORDER BY "microBlockTime" DESC, "logIndex" DESC
LIMIT 1) latest_liquidity_info ON TRUE
WHERE $1 = t.id' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT;
27 changes: 27 additions & 0 deletions sql-functions/volume_usd.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
CREATE
OR REPLACE FUNCTION volume_usd (integer, interval) RETURNS numeric AS 'SELECT ROUND(SUM(CASE
WHEN t.id = p.t0 THEN
CASE
WHEN liquidity_history."token0AePrice" >= 0 AND
liquidity_history."eventType" = ''SwapTokens'' AND
liquidity_history."microBlockTime" >=
extract(epoch from NOW() - $2) * 1000
THEN
(ABS(liquidity_history."deltaReserve0") / POW(10, t.decimals)) *
liquidity_history."token0AePrice" *
liquidity_history."aeUsdPrice" END
ELSE CASE
WHEN liquidity_history."token1AePrice" >= 0 AND
liquidity_history."eventType" = ''SwapTokens'' AND
liquidity_history."microBlockTime" >=
extract(epoch from NOW() - $2) * 1000
THEN
(ABS(liquidity_history."deltaReserve1") / POW(10, t.decimals)) *
liquidity_history."token1AePrice" *
liquidity_history."aeUsdPrice" END END
)::numeric, 4)
FROM "Token" t
LEFT JOIN "Pair" p on t.id = p.t0 OR t.id = p.t1
LEFT JOIN "PairLiquidityInfoHistory" liquidity_history ON p.id = liquidity_history."pairId"
WHERE $1 = t.id' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT;

0 comments on commit c257df3

Please sign in to comment.