Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

chore: db schema docs #739

Merged
merged 27 commits into from
Feb 3, 2025
Merged
Changes from all commits
Commits
Show all changes
27 commits
Select commit Hold shift + click to select a range
8a9430d
feat(dx): added new queries to the example queries
baktun14 Jan 24, 2025
5516943
chore: added example queries
baktun14 Jan 24, 2025
a03e718
chore: added comments to akash block
baktun14 Jan 24, 2025
ff1f37b
chore: added comments to akash message
baktun14 Jan 24, 2025
f9483f5
chore: added comments to bid
baktun14 Jan 24, 2025
636db83
chore: document deployment schema
baktun14 Jan 25, 2025
d835ee6
chore: document deployment group schema
baktun14 Jan 25, 2025
d820ec9
chore: add documentation to deployment group resource
baktun14 Jan 25, 2025
aa4c866
chore: add comprehensive documentation to lease schema
baktun14 Jan 25, 2025
6c96069
chore: add comprehensive documentation to provider schema
baktun14 Jan 25, 2025
83fb3e6
chore: add documentation to provider attribute schema
baktun14 Jan 25, 2025
7031d2e
chore: enhance documentation for provider attribute signature schema
baktun14 Jan 25, 2025
4eaae5b
chore: add comprehensive documentation to provider snapshot schema
baktun14 Jan 25, 2025
1437ca2
chore: add detailed documentation to provider snapshot node schema
baktun14 Jan 25, 2025
0415a6f
chore: add detailed documentation to provider snapshot node GPU and C…
baktun14 Jan 25, 2025
88bf8ab
chore: add detailed documentation to provider snapshot storage schema
baktun14 Jan 25, 2025
8c62d20
chore: add detailed documentation to address reference schema
baktun14 Jan 27, 2025
f1a1e0d
chore: add detailed documentation to block schema
baktun14 Jan 27, 2025
2d4f0d7
chore: add detailed documentation to day schema
baktun14 Jan 27, 2025
7405fe8
chore: add detailed documentation to message schema
baktun14 Jan 27, 2025
b204711
chore: add detailed documentation to monitored value schema
baktun14 Jan 27, 2025
f06f90f
chore: add detailed documentation to transaction schema
baktun14 Jan 27, 2025
d9eeea0
chore: add detailed documentation to validator schema
baktun14 Jan 27, 2025
b0411e9
chore: add detailed documentation to template schema
baktun14 Jan 27, 2025
a29795d
chore: add detailed documentation to template favorite schema
baktun14 Jan 27, 2025
39d2d6a
chore: add detailed documentation to user setting schema
baktun14 Jan 27, 2025
7de9c4b
chore: add detailed documentation to Akash block schema
baktun14 Jan 28, 2025
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
139 changes: 138 additions & 1 deletion doc/Example_Queries.md
Original file line number Diff line number Diff line change
@@ -179,4 +179,141 @@ INNER JOIN "deployment" ON "deployment".id = "message"."relatedDeploymentId"
WHERE "owner" = '<AKASH_ADDRESS>' AND "dseq"='<DSEQ>'
ORDER BY "height" DESC
```
![Get all messages related to a deployment](./get-all-messages-related-to-a-deployment.png)
![Get all messages related to a deployment](./get-all-messages-related-to-a-deployment.png)

## Get the total amount of total leases, akt spent, usdc spent and usd spent per address sorted by total leases

You can also filter for only gpu leases by adding `WHERE l."gpuUnits" > 0` to the `active_lease` query

```
WITH current_block AS (
SELECT MAX(height) as height
FROM block
),
active_leases AS (
SELECT
l.id,
l.owner,
l.denom,
l.price,
l."createdHeight",
LEAST((SELECT height FROM current_block), COALESCE(l."closedHeight" ,l."predictedClosedHeight")) as end_height,
d."aktPrice"
FROM lease l
INNER JOIN block b ON b.height = l."createdHeight"
INNER JOIN day d ON d.id = b."dayId"
),
lease_costs AS (
SELECT
owner,
ROUND(CAST(SUM(CASE
WHEN denom = 'uakt'
THEN (end_height - "createdHeight") * price / 1000000.0
ELSE 0
END) as numeric), 2) as total_akt_spent,
ROUND(CAST(SUM(CASE
WHEN denom = 'uusdc'
THEN (end_height - "createdHeight") * price / 1000000.0
ELSE 0
END) as numeric), 2) as total_usdc_spent,
ROUND(CAST(SUM(CASE
WHEN denom = 'uakt'
THEN (end_height - "createdHeight") * price * "aktPrice" / 1000000.0
WHEN denom = 'uusdc'
THEN (end_height - "createdHeight") * price / 1000000.0
ELSE 0
END) as numeric), 2) as total_usd_spent
FROM active_leases
GROUP BY owner
)
SELECT
al.owner,
COUNT(DISTINCT al.id) as active_lease_count,
COALESCE(lc.total_akt_spent, 0.00) as total_akt_spent,
COALESCE(lc.total_usdc_spent, 0.00) as total_usdc_spent,
COALESCE(lc.total_usd_spent, 0.00) as total_usd_spent
FROM active_leases al
LEFT JOIN lease_costs lc ON lc.owner = al.owner
GROUP BY
al.owner,
lc.total_akt_spent,
lc.total_usdc_spent,
lc.total_usd_spent
ORDER BY active_lease_count DESC;
```

## Cross database queries from chain-db (indexer) and user db

User db stores the addresses of the managed wallet users and if we want to query the indexer db to compute amount spent, we need to do a cross database query.

This query will fetch the sum of all spent for all the users per day.

```
-- First, enable postgres_fdw extension in both databases
CREATE EXTENSION postgres_fdw;

-- In the user db database, create the foreign server connection to the chain database
CREATE SERVER chain_db
FOREIGN DATA WRAPPER postgres_fdw
OPTIONS (host 'localhost', port '5432', dbname 'console-akash');

-- Create user mapping
CREATE USER MAPPING FOR CURRENT_USER
SERVER chain_db
OPTIONS (user 'postgres', password 'your_password');

IMPORT FOREIGN SCHEMA public
LIMIT TO (lease, block, day)
FROM SERVER chain_db
INTO public;

-- Create foreign tables for the tables we need
CREATE FOREIGN TABLE chain_lease (
id uuid,
owner character varying(255),
denom character varying(255),
price double precision,
"createdHeight" integer,
"closedHeight" integer,
"predictedClosedHeight" numeric(30,0)
) SERVER chain_db
OPTIONS (schema_name 'public', table_name 'lease');

CREATE FOREIGN TABLE chain_block (
height integer,
datetime timestamp with time zone,
"dayId" uuid
) SERVER chain_db
OPTIONS (schema_name 'public', table_name 'block');

CREATE FOREIGN TABLE chain_day (
id uuid,
date timestamp with time zone,
"aktPrice" double precision,
"firstBlockHeight" integer,
"lastBlockHeight" integer,
"lastBlockHeightYet" integer
) SERVER chain_db
OPTIONS (schema_name 'public', table_name 'day');

-- Query the amount spent per day for all the trial or non-trial users, just change w.trial = true or false
WITH daily_leases AS (
SELECT
d.date,
l.id,
((LEAST(d."lastBlockHeightYet", COALESCE(l."closedHeight", l."predictedClosedHeight")) - GREATEST(d."firstBlockHeight", l."createdHeight")) * l.price) AS "uusdc_spent"
FROM chain_day d
INNER JOIN chain_lease l ON l."createdHeight" < d."lastBlockHeightYet" AND COALESCE(l."closedHeight", l."predictedClosedHeight") > d."firstBlockHeight"
INNER JOIN user_wallets w ON w.address = l.owner AND w.trial = true
WHERE l.denom='uusdc'
)
SELECT
date AS "Date",
COUNT(l.id) AS "Lease Count",
ROUND(SUM(l.uusdc_spent)::decimal / 1000000, 2) AS "USDC Spent",
ROUND(SUM(SUM(l.uusdc_spent)::decimal) OVER (ORDER BY date) / 1000000, 2) AS "Cummulative USDC Spent"
FROM daily_leases l
GROUP BY date
ORDER BY date DESC

```
41 changes: 41 additions & 0 deletions packages/database/dbSchemas/akash/akashBlock.ts
Original file line number Diff line number Diff line change
@@ -4,20 +4,61 @@ import { Column, Table } from "sequelize-typescript";
import { Block } from "../base";
import { tableConfig } from "../base/block";

/**
* Custom Block model for Akash
*
* This model extends the base Block model and adds additional columns for Akash specific metrics updated by the indexer for every block.
* It makes it easier to query for Akash specific metrics with the most precision.
*/
@Table({
...tableConfig,
indexes: [...tableConfig.indexes, { name: "block_totaluusdspent_is_null", unique: false, fields: ["height"], where: { totalUUsdSpent: null } }]
})
export class AkashBlock extends Block {
/**
* Total amount of AKT spent at current block height in uakt
*/
@Column(DataTypes.DOUBLE) totalUAktSpent?: number;
/**
* Total amount of USDC spent at current block height in uusdc
*/
@Column(DataTypes.DOUBLE) totalUUsdcSpent?: number;
/**
* Total amount of USD spent at current block height in usd
*/
@Column(DataTypes.DOUBLE) totalUUsdSpent?: number;
/**
* Total amount of active leases at current block height
*/
@Column activeLeaseCount?: number;
/**
* Total amount of leases at current block height
*/
@Column totalLeaseCount?: number;
/**
* Total amount of active CPU in thousandths of a CPU at current block height
* 1 CPU = 1000 thousandths of a CPU
*/
@Column activeCPU?: number;
/**
* Total amount of active GPU at current block height
* 1 GPU = 1 unit of a GPU
*/
@Column activeGPU?: number;
/**
* Total amount of active memory at current block height in bytes
*/
@Column(DataTypes.BIGINT) activeMemory?: number;
/**
* Total amount of active ephemeral storage at current block height in bytes
*/
@Column(DataTypes.BIGINT) activeEphemeralStorage?: number;
/**
* Total amount of active persistent storage at current block height in bytes
*/
@Column(DataTypes.BIGINT) activePersistentStorage?: number;
/**
* Total amount of active providers at current block height
*/
@Column activeProviderCount?: number;
}
8 changes: 8 additions & 0 deletions packages/database/dbSchemas/akash/akashMessage.ts
Original file line number Diff line number Diff line change
@@ -4,10 +4,18 @@ import { Column, Table } from "sequelize-typescript";
import { Message } from "../base";
import { tableConfig } from "../base/message";

/**
* Custom Message model for Akash
*
* This model extends the base Message model and adds additional columns for Akash specific metrics
*/
@Table({
...tableConfig,
indexes: [...tableConfig.indexes, { unique: false, fields: ["relatedDeploymentId"] }]
})
export class AkashMessage extends Message {
/**
* The ID of the deployment that this message is related to
*/
@Column(DataTypes.UUID) relatedDeploymentId?: string;
}
27 changes: 27 additions & 0 deletions packages/database/dbSchemas/akash/bid.ts
Original file line number Diff line number Diff line change
@@ -3,16 +3,43 @@ import { Column, Model, Table } from "sequelize-typescript";

import { Required } from "../decorators/requiredDecorator";

/**
* Bid model for Akash
*
* Bids are created when a provider makes a bid for a deployment. (MsgCreateBid)
* When a bid is accepted by the deployment owner, a lease is created with the same dseq, gseq, oseq, and provider.
*/
@Table({
modelName: "bid",
indexes: [{ unique: false, fields: ["owner", "dseq", "gseq", "oseq", "provider"] }]
})
export class Bid extends Model {
/**
* The owner of the deployment that this bid is for
*/
@Required @Column owner: string;
/**
* The dseq of the deployment that this bid is for
*/
@Required @Column dseq: string;
/**
* The gseq of the deployment that this bid is for
*/
@Required @Column gseq: number;
/**
* The oseq of the deployment that this bid is for
*/
@Required @Column oseq: number;
/**
* The provider address that made the bid
*/
@Required @Column provider: string;
/**
* The price of the bid in uakt per block
*/
@Required @Column(DataTypes.DOUBLE) price: number;
/**
* The block height at which the bid was created (MsgCreateBid)
*/
@Required @Column createdHeight: number;
}
62 changes: 61 additions & 1 deletion packages/database/dbSchemas/akash/deployment.ts
Original file line number Diff line number Diff line change
@@ -6,6 +6,12 @@ import { Required } from "../decorators/requiredDecorator";
import { DeploymentGroup } from "./deploymentGroup";
import { Lease } from "./lease";

/**
* Deployment model for Akash
*
* Deployments are created when a user creates a deployment on the blockchain. (MsgCreateDeployment)
* They are used to track the state of a deployment and the associated leases.
*/
@Table({
modelName: "deployment",
indexes: [
@@ -18,20 +24,74 @@ import { Lease } from "./lease";
]
})
export class Deployment extends Model {
/**
* The unique identifier for the database deployment
*/
@Required @PrimaryKey @Default(UUIDV4) @Column(DataTypes.UUID) id: string;
/**
* Address of the wallet that owns this deployment
*/
@Required @Column owner: string;
/**
* The dseq of the deployment (unique identifier for the deployment on the blockchain)
* It can be any string, but ususally it's the block height at which the deployment was created.
* Unique Identifier: DSEQ is a unique identifier assigned to each deployment on the Akash Network, enabling precise tracking and management of deployments
* Order Sequence Number (OSEQ): DSEQ is associated with an Order Sequence Number (OSEQ), which indicates the order in which deployments are created and managed within the network
* Deployment Management: DSEQ facilitates the management of deployments by providing a specific reference point for each deployment instance, ensuring clarity and organization in the deployment process
* Lease Creation: When creating a lease with a provider on the Akash Network, DSEQ is a key parameter used to establish the terms of the lease and finalize the deployment process
* Deployment Status: DSEQ allows users to check the status of their deployments, access application endpoints, and monitor the progress of container image pulling and container startup
*/
@Required @Column dseq: string;
/**
* The block height at which the deployment was created (MsgCreateDeployment)
*/
@Required @Column createdHeight: number;
/**
* The balance of the deployment in the denom specified in the denom column
* Remaining balance based on deposits and MsgWithdrawLease
*/
@Required @Column(DataTypes.DOUBLE) balance: number;
/**
* The deposit of the deployment in the denom specified in the denom column
* Deposited amount based on MsgCreateDeployment and MsgDepositDeployment
*/
@Required @Column(DataTypes.BIGINT) deposit: number;
/**
* The denom of the deployment
* This can be uakt or uusdc
*/
@Required @Column denom: string;
/**
* Last block height where an account settlement occurred. This happens on create, withdraw and close.
* This is used to calculate the predicted closed height of the deployment and account settlement.
*/
@Column lastWithdrawHeight?: number;
/**
* Withdrawn amount as of now. Updated on account settlement (create lease MsgCreateLease, withdraw lease MsgWithdrawLease, close lease MsgCloseLease).
*/
@Required @Column(DataTypes.DOUBLE) withdrawnAmount!: number;
/**
* Block height the deployment got closed on-chain. Can happen from MsgCloseDeployment or as a side-effect through transaction events of having no active leases remaining.
*/
@Column closedHeight?: number;

/**
* The block at which the deployment was created
*/
@BelongsTo(() => Block, "createdHeight") createdBlock: Block;
/**
* The block at which the deployment was closed
*/
@BelongsTo(() => Block, "closedHeight") closedBlock: Block;
/**
* The deployment groups associated with the deployment
*/
@HasMany(() => DeploymentGroup, "deploymentId") deploymentGroups: DeploymentGroup[];
/**
* The leases associated with the deployment
*/
@HasMany(() => Lease, "deploymentId") leases: Lease[];
/**
* The messages associated with the deployment
*/
@HasMany(() => Message, { foreignKey: "relatedDeploymentId", constraints: false }) relatedMessages: Message[];
}
Loading