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

New CRT marketplace query #336

Merged
merged 32 commits into from
Jul 19, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
32 commits
Select commit Hold shift + click to select a range
83c7b4d
New query
ikprk Jun 11, 2024
242e152
New query for top selling channels
ikprk Jun 12, 2024
4282269
Add materialized view into view migrations
ikprk Jun 14, 2024
81f2de7
Fix build
ikprk Jun 14, 2024
9fdefbd
Add new migration
ikprk Jun 15, 2024
8182516
Adjust migration and resolver
ikprk Jun 17, 2024
a631bb6
Small fixes
ikprk Jun 18, 2024
ef7855e
Make creator token just a view
ikprk Jun 25, 2024
7a0e604
Fix divison by zero
ikprk Jun 25, 2024
73847b0
Correct hot and cold tokens
ikprk Jun 25, 2024
1c4a6a9
Make field more generic and increase the period
ikprk Jun 27, 2024
69a3d6b
Major view query rework
ikprk Jun 28, 2024
f7ba521
Make initial price on amm start correct
ikprk Jun 28, 2024
6295379
Rework resolver extensions
ikprk Jun 28, 2024
69076f8
Add new db table
ikprk Jul 2, 2024
5be4304
Add new handler for the auth server to record interactions
ikprk Jul 2, 2024
c353aaa
Add resolver to get most interacted entities for given type
ikprk Jul 4, 2024
cd15a64
Introduce limiting for custom resolvers
ikprk Jul 7, 2024
0dae177
Fix token price change resolver
ikprk Jul 9, 2024
9f345b1
Fix marketplace token view definition
ikprk Jul 9, 2024
e13c03f
Introduce user based rate limiting per type and entity
ikprk Jul 9, 2024
c74b8d2
CR fixes
ikprk Jul 15, 2024
7058eda
Add tests for user interactions endpoint
ikprk Jul 15, 2024
784b4c2
Fix build
ikprk Jul 16, 2024
c49ecb7
Fix resolver for most interacted entity
ikprk Jul 16, 2024
732ddc2
fix: db views generation
zeeshanakram3 Jul 16, 2024
bb426a5
debug log
zeeshanakram3 Jul 16, 2024
ea47d61
Merge remote-tracking branch 'upstream/master' into pr/ikprk/336
zeeshanakram3 Jul 16, 2024
8b0636a
undo: debug log
zeeshanakram3 Jul 16, 2024
b29d5c1
regenerate auth api docs
zeeshanakram3 Jul 19, 2024
81fbc60
change view name from 'marketplace_tokens' to 'marketplace_token'
zeeshanakram3 Jul 19, 2024
425f784
fix: lint issue
zeeshanakram3 Jul 19, 2024
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
7 changes: 7 additions & 0 deletions db/generateViewsMigration.js
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,13 @@ module.exports = class ${className} {
name = '${className}'
async up(db) {
// these two queries will be invoked and the cleaned up by the squid itself
// we only do this to be able to reference processor height in mappings
await db.query(\`CREATE SCHEMA IF NOT EXISTS squid_processor;\`)
await db.query(\`CREATE TABLE IF NOT EXISTS squid_processor.status (
id SERIAL PRIMARY KEY,
height INT
);\`)
const viewDefinitions = getViewDefinitions(db);
for (const [tableName, viewConditions] of Object.entries(viewDefinitions)) {
if (Array.isArray(viewConditions)) {
Expand Down
19 changes: 19 additions & 0 deletions db/migrations/1721141313646-Data.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
module.exports = class Data1721141313646 {
name = 'Data1721141313646'

async up(db) {
await db.query(`CREATE TABLE "admin"."user_interaction_count" ("id" character varying NOT NULL, "type" text, "entity_id" text, "day_timestamp" TIMESTAMP WITH TIME ZONE NOT NULL, "count" integer NOT NULL, CONSTRAINT "PK_8e334a51febcf02c54dff48147d" PRIMARY KEY ("id"))`)
await db.query(`CREATE INDEX "IDX_b5261af5f3fe48d77086ebc602" ON "admin"."user_interaction_count" ("day_timestamp") `)
await db.query(`CREATE TABLE "admin"."marketplace_token" ("liquidity" integer, "market_cap" numeric, "cumulative_revenue" numeric, "amm_volume" numeric, "price_change" numeric, "liquidity_change" numeric, "id" character varying NOT NULL, "status" character varying(6) NOT NULL, "avatar" jsonb, "total_supply" numeric NOT NULL, "is_featured" boolean NOT NULL, "symbol" text, "is_invite_only" boolean NOT NULL, "annual_creator_reward_permill" integer NOT NULL, "revenue_share_ratio_permill" integer NOT NULL, "created_at" TIMESTAMP WITH TIME ZONE NOT NULL, "channel_id" text, "description" text, "whitelist_applicant_note" text, "whitelist_applicant_link" text, "accounts_num" integer NOT NULL, "number_of_revenue_share_activations" integer NOT NULL, "deissued" boolean NOT NULL, "current_amm_sale_id" text, "current_sale_id" text, "current_revenue_share_id" text, "number_of_vested_transfer_issued" integer NOT NULL, "last_price" numeric, CONSTRAINT "PK_d836a8c3d907b67099c140c4d84" PRIMARY KEY ("id"))`)
await db.query(`CREATE INDEX "IDX_1268fd020cf195b2e8d5d85093" ON "admin"."marketplace_token" ("symbol") `)
await db.query(`CREATE INDEX "IDX_b99bb1ecee77f23016f6ef687c" ON "admin"."marketplace_token" ("created_at") `)
}

async down(db) {
await db.query(`DROP TABLE "admin"."user_interaction_count"`)
await db.query(`DROP INDEX "admin"."IDX_b5261af5f3fe48d77086ebc602"`)
await db.query(`DROP TABLE "admin"."marketplace_token"`)
await db.query(`DROP INDEX "admin"."IDX_1268fd020cf195b2e8d5d85093"`)
await db.query(`DROP INDEX "admin"."IDX_b99bb1ecee77f23016f6ef687c"`)
}
}
Original file line number Diff line number Diff line change
@@ -1,10 +1,17 @@

const { getViewDefinitions } = require('../viewDefinitions')

module.exports = class Views1720623003800 {
name = 'Views1720623003800'
module.exports = class Views1721141313757 {
name = 'Views1721141313757'

async up(db) {
// these two queries will be invoked and the cleaned up by the squid itself
// we only do this to be able to reference processor height in mappings
await db.query(`CREATE SCHEMA IF NOT EXISTS squid_processor;`)
await db.query(`CREATE TABLE IF NOT EXISTS squid_processor.status (
id SERIAL PRIMARY KEY,
height INT
);`)
const viewDefinitions = getViewDefinitions(db);
for (const [tableName, viewConditions] of Object.entries(viewDefinitions)) {
if (Array.isArray(viewConditions)) {
Expand Down
98 changes: 98 additions & 0 deletions db/viewDefinitions.js
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,8 @@ const noCategoryVideosSupportedByDefault =
process.env.SUPPORT_NO_CATEGORY_VIDEOS === 'true' ||
process.env.SUPPORT_NO_CATEGORY_VIDEOS === '1'

const BLOCKS_PER_DAY = 10 * 60 * 24 // 10 blocs per minute, 60 mins * 24 hours

// Add public 'VIEW' definitions for hidden entities created by
// applying `@schema(name: "admin") directive to the Graphql entities
function getViewDefinitions(db) {
Expand Down Expand Up @@ -87,6 +89,102 @@ function getViewDefinitions(db) {
email_delivery_attempt: ['FALSE'],
// TODO (notifications v2): make this part of the admin schema with appropriate resolver for queries
// notification: ['FALSE'],
marketplace_token: `
WITH trading_volumes AS
(SELECT ac.token_id,
SUM(tr.price_paid) as amm_volume
FROM amm_transaction tr
JOIN amm_curve ac ON ac.id = tr.amm_id
GROUP BY token_id),

base_price_transaction AS (
WITH oldest_transactions AS (
SELECT DISTINCT ON (ac.token_id)
tr.amm_id,
ac.token_id,
tr.price_per_unit AS oldest_price_paid,
tr.created_in
FROM amm_transaction tr
JOIN amm_curve ac ON tr.amm_id = ac.id
WHERE tr.created_in < (SELECT height FROM squid_processor.status) - ${
BLOCKS_PER_DAY * 30
}
ORDER BY ac.token_id, tr.created_in DESC
),
fallback_transactions AS (
SELECT DISTINCT ON (ac.token_id)
tr.amm_id,
ac.token_id,
tr.price_per_unit AS oldest_price_paid,
tr.created_in
FROM amm_transaction tr
JOIN amm_curve ac ON tr.amm_id = ac.id
WHERE tr.created_in > (SELECT height FROM squid_processor.status) - ${
BLOCKS_PER_DAY * 30
}
ORDER BY ac.token_id, tr.created_in ASC
)
SELECT * FROM oldest_transactions
UNION ALL
SELECT * FROM fallback_transactions
WHERE NOT EXISTS (SELECT 1 FROM oldest_transactions)
)

SELECT
COALESCE(ac.total_liq, 0) as liquidity,
COALESCE((ct.last_price * ct.total_supply), 0) as market_cap,
c.cumulative_revenue,
c.id as channel_id,
COALESCE(tv.amm_volume, 0) as amm_volume,
CASE
WHEN ldt_o.oldest_price_paid = 0
OR ldt_o.oldest_price_paid IS NULL THEN 0
ELSE ((ct.last_price - ldt_o.oldest_price_paid) * 100.0 / ldt_o.oldest_price_paid)
END AS price_change,
CASE
WHEN liq_until.quantity IS NULL THEN 0
ELSE ((ac.total_liq - liq_until.quantity) * 100 / GREATEST(liq_until.quantity, 1))
END as liquidity_change,
ct.*
FROM creator_token ct
LEFT JOIN token_channel tc ON tc.token_id = ct.id
LEFT JOIN channel c ON c.id = tc.channel_id
LEFT JOIN base_price_transaction ldt_o ON ldt_o.token_id = ct.id
LEFT JOIN

(SELECT token_id,
SUM(CASE
WHEN transaction_type = 'BUY' THEN quantity
ELSE quantity * -1
END) AS total_liq
FROM
(SELECT ac.token_id,
tr.transaction_type,
tr.quantity
FROM amm_transaction tr
JOIN amm_curve ac ON tr.amm_id = ac.id) as tr
GROUP BY token_id) as ac ON ac.token_id = ct.id

LEFT JOIN

(SELECT token_id,
SUM(CASE
WHEN transaction_type = 'BUY' THEN quantity
ELSE quantity * -1
END) AS quantity
FROM
(SELECT ac.token_id,
tr.transaction_type,
tr.quantity
FROM amm_transaction tr
JOIN amm_curve ac ON tr.amm_id = ac.id
WHERE tr.created_in <
(SELECT height
FROM squid_processor.status) - ${BLOCKS_PER_DAY * 30}) as tr
GROUP BY token_id) as liq_until ON liq_until.token_id = ct.id

LEFT JOIN trading_volumes tv ON tv.token_id = ct.id
`,
}
}

Expand Down
74 changes: 74 additions & 0 deletions package-lock.json

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

2 changes: 2 additions & 0 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -57,6 +57,7 @@
"@polkadot/util-crypto": "9.5.1",
"@sendgrid/mail": "^7.7.0",
"@subsquid/archive-registry": "^2.1.0",
"@subsquid/big-decimal": "^0.0.0",
"@subsquid/graphql-server": "3.3.2",
"@subsquid/ss58": "^0.1.3",
"@subsquid/substrate-processor": "^2.2.0",
Expand Down Expand Up @@ -87,6 +88,7 @@
"p-limit": "3.1.0",
"patch-package": "^6.5.0",
"pg": "8.8.0",
"rolling-rate-limiter": "^0.4.2",
"swagger-ui-express": "^4.6.2",
"type-graphql": "^1.2.0-rc.1",
"typeorm": "^0.3.11",
Expand Down
17 changes: 17 additions & 0 deletions schema/events.graphql
Original file line number Diff line number Diff line change
Expand Up @@ -505,3 +505,20 @@ type CreatorTokenRevenueSplitIssuedEventData {
"Details of the revenue split"
revenueShare: RevenueShare
}

type UserInteractionCount @entity @schema(name: "admin") {
"Autoincremented ID"
id: ID!

"Type of the user interaction eg. 'tokenMarketplaceEntry'"
type: String

"ID of the entity that the event is related to for 'tokenMarketplaceEntry' it would be token ID"
entityId: String

"Timestamp of the day that is used to count the interactions"
dayTimestamp: DateTime! @index

"Count of the interactions"
count: Int!
}
Loading
Loading