Skip to content

Commit

Permalink
chore: niftysave combine owner tables (#595)
Browse files Browse the repository at this point in the history
  • Loading branch information
Gozala committed Oct 13, 2021
1 parent 0e0979e commit 093b83d
Show file tree
Hide file tree
Showing 3 changed files with 97 additions and 1 deletion.
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,6 @@
- '!include public_nft.yaml'
- '!include public_nft_asset.yaml'
- '!include public_nft_metadata.yaml'
- '!include public_nft_owner.yaml'
- '!include public_nft_ownership.yaml'
- '!include public_nfts_by_blockchain_blocks.yaml'
- '!include public_niftysave_migration.yaml'
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
-- Could not auto-generate a down migration.
Original file line number Diff line number Diff line change
@@ -0,0 +1,96 @@
-- Populate nft_ownership table from nft + blockchain_block

INSERT INTO nft_ownership (nft_id, owner_id, block_number, updated_at, inserted_at)
(SELECT nft.id as nft_id,
nft.nft_owner_id as owner_id,

(SELECT number
FROM blockchain_block
WHERE hash = nfts_by_blockchain_blocks.blockchain_block_hash ) as block_number,
nfts_by_blockchain_blocks.updated_at as updated_at,
nfts_by_blockchain_blocks.inserted_at as inserted_at
FROM nft
INNER JOIN nfts_by_blockchain_blocks ON nft.id = nfts_by_blockchain_blocks.nft_id) ON CONFLICT ON CONSTRAINT nft_ownership_pkey DO
UPDATE
SET updated_at = EXCLUDED.updated_at;

-- Update ingest_erc721_token function so it no longer inserts nft_owner_id into
-- nft table

CREATE OR REPLACE FUNCTION ingest_erc721_token (-- Unique token identifier
id nft.id % TYPE, -- ERC721 tokenID (unique within a contract space)
token_id nft.token_id % TYPE, -- ERC721 tokenURI
token_uri nft_asset.token_uri % TYPE, -- ERC721 mintTime
mint_time nft.mint_time % TYPE, -- NFT Contract
contract_id nft.contract_id % TYPE, contract_name blockchain_contract.name % TYPE, contract_symbol blockchain_contract.symbol % TYPE, contract_supports_eip721_metadata blockchain_contract.supports_eip721_metadata % TYPE, -- Block
block_hash blockchain_block.hash % TYPE, block_number blockchain_block.number % TYPE, -- Owner
owner_id nft_ownership.owner_id % TYPE, -- Timestamps
updated_at nft.updated_at % TYPE DEFAULT timezone('utc'::text, now()), inserted_at nft.inserted_at % TYPE DEFAULT timezone('utc'::text, now())) RETURNS
SETOF nft LANGUAGE plpgsql AS $$
DECLARE
token_uri_hash nft.token_uri_hash % TYPE;
nft_id nft.id % TYPE;
BEGIN
nft_id := id;

-- Create a corresponding token_asset record. If one already
-- exists just update it's `update_at` timestamp.
INSERT INTO nft_asset (token_uri, ipfs_url, content_cid, status, status_text)
VALUES (token_uri, NULL, NULL, 'Queued', '')
ON CONFLICT ON CONSTRAINT nft_asset_pkey
DO UPDATE SET
updated_at = EXCLUDED.updated_at
RETURNING
nft_asset.token_uri_hash INTO token_uri_hash;

-- Record the block information if already exists just update the timestamp.
INSERT INTO blockchain_block (hash, number)
VALUES (block_hash, block_number)
ON CONFLICT ON CONSTRAINT blockchain_block_pkey
DO UPDATE SET
updated_at = EXCLUDED.updated_at;

-- Record contract information if already exists just update
-- the date.
INSERT INTO blockchain_contract (id, name, symbol, supports_eip721_metadata)
VALUES (contract_id, contract_name, contract_symbol, contract_supports_eip721_metadata)
ON CONFLICT ON CONSTRAINT blockchain_contract_pkey
DO UPDATE SET
updated_at = EXCLUDED.updated_at;

-- Record owner information
INSERT INTO nft_ownership (nft_id, owner_id, block_number)
VALUES (nft_id, owner_id, block_number)
ON CONFLICT ON CONSTRAINT nft_ownership_pkey
DO UPDATE SET
updated_at = EXCLUDED.updated_at;

-- Record nft
INSERT INTO nft (id, token_id, token_uri_hash, mint_time, contract_id)
VALUES (nft_id, token_id, token_uri_hash, mint_time, contract_id)
ON CONFLICT ON CONSTRAINT nft_pkey
DO UPDATE SET
updated_at = EXCLUDED.updated_at;

-- Record nft to block association
INSERT INTO nfts_by_blockchain_blocks (blockchain_block_hash, nft_id)
VALUES (block_hash, nft_id)
ON CONFLICT ON CONSTRAINT nfts_by_blockchain_blocks_pkey
DO UPDATE SET
updated_at = EXCLUDED.updated_at;

RETURN QUERY
SELECT
*
FROM
nft
WHERE
nft.id = nft_id;
END;
$$;

-- DROP nft_owner_column

ALTER TABLE nft
DROP COLUMN nft_owner_id;

0 comments on commit 093b83d

Please sign in to comment.