diff --git a/db/alembic/versions/240476c67b9f_drop_etherium_addresses_and_address_id_.py b/db/alembic/versions/240476c67b9f_drop_ethereum_addresses_and_address_id.py similarity index 60% rename from db/alembic/versions/240476c67b9f_drop_etherium_addresses_and_address_id_.py rename to db/alembic/versions/240476c67b9f_drop_ethereum_addresses_and_address_id.py index 0c5fd0b8..8026daaa 100644 --- a/db/alembic/versions/240476c67b9f_drop_etherium_addresses_and_address_id_.py +++ b/db/alembic/versions/240476c67b9f_drop_ethereum_addresses_and_address_id.py @@ -1,4 +1,4 @@ -"""Drop etherium_addresses and address_id column +"""Drop ethereum_addresses and address_id column Revision ID: 240476c67b9f Revises: f1e8cf50a3ff @@ -87,29 +87,29 @@ def upgrade(): """ ALTER TABLE - ONLY public.ethereum_labels + ONLY ethereum_labels ADD CONSTRAINT pk_ethereum_labels PRIMARY KEY (id); ALTER TABLE - ONLY public.ethereum_labels + ONLY ethereum_labels ADD CONSTRAINT uq_ethereum_labels_id UNIQUE (id); /* Create indexes must be unique cross database */ - CREATE INDEX idx_ethereum_labels_opensea_nft_name ON public.ethereum_labels USING btree (((label_data ->> 'name' :: text))) + CREATE INDEX idx_ethereum_labels_opensea_nft_name ON ethereum_labels USING btree (((label_data ->> 'name' :: text))) WHERE ((label) :: text = 'opensea_nft' :: text); - CREATE INDEX ix_ethereum_labels_address ON public.ethereum_labels USING btree (address); + CREATE INDEX ix_ethereum_labels_address ON ethereum_labels USING btree (address); - CREATE INDEX ix_ethereum_labels_block_number ON public.ethereum_labels USING btree (block_number); + CREATE INDEX ix_ethereum_labels_block_number ON ethereum_labels USING btree (block_number); - CREATE INDEX ix_ethereum_labels_label ON public.ethereum_labels USING btree (label); + CREATE INDEX ix_ethereum_labels_label ON ethereum_labels USING btree (label); - CREATE INDEX ix_ethereum_labels_transaction_hash ON public.ethereum_labels USING btree (transaction_hash); + CREATE INDEX ix_ethereum_labels_transaction_hash ON ethereum_labels USING btree (transaction_hash); - CREATE INDEX ix_ethereum_labels_block_timestamp ON public.ethereum_labels USING btree (block_timestamp); + CREATE INDEX ix_ethereum_labels_block_timestamp ON ethereum_labels USING btree (block_timestamp); """ ) @@ -125,96 +125,22 @@ def downgrade(): op.execute( """ - CREATE TABLE public.ethereum_addresses ( - id integer NOT NULL, + CREATE TABLE ethereum_addresses ( + id integer PRIMARY KEY, transaction_hash character varying(256), address character varying(256) NOT NULL, created_at timestamp with time zone DEFAULT timezone('utc'::text, statement_timestamp()) NOT NULL ); - ALTER TABLE public.ethereum_addresses OWNER TO postgres; - CREATE UNIQUE INDEX ix_ethereum_addresses_address ON public.ethereum_addresses USING btree (address); + CREATE UNIQUE INDEX ix_ethereum_addresses_address ON ethereum_addresses USING btree (address); - CREATE INDEX ix_ethereum_addresses_transaction_hash ON public.ethereum_addresses USING btree (transaction_hash); + CREATE INDEX ix_ethereum_addresses_transaction_hash ON ethereum_addresses USING btree (transaction_hash); """ ) - # sequence creation - - op.execute( - """ - - INSERT INTO - ethereum_addresses ( - id, - address - ) - SELECT - distinct(ethereum_labels.address_id) as id, - ethereum_labels.address as address - FROM - ethereum_labels - where address_id IS NOT NULL - order by id; - - """ - ) - - conn = op.get_bind() - latest_id = conn.execute( - "select MAX(address_id) + 1 from ethereum_labels" - ).fetchall() - - if latest_id: - max_id = latest_id[0][0] - else: - max_id = 1 - - op.execute( - f"CREATE SEQUENCE public.ethereum_smart_contracts_id_seq INCREMENT BY 1 START WITH {max_id} NO MINVALUE NO MAXVALUE CACHE 1" - ) - - # id column settings - op.execute( - """ - - ALTER TABLE public.ethereum_smart_contracts_id_seq OWNER TO postgres; - - ALTER SEQUENCE public.ethereum_smart_contracts_id_seq OWNED BY public.ethereum_addresses.id; - - ALTER TABLE ONLY public.ethereum_addresses ALTER COLUMN id SET DEFAULT nextval('public.ethereum_smart_contracts_id_seq'::regclass); - - ALTER TABLE ONLY public.ethereum_addresses ADD CONSTRAINT pk_ethereum_smart_contracts PRIMARY KEY (id); - - """ - ) - - op.execute( - """ - - INSERT INTO - ethereum_addresses ( - address - ) - select result.address from ( - SELECT - ethereum_labels.address as address - FROM - ethereum_labels - where address_id IS NULL - EXCEPT - SELECT - ethereum_labels.address as address - FROM - ethereum_labels - where address_id IS NOT NULL - ) AS result - """ - ) - op.execute( "ALTER TABLE IF EXISTS ethereum_labels DROP CONSTRAINT IF EXISTS pk_ethereum_labels;" ) @@ -253,12 +179,3 @@ def downgrade(): ALTER INDEX uq_ethereum_labels_id_v1 RENAME TO uq_ethereum_labels_id; """ ) - - op.create_foreign_key( - "fk_ethereum_labels_address_id_ethereum_addresses", - "ethereum_labels", - "ethereum_addresses", - ["address_id"], - ["id"], - ondelete="CASCADE", - ) diff --git a/db/alembic/versions/f1e8cf50a3ff_add_log_index_block_number_timestamp_.py b/db/alembic/versions/f1e8cf50a3ff_add_log_index_block_number_timestamp_.py index d699075e..92a32d45 100644 --- a/db/alembic/versions/f1e8cf50a3ff_add_log_index_block_number_timestamp_.py +++ b/db/alembic/versions/f1e8cf50a3ff_add_log_index_block_number_timestamp_.py @@ -29,7 +29,6 @@ def upgrade(): ethereum_labels.label_data as label_data, ethereum_labels.created_at as created_at, ethereum_labels.transaction_hash as transaction_hash, - ethereum_addresses.id as address_id, ethereum_addresses.address as address FROM ethereum_labels diff --git a/db/scripts/f1e8cf50a3ff_add_log_index_block_number_timestamp_test.py b/db/scripts/f1e8cf50a3ff_add_log_index_block_number_timestamp_test.py index 06829adc..0ef2b642 100644 --- a/db/scripts/f1e8cf50a3ff_add_log_index_block_number_timestamp_test.py +++ b/db/scripts/f1e8cf50a3ff_add_log_index_block_number_timestamp_test.py @@ -1,115 +1,81 @@ import argparse -import os -from typing import Any, Dict, Optional + +from moonstreamdb.db import yield_db_session_ctx -from typing import Any, Dict, Optional -from sqlalchemy import create_engine +def ethereum_labels_copy_check() -> None: + with yield_db_session_ctx() as db_session: -def ethereum_labels_copy_check(args: argparse.Namespace) -> None: + # check counts in 2 tables - engine = create_engine(args.database) - connection = engine.connect() - - # check counts in 2 tables - - count_original = connection.execute( + count_original = db_session.execute( + """ + select count(*) from ethereum_labels; """ - select count(*) from ethereum_labels; - """ - ).fetchall()[0][0] + ).fetchall()[0][0] - count_new_labels = connection.execute( + count_new_labels = db_session.execute( + """ + select count(*) from ethereum_labels_v2; """ - select count(*) from ethereum_labels_v2; - """ - ).fetchall()[0][0] - if count_original == count_new_labels: - print(f"Count check passed") - else: - print(f"Tables recors counts mismatch") + ).fetchall()[0][0] + if count_original == count_new_labels: + print(f"Count check passed") + else: + print(f"Tables recors counts mismatch") - print( - f"etherium_labels count:{count_original}, ethereum_labels_v2 count:{count_new_labels}" - ) - - # check random selected rows - original_table_rows_select = connection.execute( - """ - select id from ethereum_labels TABLESAMPLE BERNOULLI (0.1) limit 1000; - """ - ).fetchall() - - ids = [str(row[0]) for row in original_table_rows_select] - - ids_str = "', '".join(ids) - - # check - - original_table_rows_select = connection.execute( - """ - SELECT - id, - label, - label_data, - created_at, - transaction_hash, - address - FROM - ethereum_labels_v2 - where id IN ('{}') - EXCEPT - SELECT - ethereum_labels.id as id, - ethereum_labels.label as label, - ethereum_labels.label_data as label_data, - ethereum_labels.created_at as created_at, - ethereum_labels.transaction_hash as transaction_hash, - ethereum_addresses.address as address - FROM - ethereum_labels - left join ethereum_addresses ON ethereum_labels.address_id = ethereum_addresses.id - where ethereum_labels.id IN ('{}'); - """.format( - ids_str, ids_str + print( + f"ethereum_labels count:{count_original}, ethereum_labels_v2 count:{count_new_labels}" ) - ).fetchall() - if original_table_rows_select: - print("Error rows data from sample missmatch") - else: - print("Rows sample is correct") + # check random selected rows + original_table_rows_select = db_session.execute( + """ + select id from ethereum_labels TABLESAMPLE BERNOULLI (0.1) limit 1000; + """ + ).fetchall() + ids = [str(row[0]) for row in original_table_rows_select] -def main() -> None: - parser = argparse.ArgumentParser(description="Migration check") - parser.set_defaults(func=lambda _: parser.print_help()) - subcommands = parser.add_subparsers(description="Subcommands") + ids_str = "', '".join(ids) - parser_migration_check = subcommands.add_parser( - "ethereum_migration_check", - description="Check for migration between tables.", - ) - parser_migration_check.set_defaults( - func=lambda _: parser_migration_check.print_help() - ) - subparsers_migration_check = parser_migration_check.add_subparsers() + # check - parser_ethereum_migration_check = subparsers_migration_check.add_parser( - "run", - description="Run check of tables", - ) + original_table_rows_select = db_session.execute( + """ + SELECT + id, + label, + label_data, + created_at, + transaction_hash, + address + FROM + ethereum_labels_v2 + where id IN ('{}') + EXCEPT + SELECT + ethereum_labels.id as id, + ethereum_labels.label as label, + ethereum_labels.label_data as label_data, + ethereum_labels.created_at as created_at, + ethereum_labels.transaction_hash as transaction_hash, + ethereum_addresses.address as address + FROM + ethereum_labels + left join ethereum_addresses ON ethereum_labels.address_id = ethereum_addresses.id + where ethereum_labels.id IN ('{}'); + """.format( + ids_str, ids_str + ) + ).fetchall() - parser_ethereum_migration_check.add_argument( - "--database", type=str, required=True, help="Database for check." - ) - - parser_ethereum_migration_check.set_defaults(func=ethereum_labels_copy_check) - - args = parser.parse_args() - args.func(args) + if original_table_rows_select: + print("Error rows data from sample missmatch") + else: + print("Rows sample is correct") if __name__ == "__main__": - main() + ethereum_labels_copy_check()