Blockchain explorer for Ethereum based network and a tool for inspecting and analyzing EVM based blockchains.
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
blockscout/priv/repo/migrations/20180224004300_update_credi...

88 lines
3.3 KiB

defmodule Explorer.Repo.Migrations.UpdateCreditDebitMaterializedView do
use Ecto.Migration
def up do
execute "DROP MATERIALIZED VIEW IF EXISTS credits;"
execute "DROP MATERIALIZED VIEW IF EXISTS debits;"
execute """
CREATE MATERIALIZED VIEW credits AS
SELECT addresses.id AS address_id,
COALESCE(SUM(transactions.value), 0) AS value,
COUNT(transactions.to_address_id) AS count,
COALESCE(MIN(transactions.inserted_at), NOW()) AS inserted_at,
COALESCE(MAX(transactions.inserted_at), NOW()) AS updated_at
FROM addresses
INNER JOIN transactions ON transactions.to_address_id = addresses.id
INNER JOIN receipts ON receipts.transaction_id = transactions.id AND receipts.status = 1
GROUP BY addresses.id
;
"""
execute """
CREATE MATERIALIZED VIEW debits AS
SELECT addresses.id AS address_id,
COALESCE(SUM(transactions.value), 0) AS value,
COUNT(transactions.from_address_id) AS count,
COALESCE(MIN(transactions.inserted_at), NOW()) AS inserted_at,
COALESCE(MAX(transactions.inserted_at), NOW()) AS updated_at
FROM addresses
INNER JOIN transactions ON transactions.from_address_id = addresses.id
INNER JOIN receipts ON receipts.transaction_id = transactions.id AND receipts.status = 1
GROUP BY addresses.id
;
"""
create unique_index(:credits, :address_id)
create index(:credits, :inserted_at)
create index(:credits, :updated_at)
create unique_index(:debits, :address_id)
create index(:debits, :inserted_at)
create index(:debits, :updated_at)
end
def down do
execute "DROP MATERIALIZED VIEW IF EXISTS credits;"
execute "DROP MATERIALIZED VIEW IF EXISTS debits;"
execute """
CREATE MATERIALIZED VIEW credits AS
SELECT addresses.id AS address_id,
COALESCE(SUM(transactions.value), 0) AS value,
COUNT(to_addresses.address_id) AS count,
COALESCE(MIN(transactions.inserted_at), NOW()) AS inserted_at,
COALESCE(MAX(transactions.inserted_at), NOW()) AS updated_at
FROM addresses
INNER JOIN to_addresses ON to_addresses.address_id = addresses.id
INNER JOIN transactions ON transactions.id = to_addresses.transaction_id
INNER JOIN receipts ON receipts.transaction_id = transactions.id AND receipts.status = 1
GROUP BY addresses.id
;
"""
execute """
CREATE MATERIALIZED VIEW debits AS
SELECT addresses.id AS address_id,
COALESCE(SUM(transactions.value), 0) AS value,
COUNT(from_addresses.address_id) AS count,
COALESCE(MIN(transactions.inserted_at), NOW()) AS inserted_at,
COALESCE(MAX(transactions.inserted_at), NOW()) AS updated_at
FROM addresses
INNER JOIN from_addresses ON from_addresses.address_id = addresses.id
INNER JOIN transactions ON transactions.id = from_addresses.transaction_id
INNER JOIN receipts ON receipts.transaction_id = transactions.id AND receipts.status = 1
GROUP BY addresses.id
;
"""
create unique_index(:credits, :address_id)
create index(:credits, :inserted_at)
create index(:credits, :updated_at)
create unique_index(:debits, :address_id)
create index(:debits, :inserted_at)
create index(:debits, :updated_at)
end
end