diff --git a/Makefile b/Makefile
index 0e81c0d..2801e47 100644
--- a/Makefile
+++ b/Makefile
@@ -30,7 +30,7 @@ TEST_CONNECT_STRING = postgresql://$(USER)@$(HOST_NAME):$(PORT)/$(TEST_DB)?sslmo
 test: | $(GINKGO)
 	dropdb --if-exists $(TEST_DB)
 	createdb $(TEST_DB)
-	$(GOOSE) -dir db/migrations postgres "$(TEST_CONNECT_STRING)" up
+	make migrate NAME=$(TEST_DB)
 	$(GOOSE) -dir db/migrations postgres "$(TEST_CONNECT_STRING)" reset
 
 ## Build docker image
diff --git a/db/migrations/00022_add_tx_type_to_transaction_cids.sql b/db/migrations/00022_add_tx_type_to_transaction_cids.sql
new file mode 100644
index 0000000..010791e
--- /dev/null
+++ b/db/migrations/00022_add_tx_type_to_transaction_cids.sql
@@ -0,0 +1,7 @@
+-- +goose Up
+ALTER TABLE eth.transaction_cids
+ADD COLUMN tx_type BYTEA;
+
+-- +goose Down
+ALTER TABLE eth.transaction_cids
+DROP COLUMN tx_type;
\ No newline at end of file
diff --git a/db/migrations/00023_create_access_list_table.sql b/db/migrations/00023_create_access_list_table.sql
new file mode 100644
index 0000000..3e27a63
--- /dev/null
+++ b/db/migrations/00023_create_access_list_table.sql
@@ -0,0 +1,15 @@
+-- +goose Up
+CREATE TABLE eth.access_list_element (
+    id                    SERIAL PRIMARY KEY,
+    tx_id                 INTEGER NOT NULL REFERENCES eth.transaction_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
+    index                 INTEGER NOT NULL,
+    address               VARCHAR(66),
+    storage_keys          VARCHAR(66)[],
+    UNIQUE (tx_id, index)
+);
+
+CREATE INDEX accesss_list_element_address_index ON eth.access_list_element USING btree (address);
+
+-- +goose Down
+DROP INDEX eth.accesss_list_element_address_index;
+DROP TABLE eth.access_list_element;
diff --git a/db/schema.sql b/db/schema.sql
index 7dd3509..1e21ed0 100644
--- a/db/schema.sql
+++ b/db/schema.sql
@@ -23,6 +23,58 @@ SET row_security = off;
 CREATE SCHEMA eth;
 
 
+SET default_tablespace = '';
+
+SET default_table_access_method = heap;
+
+--
+-- Name: header_cids; Type: TABLE; Schema: eth; Owner: -
+--
+
+CREATE TABLE eth.header_cids (
+    id integer NOT NULL,
+    block_number bigint NOT NULL,
+    block_hash character varying(66) NOT NULL,
+    parent_hash character varying(66) NOT NULL,
+    cid text NOT NULL,
+    mh_key text NOT NULL,
+    td numeric NOT NULL,
+    node_id integer NOT NULL,
+    reward numeric NOT NULL,
+    state_root character varying(66) NOT NULL,
+    tx_root character varying(66) NOT NULL,
+    receipt_root character varying(66) NOT NULL,
+    uncle_root character varying(66) NOT NULL,
+    bloom bytea NOT NULL,
+    "timestamp" numeric NOT NULL,
+    times_validated integer DEFAULT 1 NOT NULL
+);
+
+
+--
+-- Name: TABLE header_cids; Type: COMMENT; Schema: eth; Owner: -
+--
+
+COMMENT ON TABLE eth.header_cids IS '@name EthHeaderCids';
+
+
+--
+-- Name: COLUMN header_cids.node_id; Type: COMMENT; Schema: eth; Owner: -
+--
+
+COMMENT ON COLUMN eth.header_cids.node_id IS '@name EthNodeID';
+
+
+--
+-- Name: child_result; Type: TYPE; Schema: public; Owner: -
+--
+
+CREATE TYPE public.child_result AS (
+	has_child boolean,
+	children eth.header_cids[]
+);
+
+
 --
 -- Name: graphql_subscription(); Type: FUNCTION; Schema: eth; Owner: -
 --
@@ -78,46 +130,90 @@ END
 $$;
 
 
-SET default_tablespace = '';
-
-SET default_table_access_method = heap;
-
---
--- Name: header_cids; Type: TABLE; Schema: eth; Owner: -
---
-
-CREATE TABLE eth.header_cids (
-    id integer NOT NULL,
-    block_number bigint NOT NULL,
-    block_hash character varying(66) NOT NULL,
-    parent_hash character varying(66) NOT NULL,
-    cid text NOT NULL,
-    mh_key text NOT NULL,
-    td numeric NOT NULL,
-    node_id integer NOT NULL,
-    reward numeric NOT NULL,
-    state_root character varying(66) NOT NULL,
-    tx_root character varying(66) NOT NULL,
-    receipt_root character varying(66) NOT NULL,
-    uncle_root character varying(66) NOT NULL,
-    bloom bytea NOT NULL,
-    "timestamp" numeric NOT NULL,
-    times_validated integer DEFAULT 1 NOT NULL
-);
-
-
 --
--- Name: TABLE header_cids; Type: COMMENT; Schema: eth; Owner: -
+-- Name: canonical_header_from_array(eth.header_cids[]); Type: FUNCTION; Schema: public; Owner: -
 --
 
-COMMENT ON TABLE eth.header_cids IS '@name EthHeaderCids';
+CREATE FUNCTION public.canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids
+    LANGUAGE plpgsql
+    AS $$
+DECLARE
+  canonical_header eth.header_cids;
+  canonical_child eth.header_cids;
+  header eth.header_cids;
+  current_child_result child_result;
+  child_headers eth.header_cids[];
+  current_header_with_child eth.header_cids;
+  has_children_count INT DEFAULT 0;
+BEGIN
+  -- for each header in the provided set
+  FOREACH header IN ARRAY headers
+  LOOP
+    -- check if it has any children
+    current_child_result = has_child(header.block_hash, header.block_number);
+    IF current_child_result.has_child THEN
+      -- if it does, take note
+      has_children_count = has_children_count + 1;
+      current_header_with_child = header;
+      -- and add the children to the growing set of child headers
+      child_headers = array_cat(child_headers, current_child_result.children);
+    END IF;
+  END LOOP;
+  -- if none of the headers had children, none is more canonical than the other
+  IF has_children_count = 0 THEN
+    -- return the first one selected
+    SELECT * INTO canonical_header FROM unnest(headers) LIMIT 1;
+  -- if only one header had children, it can be considered the heaviest/canonical header of the set
+  ELSIF has_children_count = 1 THEN
+    -- return the only header with a child
+    canonical_header = current_header_with_child;
+  -- if there are multiple headers with children
+  ELSE
+    -- find the canonical header from the child set
+    canonical_child = canonical_header_from_array(child_headers);
+    -- the header that is parent to this header, is the canonical header at this level
+    SELECT * INTO canonical_header FROM unnest(headers)
+    WHERE block_hash = canonical_child.parent_hash;
+  END IF;
+  RETURN canonical_header;
+END
+$$;
 
 
 --
--- Name: COLUMN header_cids.node_id; Type: COMMENT; Schema: eth; Owner: -
+-- Name: canonical_header_id(bigint); Type: FUNCTION; Schema: public; Owner: -
 --
 
-COMMENT ON COLUMN eth.header_cids.node_id IS '@name EthNodeID';
+CREATE FUNCTION public.canonical_header_id(height bigint) RETURNS integer
+    LANGUAGE plpgsql
+    AS $$
+DECLARE
+  canonical_header eth.header_cids;
+  headers eth.header_cids[];
+  header_count INT;
+  temp_header eth.header_cids;
+BEGIN
+  -- collect all headers at this height
+  FOR temp_header IN
+  SELECT * FROM eth.header_cids WHERE block_number = height
+  LOOP
+    headers = array_append(headers, temp_header);
+  END LOOP;
+  -- count the number of headers collected
+  header_count = array_length(headers, 1);
+  -- if we have less than 1 header, return NULL
+  IF header_count IS NULL OR header_count < 1 THEN
+    RETURN NULL;
+  -- if we have one header, return its id
+  ELSIF header_count = 1 THEN
+    RETURN headers[1].id;
+  -- if we have multiple headers we need to determine which one is canonical
+  ELSE
+    canonical_header = canonical_header_from_array(headers);
+    RETURN canonical_header.id;
+  END IF;
+END;
+$$;
 
 
 --
@@ -131,6 +227,39 @@ SELECT * FROM eth.header_cids WHERE block_number=$1 ORDER BY id
 $_$;
 
 
+--
+-- Name: has_child(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
+--
+
+CREATE FUNCTION public.has_child(hash character varying, height bigint) RETURNS public.child_result
+    LANGUAGE plpgsql
+    AS $$
+DECLARE
+  child_height INT;
+  temp_child eth.header_cids;
+  new_child_result child_result;
+BEGIN
+  child_height = height + 1;
+  -- short circuit if there are no children
+  SELECT exists(SELECT 1
+              FROM eth.header_cids
+              WHERE parent_hash = hash
+                AND block_number = child_height
+              LIMIT 1)
+  INTO new_child_result.has_child;
+  -- collect all the children for this header
+  IF new_child_result.has_child THEN
+    FOR temp_child IN
+    SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
+    LOOP
+      new_child_result.children = array_append(new_child_result.children, temp_child);
+    END LOOP;
+  END IF;
+  RETURN new_child_result;
+END
+$$;
+
+
 --
 -- Name: header_weight(character varying); Type: FUNCTION; Schema: public; Owner: -
 --
@@ -153,6 +282,80 @@ CREATE FUNCTION public.header_weight(hash character varying) RETURNS bigint
 $$;
 
 
+--
+-- Name: was_state_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
+--
+
+CREATE FUNCTION public.was_state_removed(path bytea, height bigint, hash character varying) RETURNS boolean
+    LANGUAGE sql
+    AS $$
+SELECT exists(SELECT 1
+              FROM eth.state_cids
+                INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
+              WHERE state_path = path
+                AND block_number > height
+                AND block_number <= (SELECT block_number
+                                     FROM eth.header_cids
+                                     WHERE block_hash = hash)
+                AND state_cids.node_type = 3
+              LIMIT 1);
+$$;
+
+
+--
+-- Name: was_storage_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
+--
+
+CREATE FUNCTION public.was_storage_removed(path bytea, height bigint, hash character varying) RETURNS boolean
+    LANGUAGE sql
+    AS $$
+SELECT exists(SELECT 1
+              FROM eth.storage_cids
+                INNER JOIN eth.state_cids ON (storage_cids.state_id = state_cids.id)
+                INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
+              WHERE storage_path = path
+                AND block_number > height
+                AND block_number <= (SELECT block_number
+                                     FROM eth.header_cids
+                                     WHERE block_hash = hash)
+                AND storage_cids.node_type = 3
+              LIMIT 1);
+$$;
+
+
+--
+-- Name: access_list_element; Type: TABLE; Schema: eth; Owner: -
+--
+
+CREATE TABLE eth.access_list_element (
+    id integer NOT NULL,
+    tx_id integer NOT NULL,
+    index integer NOT NULL,
+    address character varying(66),
+    storage_keys character varying(66)[]
+);
+
+
+--
+-- Name: access_list_element_id_seq; Type: SEQUENCE; Schema: eth; Owner: -
+--
+
+CREATE SEQUENCE eth.access_list_element_id_seq
+    AS integer
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: access_list_element_id_seq; Type: SEQUENCE OWNED BY; Schema: eth; Owner: -
+--
+
+ALTER SEQUENCE eth.access_list_element_id_seq OWNED BY eth.access_list_element.id;
+
+
 --
 -- Name: header_cids_id_seq; Type: SEQUENCE; Schema: eth; Owner: -
 --
@@ -269,7 +472,6 @@ CREATE TABLE eth.state_cids (
 --
 
 CREATE SEQUENCE eth.state_cids_id_seq
-    AS integer
     START WITH 1
     INCREMENT BY 1
     NO MINVALUE
@@ -305,7 +507,6 @@ CREATE TABLE eth.storage_cids (
 --
 
 CREATE SEQUENCE eth.storage_cids_id_seq
-    AS integer
     START WITH 1
     INCREMENT BY 1
     NO MINVALUE
@@ -333,7 +534,8 @@ CREATE TABLE eth.transaction_cids (
     mh_key text NOT NULL,
     dst character varying(66) NOT NULL,
     src character varying(66) NOT NULL,
-    tx_data bytea
+    tx_data bytea,
+    tx_type bytea
 );
 
 
@@ -489,6 +691,13 @@ CREATE SEQUENCE public.nodes_id_seq
 ALTER SEQUENCE public.nodes_id_seq OWNED BY public.nodes.id;
 
 
+--
+-- Name: access_list_element id; Type: DEFAULT; Schema: eth; Owner: -
+--
+
+ALTER TABLE ONLY eth.access_list_element ALTER COLUMN id SET DEFAULT nextval('eth.access_list_element_id_seq'::regclass);
+
+
 --
 -- Name: header_cids id; Type: DEFAULT; Schema: eth; Owner: -
 --
@@ -552,6 +761,22 @@ ALTER TABLE ONLY public.goose_db_version ALTER COLUMN id SET DEFAULT nextval('pu
 ALTER TABLE ONLY public.nodes ALTER COLUMN id SET DEFAULT nextval('public.nodes_id_seq'::regclass);
 
 
+--
+-- Name: access_list_element access_list_element_pkey; Type: CONSTRAINT; Schema: eth; Owner: -
+--
+
+ALTER TABLE ONLY eth.access_list_element
+    ADD CONSTRAINT access_list_element_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: access_list_element access_list_element_tx_id_index_key; Type: CONSTRAINT; Schema: eth; Owner: -
+--
+
+ALTER TABLE ONLY eth.access_list_element
+    ADD CONSTRAINT access_list_element_tx_id_index_key UNIQUE (tx_id, index);
+
+
 --
 -- Name: header_cids header_cids_block_number_block_hash_key; Type: CONSTRAINT; Schema: eth; Owner: -
 --
@@ -696,6 +921,13 @@ ALTER TABLE ONLY public.nodes
     ADD CONSTRAINT nodes_pkey PRIMARY KEY (id);
 
 
+--
+-- Name: accesss_list_element_address_index; Type: INDEX; Schema: eth; Owner: -
+--
+
+CREATE INDEX accesss_list_element_address_index ON eth.access_list_element USING btree (address);
+
+
 --
 -- Name: account_state_id_index; Type: INDEX; Schema: eth; Owner: -
 --
@@ -983,6 +1215,14 @@ CREATE TRIGGER transaction_cids_ai AFTER INSERT ON eth.transaction_cids FOR EACH
 CREATE TRIGGER uncle_cids_ai AFTER INSERT ON eth.uncle_cids FOR EACH ROW EXECUTE FUNCTION eth.graphql_subscription('uncle_cids', 'id');
 
 
+--
+-- Name: access_list_element access_list_element_tx_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
+--
+
+ALTER TABLE ONLY eth.access_list_element
+    ADD CONSTRAINT access_list_element_tx_id_fkey FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids(id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
+
+
 --
 -- Name: header_cids header_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
 --