Skip to content

Commit

Permalink
fix: optimize base inscriptions query (#364)
Browse files Browse the repository at this point in the history
* fix: restructure query

* fix: turn off block hash and output for now
  • Loading branch information
rafaelcr committed Jun 16, 2024
1 parent 46f0633 commit cbcc830
Show file tree
Hide file tree
Showing 2 changed files with 129 additions and 124 deletions.
249 changes: 127 additions & 122 deletions src/pg/pg-store.ts
Original file line number Diff line number Diff line change
Expand Up @@ -496,136 +496,141 @@ export class PgStore extends BasePgStore {
orderBy = sql`ARRAY_POSITION(ARRAY['common','uncommon','rare','epic','legendary','mythic'], s.rarity) ${order}, i.number DESC`;
break;
}
// This function will generate a query to be used for getting results or total counts.
const query = (
columns: postgres.PendingQuery<postgres.Row[]>,
sorting: postgres.PendingQuery<postgres.Row[]>
) => sql`
SELECT ${columns}
FROM inscriptions AS i
INNER JOIN current_locations AS cur ON cur.ordinal_number = i.ordinal_number
INNER JOIN locations AS cur_l ON cur_l.ordinal_number = cur.ordinal_number AND cur_l.block_height = cur.block_height AND cur_l.tx_index = cur.tx_index
INNER JOIN locations AS gen_l ON gen_l.ordinal_number = i.ordinal_number AND gen_l.block_height = i.block_height AND gen_l.tx_index = i.tx_index
INNER JOIN satoshis AS s ON s.ordinal_number = i.ordinal_number
WHERE TRUE
${
filters?.genesis_id?.length
? sql`AND i.genesis_id IN ${sql(filters.genesis_id)}`
: sql``
}
${
filters?.genesis_block_height
? sql`AND i.block_height = ${filters.genesis_block_height}`
: sql``
}
${
filters?.genesis_block_hash
? sql`AND gen_l.block_hash = ${filters.genesis_block_hash}`
: sql``
}
${
filters?.from_genesis_block_height
? sql`AND i.block_height >= ${filters.from_genesis_block_height}`
: sql``
}
${
filters?.to_genesis_block_height
? sql`AND i.block_height <= ${filters.to_genesis_block_height}`
: sql``
}
${
filters?.from_sat_coinbase_height
? sql`AND s.coinbase_height >= ${filters.from_sat_coinbase_height}`
: sql``
}
${
filters?.to_sat_coinbase_height
? sql`AND s.coinbase_height <= ${filters.to_sat_coinbase_height}`
: sql``
}
${
filters?.from_genesis_timestamp
? sql`AND i.timestamp >= to_timestamp(${filters.from_genesis_timestamp})`
: sql``
}
${
filters?.to_genesis_timestamp
? sql`AND i.timestamp <= to_timestamp(${filters.to_genesis_timestamp})`
: sql``
}
${
filters?.from_sat_ordinal
? sql`AND i.ordinal_number >= ${filters.from_sat_ordinal}`
: sql``
}
${
filters?.to_sat_ordinal ? sql`AND i.ordinal_number <= ${filters.to_sat_ordinal}` : sql``
}
${filters?.number?.length ? sql`AND i.number IN ${sql(filters.number)}` : sql``}
${
filters?.from_number !== undefined ? sql`AND i.number >= ${filters.from_number}` : sql``
}
${filters?.to_number !== undefined ? sql`AND i.number <= ${filters.to_number}` : sql``}
${filters?.address?.length ? sql`AND cur.address IN ${sql(filters.address)}` : sql``}
${filters?.mime_type?.length ? sql`AND i.mime_type IN ${sql(filters.mime_type)}` : sql``}
${filters?.output ? sql`AND cur_l.output = ${filters.output}` : sql``}
${filters?.sat_rarity?.length ? sql`AND s.rarity IN ${sql(filters.sat_rarity)}` : sql``}
${filters?.sat_ordinal ? sql`AND i.ordinal_number = ${filters.sat_ordinal}` : sql``}
${filters?.recursive !== undefined ? sql`AND i.recursive = ${filters.recursive}` : sql``}
${filters?.cursed === true ? sql`AND i.number < 0` : sql``}
${filters?.cursed === false ? sql`AND i.number >= 0` : sql``}
${
filters?.genesis_address?.length
? sql`AND i.address IN ${sql(filters.genesis_address)}`
: sql``
}
${sorting}
`;
const results = await sql<DbFullyLocatedInscriptionResult[]>`${query(
sql`
i.genesis_id,
i.number,
i.mime_type,
i.content_type,
i.content_length,
i.fee AS genesis_fee,
i.curse_type,
i.ordinal_number AS sat_ordinal,
i.parent,
i.metadata,
s.rarity AS sat_rarity,
s.coinbase_height AS sat_coinbase_height,
i.recursive,
(
SELECT STRING_AGG(ir.ref_genesis_id, ',')
FROM inscription_recursions AS ir
WHERE ir.genesis_id = i.genesis_id
) AS recursion_refs,
i.block_height AS genesis_block_height,
// Do we need a filtered `COUNT(*)`? If so, try to use the pre-calculated counts we have in
// cached tables to speed up these queries.
const countType = getIndexResultCountType(filters);
const total = await this.counts.fromResults(countType, filters);
const results = await sql<(DbFullyLocatedInscriptionResult & { total: number })[]>`
WITH results AS (
SELECT
i.genesis_id,
i.number,
i.mime_type,
i.content_type,
i.content_length,
i.fee AS genesis_fee,
i.curse_type,
i.ordinal_number AS sat_ordinal,
i.parent,
i.metadata,
s.rarity AS sat_rarity,
s.coinbase_height AS sat_coinbase_height,
i.recursive,
(
SELECT STRING_AGG(ir.ref_genesis_id, ',')
FROM inscription_recursions AS ir
WHERE ir.genesis_id = i.genesis_id
) AS recursion_refs,
i.block_height AS genesis_block_height,
i.tx_index AS genesis_tx_index,
i.timestamp AS genesis_timestamp,
i.address AS genesis_address,
cur.address,
cur.tx_index,
cur.block_height,
${total === undefined ? sql`COUNT(*) OVER() AS total` : sql`0 AS total`},
ROW_NUMBER() OVER(ORDER BY ${orderBy}) AS row_num
FROM inscriptions AS i
INNER JOIN current_locations AS cur ON cur.ordinal_number = i.ordinal_number
INNER JOIN satoshis AS s ON s.ordinal_number = i.ordinal_number
WHERE TRUE
${
filters?.genesis_id?.length
? sql`AND i.genesis_id IN ${sql(filters.genesis_id)}`
: sql``
}
${
filters?.genesis_block_height
? sql`AND i.block_height = ${filters.genesis_block_height}`
: sql``
}
${
/*filters?.genesis_block_hash
? sql`AND gen_l.block_hash = ${filters.genesis_block_hash}`
:*/ sql``
}
${
filters?.from_genesis_block_height
? sql`AND i.block_height >= ${filters.from_genesis_block_height}`
: sql``
}
${
filters?.to_genesis_block_height
? sql`AND i.block_height <= ${filters.to_genesis_block_height}`
: sql``
}
${
filters?.from_sat_coinbase_height
? sql`AND s.coinbase_height >= ${filters.from_sat_coinbase_height}`
: sql``
}
${
filters?.to_sat_coinbase_height
? sql`AND s.coinbase_height <= ${filters.to_sat_coinbase_height}`
: sql``
}
${
filters?.from_genesis_timestamp
? sql`AND i.timestamp >= to_timestamp(${filters.from_genesis_timestamp})`
: sql``
}
${
filters?.to_genesis_timestamp
? sql`AND i.timestamp <= to_timestamp(${filters.to_genesis_timestamp})`
: sql``
}
${
filters?.from_sat_ordinal
? sql`AND i.ordinal_number >= ${filters.from_sat_ordinal}`
: sql``
}
${
filters?.to_sat_ordinal
? sql`AND i.ordinal_number <= ${filters.to_sat_ordinal}`
: sql``
}
${filters?.number?.length ? sql`AND i.number IN ${sql(filters.number)}` : sql``}
${
filters?.from_number !== undefined
? sql`AND i.number >= ${filters.from_number}`
: sql``
}
${filters?.to_number !== undefined ? sql`AND i.number <= ${filters.to_number}` : sql``}
${filters?.address?.length ? sql`AND cur.address IN ${sql(filters.address)}` : sql``}
${
filters?.mime_type?.length ? sql`AND i.mime_type IN ${sql(filters.mime_type)}` : sql``
}
${/*filters?.output ? sql`AND cur_l.output = ${filters.output}` : */ sql``}
${filters?.sat_rarity?.length ? sql`AND s.rarity IN ${sql(filters.sat_rarity)}` : sql``}
${filters?.sat_ordinal ? sql`AND i.ordinal_number = ${filters.sat_ordinal}` : sql``}
${
filters?.recursive !== undefined ? sql`AND i.recursive = ${filters.recursive}` : sql``
}
${filters?.cursed === true ? sql`AND i.number < 0` : sql``}
${filters?.cursed === false ? sql`AND i.number >= 0` : sql``}
${
filters?.genesis_address?.length
? sql`AND i.address IN ${sql(filters.genesis_address)}`
: sql``
}
ORDER BY ${orderBy} LIMIT ${page.limit} OFFSET ${page.offset}
)
SELECT
r.*,
gen_l.block_hash AS genesis_block_hash,
gen_l.tx_id AS genesis_tx_id,
i.timestamp AS genesis_timestamp,
i.address AS genesis_address,
cur_l.tx_id,
cur.address,
cur_l.output,
cur_l.offset,
cur_l.timestamp,
cur_l.value
`,
sql`ORDER BY ${orderBy} LIMIT ${page.limit} OFFSET ${page.offset}`
)}`;
// Do we need a filtered `COUNT(*)`? If so, try to use the pre-calculated counts we have in
// cached tables to speed up these queries.
const countType = getIndexResultCountType(filters);
let total = await this.counts.fromResults(countType, filters);
if (total === undefined) {
// If the count is more complex, attempt it with a separate query.
const count = await sql<{ total: number }[]>`${query(sql`COUNT(*) AS total`, sql``)}`;
total = count[0].total;
}
FROM results AS r
INNER JOIN locations AS cur_l ON cur_l.ordinal_number = r.sat_ordinal AND cur_l.block_height = r.block_height AND cur_l.tx_index = r.tx_index
INNER JOIN locations AS gen_l ON gen_l.ordinal_number = r.sat_ordinal AND gen_l.block_height = r.genesis_block_height AND gen_l.tx_index = r.genesis_tx_index
ORDER BY r.row_num ASC
`;
return {
total,
total: total ?? results[0]?.total ?? 0,
results: results ?? [],
};
});
Expand Down
4 changes: 2 additions & 2 deletions tests/api/inscriptions.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -2318,7 +2318,7 @@ describe('/inscriptions', () => {
expect(responseJson4.results[1].genesis_block_height).toBe(778575);
});

test('index filtered by block hash', async () => {
test.skip('index filtered by block hash', async () => {
await db.updateInscriptions(
new TestChainhookPayloadBuilder()
.apply()
Expand Down Expand Up @@ -2794,7 +2794,7 @@ describe('/inscriptions', () => {
expect(responseJson3.results[0].number).toBe(0);
});

test('index filtered by output', async () => {
test.skip('index filtered by output', async () => {
await db.updateInscriptions(
new TestChainhookPayloadBuilder()
.apply()
Expand Down

0 comments on commit cbcc830

Please sign in to comment.