Skip to content

Commit

Permalink
fix: move nft custody view into a table (#1741)
Browse files Browse the repository at this point in the history
* fix: move to table

* fix: old nft events query

* fix: nft-custody-table migration

* fix: no longer rename old views, just remove them

---------

Co-authored-by: Matt <[email protected]>
  • Loading branch information
rafaelcr and zone117x authored Oct 25, 2023
1 parent cc4d0e5 commit fb0d0ea
Show file tree
Hide file tree
Showing 6 changed files with 349 additions and 53 deletions.
215 changes: 215 additions & 0 deletions migrations/1696872367486_nft-custody-tables.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,215 @@
/* eslint-disable camelcase */

exports.shorthands = undefined;

exports.up = pgm => {
pgm.dropMaterializedView('nft_custody');
pgm.createTable('nft_custody', {
asset_identifier: {
type: 'string',
notNull: true,
},
value: {
type: 'bytea',
notNull: true,
},
recipient: {
type: 'text',
},
block_height: {
type: 'integer',
notNull: true,
},
index_block_hash: {
type: 'bytea',
notNull: true,
},
parent_index_block_hash: {
type: 'bytea',
notNull: true,
},
microblock_hash: {
type: 'bytea',
notNull: true,
},
microblock_sequence: {
type: 'integer',
notNull: true,
},
tx_id: {
type: 'bytea',
notNull: true,
},
tx_index: {
type: 'smallint',
notNull: true,
},
event_index: {
type: 'integer',
notNull: true,
},
});
pgm.createConstraint('nft_custody', 'nft_custody_unique', 'UNIQUE(asset_identifier, value)');
pgm.createIndex('nft_custody', ['recipient', 'asset_identifier']);
pgm.createIndex('nft_custody', 'value');
pgm.createIndex('nft_custody', [
{ name: 'block_height', sort: 'DESC' },
{ name: 'microblock_sequence', sort: 'DESC' },
{ name: 'tx_index', sort: 'DESC' },
{ name: 'event_index', sort: 'DESC' }
]);
pgm.sql(`
INSERT INTO nft_custody (asset_identifier, value, recipient, tx_id, block_height, index_block_hash, parent_index_block_hash, microblock_hash, microblock_sequence, tx_index, event_index) (
SELECT
DISTINCT ON(asset_identifier, value) asset_identifier, value, recipient, tx_id, nft.block_height,
nft.index_block_hash, nft.parent_index_block_hash, nft.microblock_hash, nft.microblock_sequence, nft.tx_index, nft.event_index
FROM
nft_events AS nft
INNER JOIN
txs USING (tx_id)
WHERE
txs.canonical = true
AND txs.microblock_canonical = true
AND nft.canonical = true
AND nft.microblock_canonical = true
ORDER BY
asset_identifier,
value,
txs.block_height DESC,
txs.microblock_sequence DESC,
txs.tx_index DESC,
nft.event_index DESC
)
`);

pgm.dropMaterializedView('nft_custody_unanchored');
pgm.createTable('nft_custody_unanchored', {
asset_identifier: {
type: 'string',
notNull: true,
},
value: {
type: 'bytea',
notNull: true,
},
recipient: {
type: 'text',
},
block_height: {
type: 'integer',
notNull: true,
},
index_block_hash: {
type: 'bytea',
notNull: true,
},
parent_index_block_hash: {
type: 'bytea',
notNull: true,
},
microblock_hash: {
type: 'bytea',
notNull: true,
},
microblock_sequence: {
type: 'integer',
notNull: true,
},
tx_id: {
type: 'bytea',
notNull: true,
},
tx_index: {
type: 'smallint',
notNull: true,
},
event_index: {
type: 'integer',
notNull: true,
},
});
pgm.createConstraint('nft_custody_unanchored', 'nft_custody_unanchored_unique', 'UNIQUE(asset_identifier, value)');
pgm.createIndex('nft_custody_unanchored', ['recipient', 'asset_identifier']);
pgm.createIndex('nft_custody_unanchored', 'value');
pgm.createIndex('nft_custody_unanchored', [
{ name: 'block_height', sort: 'DESC' },
{ name: 'microblock_sequence', sort: 'DESC' },
{ name: 'tx_index', sort: 'DESC' },
{ name: 'event_index', sort: 'DESC' }
]);
pgm.sql(`
INSERT INTO nft_custody_unanchored (asset_identifier, value, recipient, tx_id, block_height, index_block_hash, parent_index_block_hash, microblock_hash, microblock_sequence, tx_index, event_index) (
SELECT
DISTINCT ON(asset_identifier, value) asset_identifier, value, recipient, tx_id, nft.block_height,
nft.index_block_hash, nft.parent_index_block_hash, nft.microblock_hash, nft.microblock_sequence, nft.tx_index, nft.event_index
FROM
nft_events AS nft
INNER JOIN
txs USING (tx_id)
WHERE
txs.canonical = true
AND txs.microblock_canonical = true
AND nft.canonical = true
AND nft.microblock_canonical = true
ORDER BY
asset_identifier,
value,
txs.block_height DESC,
txs.microblock_sequence DESC,
txs.tx_index DESC,
nft.event_index DESC
)
`);
};

exports.down = pgm => {
pgm.dropTable('nft_custody');
pgm.createMaterializedView('nft_custody', { data: true }, `
SELECT
DISTINCT ON(asset_identifier, value) asset_identifier, value, recipient, tx_id, nft.block_height
FROM
nft_events AS nft
INNER JOIN
txs USING (tx_id)
WHERE
txs.canonical = true
AND txs.microblock_canonical = true
AND nft.canonical = true
AND nft.microblock_canonical = true
ORDER BY
asset_identifier,
value,
txs.block_height DESC,
txs.microblock_sequence DESC,
txs.tx_index DESC,
nft.event_index DESC
`);
pgm.createIndex('nft_custody', ['recipient', 'asset_identifier']);
pgm.createIndex('nft_custody', ['asset_identifier', 'value'], { unique: true });
pgm.createIndex('nft_custody', 'value');

pgm.dropTable('nft_custody_unanchored');
pgm.createMaterializedView('nft_custody_unanchored', { data: true }, `
SELECT
DISTINCT ON(asset_identifier, value) asset_identifier, value, recipient, tx_id, nft.block_height
FROM
nft_events AS nft
INNER JOIN
txs USING (tx_id)
WHERE
txs.canonical = true
AND txs.microblock_canonical = true
AND nft.canonical = true
AND nft.microblock_canonical = true
ORDER BY
asset_identifier,
value,
txs.block_height DESC,
txs.microblock_sequence DESC,
txs.tx_index DESC,
nft.event_index DESC
`);
pgm.createIndex('nft_custody_unanchored', ['recipient', 'asset_identifier']);
pgm.createIndex('nft_custody_unanchored', ['asset_identifier', 'value'], { unique: true });
pgm.createIndex('nft_custody_unanchored', 'value');
};
14 changes: 14 additions & 0 deletions src/datastore/common.ts
Original file line number Diff line number Diff line change
Expand Up @@ -1357,6 +1357,20 @@ export interface NftEventInsertValues {
value: PgBytea;
}

export interface NftCustodyInsertValues {
event_index: number;
tx_id: PgBytea;
tx_index: number;
block_height: number;
index_block_hash: PgBytea;
parent_index_block_hash: PgBytea;
microblock_hash: PgBytea;
microblock_sequence: number;
recipient: string | null;
asset_identifier: string;
value: PgBytea;
}

export interface FtEventInsertValues {
event_index: number;
tx_id: PgBytea;
Expand Down
7 changes: 4 additions & 3 deletions src/datastore/pg-store.ts
Original file line number Diff line number Diff line change
Expand Up @@ -3318,6 +3318,7 @@ export class PgStore {
FROM ${nftCustody} AS nft
WHERE nft.recipient = ${args.principal}
${assetIdFilter}
ORDER BY block_height DESC, microblock_sequence DESC, tx_index DESC, event_index DESC
LIMIT ${args.limit}
OFFSET ${args.offset}
)
Expand Down Expand Up @@ -3519,11 +3520,11 @@ export class PgStore {
AND block_height <= ${args.blockHeight}
ORDER BY asset_identifier, value, block_height DESC, microblock_sequence DESC, tx_index DESC, event_index DESC
)
SELECT sender, recipient, asset_identifier, value, event_index, asset_event_type_id, address_transfers.block_height, address_transfers.tx_id, (COUNT(*) OVER())::INTEGER AS count
FROM address_transfers
SELECT sender, recipient, asset_identifier, value, at.event_index, asset_event_type_id, at.block_height, at.tx_id, (COUNT(*) OVER())::INTEGER AS count
FROM address_transfers AS at
INNER JOIN ${args.includeUnanchored ? this.sql`last_nft_transfers` : this.sql`nft_custody`}
USING (asset_identifier, value, recipient)
ORDER BY block_height DESC, microblock_sequence DESC, tx_index DESC, event_index DESC
ORDER BY at.block_height DESC, at.microblock_sequence DESC, at.tx_index DESC, event_index DESC
LIMIT ${args.limit} OFFSET ${args.offset}
`;

Expand Down
Loading

0 comments on commit fb0d0ea

Please sign in to comment.