Skip to content

Commit

Permalink
comment out expensive indices (#410)
Browse files Browse the repository at this point in the history
  • Loading branch information
bowenyang007 authored Jun 14, 2024
1 parent c093d3d commit 2397cd8
Showing 1 changed file with 27 additions and 36 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,6 @@
-- Create the schema
CREATE SCHEMA IF NOT EXISTS legacy_migration_v1;
-- Replace `move_resources` with account transactions
-- account_transactions already has index on transaction_version
CREATE OR REPLACE VIEW legacy_migration_v1.move_resources AS
SELECT transaction_version,
account_address as address
Expand All @@ -11,7 +10,6 @@ CREATE OR REPLACE VIEW legacy_migration_v1.address_version_from_move_resources A
SELECT transaction_version,
account_address as address
FROM account_transactions at2;
-- account_transactions already has index on transaction_version
-- replace `coin_activities` with `fungible_asset_activities`
CREATE OR REPLACE VIEW legacy_migration_v1.coin_activities AS
SElECT transaction_version,
Expand All @@ -34,10 +32,6 @@ SElECT transaction_version,
storage_refund_amount
FROM public.fungible_asset_activities
WHERE token_standard = 'v1';
CREATE INDEX IF NOT EXISTS lm1_ca_ct_a_index ON public.fungible_asset_activities USING btree (asset_type, amount);
CREATE INDEX IF NOT EXISTS lm1_ca_ct_at_a_index ON public.fungible_asset_activities USING btree (asset_type, "type", amount);
CREATE INDEX IF NOT EXISTS lm1_ca_oa_ct_at_index ON public.fungible_asset_activities USING btree (owner_address, asset_type, "type", amount);
CREATE INDEX IF NOT EXISTS lm1_ca_oa_igf_index ON public.fungible_asset_activities USING btree (owner_address, is_gas_fee);
-- replace `coin_balances` with `fungible_asset_balances`
CREATE OR REPLACE VIEW legacy_migration_v1.coin_balances AS
SELECT transaction_version,
Expand Down Expand Up @@ -65,7 +59,6 @@ SELECT encode(sha256(asset_type::bytea), 'hex') as coin_type_hash,
supply_aggregator_table_key_v1 as supply_aggregator_table_key
FROM public.fungible_asset_metadata
WHERE token_standard = 'v1';
CREATE INDEX IF NOT EXISTS lm1_cb_tv_oa_ct_index ON public.fungible_asset_balances USING btree (transaction_version, owner_address, asset_type);
-- replace `current_coin_balances` with `current_fungible_asset_balances`
CREATE OR REPLACE VIEW legacy_migration_v1.current_coin_balances AS
SELECT owner_address,
Expand All @@ -77,7 +70,6 @@ SELECT owner_address,
inserted_at
FROM public.current_fungible_asset_balances
WHERE token_standard = 'v1';
CREATE INDEX IF NOT EXISTS lm1_ccb_ct_a_index ON public.current_fungible_asset_balances USING btree (asset_type, amount);
-- replace `token_activities` with `token_activities_v2`
-- token_activities_v2.token_data_id is 0x prefixed, but token_activities.token_data_id is not. We need to create an index on the substring
CREATE OR REPLACE VIEW legacy_migration_v1.token_activities AS
Expand Down Expand Up @@ -108,10 +100,6 @@ FROM public.token_activities_v2 tav
JOIN collections_v2 cv ON tdv.collection_id = cv.collection_id
AND tdv.transaction_version = cv.transaction_version
WHERE tav.token_standard = 'v1';
-- token_activities_v2 already has index on token_data_id
CREATE INDEX IF NOT EXISTS lm1_tdv_tdi_tv_index ON public.token_datas_v2 USING btree (token_data_id, transaction_version);
CREATE INDEX IF NOT EXISTS lm1_cv_ci_tv_index ON public.collections_v2 USING btree (collection_id, transaction_version);
CREATE INDEX IF NOT EXISTS lm1_ta_tdih_pv_index ON public.token_activities_v2 USING btree (token_data_id, property_version_v1);
-- replace `token_ownerships` with `token_ownerships_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.token_ownerships AS
SELECT tov.token_data_id AS token_data_id_hash,
Expand All @@ -134,7 +122,6 @@ FROM public.token_ownerships_v2 tov
JOIN public.collections_v2 cv ON tdv.collection_id = cv.collection_id
AND tdv.transaction_version = cv.transaction_version
WHERE tov.token_standard = 'v1';
-- token_ownerships_v2 already has index on token_data_id
-- replace `current_token_ownerships` with `current_token_ownerships_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.current_token_ownerships AS
SELECT ctov.token_data_id AS token_data_id_hash,
Expand All @@ -154,18 +141,6 @@ FROM current_token_ownerships_v2 ctov
JOIN current_token_datas_v2 ctdv ON ctov.token_data_id = ctdv.token_data_id
JOIN current_collections_v2 ccv ON ctdv.collection_id = ccv.collection_id
WHERE ctov.token_standard = 'v1';
-- current_collections_v2 already has index on collection_id
CREATE INDEX IF NOT EXISTS lm1_curr_to_oa_tt_am_ltv_index ON current_token_ownerships_v2 USING btree (
owner_address,
table_type_v1,
amount,
last_transaction_version DESC
);
CREATE INDEX IF NOT EXISTS lm1_curr_to_oa_tt_ltv_index ON current_token_ownerships_v2 USING btree (
owner_address,
table_type_v1,
last_transaction_version DESC
);
-- replace `tokens` with `current_token_datas_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.tokens AS
SELECT tdv.token_data_id AS token_data_id_hash,
Expand All @@ -181,7 +156,6 @@ SELECT tdv.token_data_id AS token_data_id_hash,
FROM token_datas_v2 tdv
JOIN current_collections_v2 ccv ON tdv.collection_id = ccv.collection_id
WHERE tdv.token_standard = 'v1';
-- token_datas_v2 already has index on collection_id
-- replace `token_datas` with `token_datas_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.token_datas AS
SELECT token_data_id AS token_data_id_hash,
Expand Down Expand Up @@ -212,7 +186,6 @@ FROM token_datas_v2 tdv
JOIN collections_v2 cv ON tdv.collection_id = cv.collection_id
AND tdv.transaction_version = cv.transaction_version
WHERE tdv.token_standard = 'v1';
-- collections_v2 already has index on collection_id and transaction version
-- replace `current_token_datas` with `current_token_datas_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.current_token_datas AS
SELECT ctdv.token_data_id AS token_data_id_hash,
Expand Down Expand Up @@ -240,10 +213,8 @@ SELECT ctdv.token_data_id AS token_data_id_hash,
ctdv."description" AS "description"
FROM current_token_datas_v2 ctdv
JOIN current_collections_v2 ccv ON ctdv.collection_id = ccv.collection_id
LEFT JOIN current_token_royalty_v1 ctrv on ctdv.token_data_id = ctrv.token_data_id
LEFT JOIN current_token_royalty_v1 ctrv on ctdv.token_data_id = ctrv.token_data_id
WHERE ctdv.token_standard = 'v1';
-- current_collections_v2 already has index on collection_id
-- current_collections_v2 already has an index on (creator_address, collection_name)
-- replace `collection_datas` with `collection_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.collection_datas AS
SELECT collection_id AS collection_data_id_hash,
Expand All @@ -263,7 +234,6 @@ SELECT collection_id AS collection_data_id_hash,
transaction_timestamp
FROM collections_v2
WHERE token_standard = 'v1';
-- collections_v2 already has index on (creator_address, collection_name)
-- replace `current_ans_primary_name` with `current_ans_primary_name_v2`
CREATE OR REPLACE VIEW legacy_migration_v1.current_ans_primary_name AS
SELECT registered_address,
Expand All @@ -275,10 +245,7 @@ SELECT registered_address,
0 AS last_transaction_timestamp
FROM current_ans_primary_name_v2
WHERE token_standard = 'v1';
-- current_ans_primary_name_v2 already has index on token_name
-- replace `current_ans_lookup` with `current_ans_lookup_v2`
-- current_ans_lookup_v2 already has index on expiration_timestamp
-- current_ans_lookup_v2 already has index on token_name
CREATE OR REPLACE VIEW legacy_migration_v1.current_ans_lookup AS
SELECT domain,
subdomain,
Expand All @@ -290,5 +257,29 @@ SELECT domain,
is_deleted
FROM current_ans_lookup_v2
WHERE token_standard = 'v1';
CREATE INDEX IF NOT EXISTS lm1_ans_d_s_et_index ON public.current_ans_lookup_v2 USING btree (domain, subdomain, expiration_timestamp);
CREATE INDEX IF NOT EXISTS lm1_ans_ra_et_index ON public.current_ans_lookup_v2 USING btree (registered_address, expiration_timestamp);
-----
-----
-----
-- If you would like to run these indices, please do it outside of diesel migration since it will be blocking processing
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ca_ct_a_index ON public.fungible_asset_activities USING btree (asset_type, amount);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ca_ct_at_a_index ON public.fungible_asset_activities USING btree (asset_type, "type", amount);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ca_oa_ct_at_index ON public.fungible_asset_activities USING btree (owner_address, asset_type, "type", amount);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ca_oa_igf_index ON public.fungible_asset_activities USING btree (owner_address, is_gas_fee);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_cb_tv_oa_ct_index ON public.fungible_asset_balances USING btree (transaction_version, owner_address, asset_type);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ccb_ct_a_index ON public.current_fungible_asset_balances USING btree (asset_type, amount);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_tdv_tdi_tv_index ON public.token_datas_v2 USING btree (token_data_id, transaction_version);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_cv_ci_tv_index ON public.collections_v2 USING btree (collection_id, transaction_version);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ta_tdih_pv_index ON public.token_activities_v2 USING btree (token_data_id, property_version_v1);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ans_d_s_et_index ON public.current_ans_lookup_v2 USING btree (domain, subdomain, expiration_timestamp);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_ans_ra_et_index ON public.current_ans_lookup_v2 USING btree (registered_address, expiration_timestamp);
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_curr_to_oa_tt_am_ltv_index ON current_token_ownerships_v2 USING btree (
-- owner_address,
-- table_type_v1,
-- amount,
-- last_transaction_version DESC
-- );
-- CREATE INDEX CONCURRENTLY IF NOT EXISTS lm1_curr_to_oa_tt_ltv_index ON current_token_ownerships_v2 USING btree (
-- owner_address,
-- table_type_v1,
-- last_transaction_version DESC
-- );

0 comments on commit 2397cd8

Please sign in to comment.