From 46f25573422f999704e880d793c4bc66b0df14cd Mon Sep 17 00:00:00 2001 From: Juanma Hidalgo Date: Thu, 12 Dec 2024 11:18:49 +0100 Subject: [PATCH] feat: introduce the LAND queries --- src/ports/db/component.ts | 2 +- src/ports/nfts/landQueries.ts | 166 ++++++++++++++++++++++++++++++++++ src/ports/nfts/queries.ts | 7 +- src/ports/nfts/utils.ts | 2 +- 4 files changed, 173 insertions(+), 4 deletions(-) create mode 100644 src/ports/nfts/landQueries.ts diff --git a/src/ports/db/component.ts b/src/ports/db/component.ts index b1c21e8..f85a143 100644 --- a/src/ports/db/component.ts +++ b/src/ports/db/component.ts @@ -29,7 +29,7 @@ export async function createPgComponent( ...options, pool: { connectionString: databaseUrl, - query_timeout: 120000 + query_timeout: 40000 // 40 seconds }, ...(migrations ? { diff --git a/src/ports/nfts/landQueries.ts b/src/ports/nfts/landQueries.ts new file mode 100644 index 0000000..a6e5487 --- /dev/null +++ b/src/ports/nfts/landQueries.ts @@ -0,0 +1,166 @@ +import SQL, { SQLStatement } from 'sql-template-strings' +import { NFTSortBy } from '@dcl/schemas' +import { getWhereStatementFromFilters } from '../utils' +import { getNFTLimitAndOffsetStatement, getTradesCTE } from './queries' +import { GetNFTsFilters } from './types' + +export function getLandNFTsSortBy(sortBy?: NFTSortBy) { + switch (sortBy) { + case NFTSortBy.NAME: + return SQL` ORDER BY name ASC ` + case NFTSortBy.NEWEST: + return SQL` ORDER BY created_at DESC ` + case NFTSortBy.CHEAPEST: + return SQL` ORDER BY coalesce(nft.search_order_price, (trades.assets -> 'received' ->> 'amount')::numeric(78)) ASC ` + case NFTSortBy.RECENTLY_SOLD: + return SQL` ORDER BY sold_at DESC ` + default: + return SQL` ORDER BY created_at DESC` + } +} + +function getLANDWhereStatement(nftFilters: GetNFTsFilters): SQLStatement { + if (!nftFilters) { + return SQL`` + } + + // Keep only filters that need JOINed tables + const FILTER_BY_OWNER = nftFilters.owner + ? SQL` nft.owner_id IN (SELECT id FROM squid_marketplace.account WHERE address = ${nftFilters.owner.toLocaleLowerCase()}) ` + : null + const FILTER_MIN_ESTATE_SIZE = nftFilters.minEstateSize + ? SQL` estate.size >= ${nftFilters.minEstateSize} ` + : SQL` (estate.size IS NULL OR estate.size > 0) ` + const FILTER_MAX_ESTATE_SIZE = nftFilters.maxEstateSize ? SQL` estate.size <= ${nftFilters.maxEstateSize} ` : null + const FILTER_BY_MIN_PRICE = nftFilters.minPrice + ? SQL` (nft.search_order_price >= ${nftFilters.minPrice} OR (trades.assets -> 'received' ->> 'amount')::numeric(78) >= ${nftFilters.minPrice})` + : null + const FILTER_BY_MAX_PRICE = nftFilters.maxPrice + ? SQL` (nft.search_order_price <= ${nftFilters.maxPrice} OR (trades.assets -> 'received' ->> 'amount')::numeric(78) <= ${nftFilters.maxPrice})` + : null + const FILTER_BY_ON_SALE = nftFilters.isOnSale ? SQL` (trades.id IS NOT NULL OR orders.nft_id IS NOT NULL)` : null + + return getWhereStatementFromFilters([ + FILTER_BY_OWNER, + FILTER_MIN_ESTATE_SIZE, + FILTER_MAX_ESTATE_SIZE, + FILTER_BY_MIN_PRICE, + FILTER_BY_MAX_PRICE, + FILTER_BY_ON_SALE + ]) +} + +export function getLANDs(nftFilters: GetNFTsFilters): SQLStatement { + const { sortBy, isOnSale, ids } = nftFilters + return SQL` + WITH filtered_land_nfts AS ( + SELECT * + FROM squid_marketplace.nft + WHERE search_is_land = true ` + .append(ids ? SQL` AND id = ANY(${ids}) ` : SQL``) + .append( + SQL` + ORDER BY created_at + ), + filtered_estate AS ( + SELECT + est.id, + est.token_id, + est.size, + est.data_id, + array_agg(json_build_object('x', est_parcel.x, 'y', est_parcel.y)) AS estate_parcels + FROM + squid_marketplace.estate est + LEFT JOIN squid_marketplace.parcel est_parcel ON est.id = est_parcel.estate_id + GROUP BY + est.id, + est.token_id, + est.size, + est.data_id + ), + parcel_estate_data AS ( + SELECT + par.*, + par_est.token_id AS parcel_estate_token_id, + est_data.name AS parcel_estate_name + FROM + squid_marketplace.parcel par + LEFT JOIN squid_marketplace.estate par_est ON par.estate_id = par_est.id + LEFT JOIN squid_marketplace.data est_data ON par_est.data_id = est_data.id + ) + ` + .append(getTradesCTE(nftFilters)) + .append( + SQL` + ` + ) + .append( + isOnSale + ? SQL` + , valid_orders AS ( + SELECT + o.nft_id, + o.status, + o.expires_normalized + FROM + squid_marketplace.order o + WHERE + o.status = 'open' + AND o.expires_normalized > now() + )` + : SQL`` + ) + .append( + SQL` + SELECT + count(*) OVER () AS count, + nft.id, + nft.contract_address, + nft.token_id, + nft.network, + nft.created_at, + nft.token_uri AS url, + nft.updated_at, + nft.sold_at, + nft.urn, + coalesce(nft.search_order_price, (trades.assets -> 'received' ->> 'amount')::numeric(78)) AS price, + nft.owner_id, + nft.image, + nft.issued_id, + -- item.blockchain_id AS item_id, + nft.category, + nft.name, + parcel.x, + parcel.y, + nft.item_type, + estate.estate_parcels, + estate.size AS size, + parcel.parcel_estate_token_id, + parcel.parcel_estate_name, + parcel.estate_id AS parcel_estate_id, + -- COALESCE( + -- wearable.description, + -- emote.description, + -- land_data.description + -- ) AS description, + coalesce (to_timestamp(nft.search_order_created_at), trades.created_at) as order_created_at + FROM + filtered_land_nfts nft + LEFT JOIN parcel_estate_data parcel ON nft.id = parcel.id + LEFT JOIN filtered_estate estate ON nft.id = estate.id + -- LEFT JOIN squid_marketplace.data land_data ON ( + -- estate.data_id = land_data.id OR parcel.id = land_data.id + -- ) + LEFT JOIN trades ON (trades.assets -> 'sent' ->> 'token_id')::numeric = nft.token_id + AND trades.assets -> 'sent' ->> 'contract_address' = nft.contract_address + AND trades.status = 'open' + -- AND trades.signer = account.address + ` + .append(isOnSale ? SQL`LEFT JOIN valid_orders orders ON orders.nft_id = nft.id` : SQL``) + .append(getLANDWhereStatement(nftFilters)) + .append(getLandNFTsSortBy(sortBy)) + .append(getNFTLimitAndOffsetStatement(nftFilters)).append(SQL`; + `) + ) + ) +} diff --git a/src/ports/nfts/queries.ts b/src/ports/nfts/queries.ts index c7a3b1a..7cc6095 100644 --- a/src/ports/nfts/queries.ts +++ b/src/ports/nfts/queries.ts @@ -4,6 +4,7 @@ import { getDBNetworks } from '../../utils' import { MAX_ORDER_TIMESTAMP } from '../catalog/queries' import { ItemType } from '../items' import { getWhereStatementFromFilters } from '../utils' +import { getLANDs } from './landQueries' import { GetNFTsFilters } from './types' function getEmotePlayModeWhereStatement(emotePlayMode: EmotePlayMode | EmotePlayMode[] | undefined): SQLStatement | null { @@ -168,7 +169,7 @@ function getParcelEstateDataCTE(filters: GetNFTsFilters): SQLStatement { `) } -function getTradesCTE(filters: GetNFTsFilters): SQLStatement { +export function getTradesCTE(filters: GetNFTsFilters): SQLStatement { return SQL` , trades AS ( SELECT @@ -244,7 +245,7 @@ function getTradesCTE(filters: GetNFTsFilters): SQLStatement { `) } -function getNFTLimitAndOffsetStatement(nftFilters?: GetNFTsFilters) { +export function getNFTLimitAndOffsetStatement(nftFilters?: GetNFTsFilters) { const limit = nftFilters?.first ? nftFilters.first : 100 const offset = nftFilters?.skip ? nftFilters.skip : 0 @@ -283,6 +284,8 @@ export function getNFTsQuery(nftFilters: GetNFTsFilters = {}, uncapped = false): // The Recently Listed sort by is handled by a different CTE because it needs to join with the trades table if (nftFilters.sortBy === NFTSortBy.RECENTLY_LISTED) { return getRecentlyListedNFTsCTE(nftFilters) + } else if (nftFilters.isLand) { + return getLANDs(nftFilters) } return getFilteredNFTCTE(nftFilters, uncapped) diff --git a/src/ports/nfts/utils.ts b/src/ports/nfts/utils.ts index 177cf62..13cedc6 100644 --- a/src/ports/nfts/utils.ts +++ b/src/ports/nfts/utils.ts @@ -30,7 +30,7 @@ export async function getNFTFilters(filters: NFTFilters, listsServer: string, re // TODO: check filter by owner if (shouldFetchRentalListings) { - const listings = await rentals.getRentalsListings(filters) + const listings = await rentals.getRentalsListings({ ...filters, first: 1000 }) // TODO: workdaround for the time being since we need all ids with rentals filters.ids = listings.data.results.map(rentalListing => rentalListing.nftId) }