-
Notifications
You must be signed in to change notification settings - Fork 12
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
23 changed files
with
295 additions
and
367 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,27 +1,95 @@ | ||
-- +migrate Up | ||
|
||
CREATE TABLE IF NOT EXISTS assets( | ||
id SERIAL PRIMARY KEY, | ||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, | ||
type VARCHAR(255), | ||
content JSONB); | ||
CREATE TABLE IF NOT EXISTS entities( | ||
entity_id INT GENERATED ALWAYS AS IDENTITY, | ||
created_at TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
last_seen TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
etype VARCHAR(255), | ||
content JSONB, | ||
PRIMARY KEY(entity_id) | ||
); | ||
|
||
CREATE INDEX idx_entities_last_seen ON entities (last_seen); | ||
CREATE INDEX idx_entities_etype ON entities (etype); | ||
|
||
CREATE TABLE IF NOT EXISTS entity_properties( | ||
property_id INT GENERATED ALWAYS AS IDENTITY, | ||
created_at TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
last_seen TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
ptype VARCHAR(255), | ||
content JSONB, | ||
entity_id INT, | ||
PRIMARY KEY(property_id) | ||
CONSTRAINT fk_entity_properties_entities | ||
FOREIGN KEY(entity_id) | ||
REFERENCES entities(entity_id) | ||
ON DELETE CASCADE | ||
); | ||
|
||
CREATE INDEX idx_entprop_last_seen ON entity_properties (last_seen); | ||
CREATE INDEX idx_entprop_ptype ON entity_properties (ptype); | ||
CREATE INDEX idx_entprop_entity_id ON entity_properties (entity_id); | ||
|
||
CREATE TABLE IF NOT EXISTS relations( | ||
id SERIAL PRIMARY KEY, | ||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, | ||
type VARCHAR(255), | ||
from_asset_id INT, | ||
to_asset_id INT, | ||
CONSTRAINT fk_from_asset | ||
FOREIGN KEY (from_asset_id) | ||
REFERENCES assets(id) | ||
ON DELETE CASCADE, | ||
CONSTRAINT fk_to_asset | ||
FOREIGN KEY (to_asset_id) | ||
REFERENCES assets(id) | ||
ON DELETE CASCADE); | ||
relation_id INT GENERATED ALWAYS AS IDENTITY, | ||
created_at TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
last_seen TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
rtype VARCHAR(255), | ||
content JSONB, | ||
from_entity_id INT, | ||
to_entity_id INT, | ||
PRIMARY KEY(relation_id) | ||
CONSTRAINT fk_relations_entities_from | ||
FOREIGN KEY(from_entity_id) | ||
REFERENCES entities(entity_id) | ||
ON DELETE CASCADE, | ||
CONSTRAINT fk_relations_entities_to | ||
FOREIGN KEY(to_entity_id) | ||
REFERENCES entities(entity_id) | ||
ON DELETE CASCADE | ||
); | ||
|
||
CREATE INDEX idx_rel_last_seen ON relations (last_seen); | ||
CREATE INDEX idx_rel_rtype ON relations (rtype); | ||
CREATE INDEX idx_rel_from_entity_id ON relations (from_entity_id); | ||
CREATE INDEX idx_rel_to_entity_id ON relations (to_entity_id); | ||
|
||
CREATE TABLE IF NOT EXISTS relation_properties( | ||
property_id INT GENERATED ALWAYS AS IDENTITY, | ||
created_at TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
last_seen TIMESTAMP without time zone DEFAULT CURRENT_TIMESTAMP, | ||
ptype VARCHAR(255), | ||
content JSONB, | ||
relation_id INT, | ||
PRIMARY KEY(property_id) | ||
CONSTRAINT fk_relation_properties_relations | ||
FOREIGN KEY(relation_id) | ||
REFERENCES relations(relation_id) | ||
ON DELETE CASCADE | ||
); | ||
|
||
CREATE INDEX idx_relprop_last_seen ON relation_properties (last_seen); | ||
CREATE INDEX idx_relprop_ptype ON relation_properties (ptype); | ||
CREATE INDEX idx_relprop_relation_id ON relation_properties (relation_id); | ||
|
||
-- +migrate Down | ||
|
||
DROP INDEX IF EXISTS idx_relprop_relation_id; | ||
DROP INDEX IF EXISTS idx_relprop_ptype; | ||
DROP INDEX IF EXISTS idx_relprop_last_seen; | ||
DROP TABLE relation_properties; | ||
|
||
DROP INDEX IF EXISTS idx_rel_to_entity_id; | ||
DROP INDEX IF EXISTS idx_rel_from_entity_id; | ||
DROP INDEX IF EXISTS idx_rel_rtype; | ||
DROP INDEX IF EXISTS idx_rel_last_seen; | ||
DROP TABLE relations; | ||
DROP TABLE assets; | ||
|
||
DROP INDEX IF EXISTS idx_entprop_entity_id; | ||
DROP INDEX IF EXISTS idx_entprop_ptype; | ||
DROP INDEX IF EXISTS idx_entprop_last_seen; | ||
DROP TABLE entity_properties; | ||
|
||
DROP INDEX IF EXISTS idx_entities_etype; | ||
DROP INDEX IF EXISTS idx_entities_last_seen; | ||
DROP TABLE entities; |
This file was deleted.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,40 @@ | ||
-- +migrate Up | ||
|
||
-- Assumes the pg_trgm extension is created in the database | ||
CREATE INDEX idx_autnum_content_handle ON entities USING gin ((content->>'handle') gin_trgm_ops) WHERE etype = 'AutnumRecord'; | ||
CREATE INDEX idx_autnum_content_number ON entities USING gin ((content->>'number') gin_trgm_ops) WHERE etype = 'AutnumRecord'; | ||
CREATE INDEX idx_autsys_content_number ON entities USING gin ((content->>'number') gin_trgm_ops) WHERE etype = 'AutonomousSystem'; | ||
CREATE INDEX idx_domainrec_content_domain ON entities USING gin ((content->>'domain') gin_trgm_ops) WHERE etype = 'DomainRecord'; | ||
CREATE INDEX idx_email_content_address ON entities USING gin ((content->>'address') gin_trgm_ops) WHERE etype = 'EmailAddress'; | ||
CREATE INDEX idx_finger_content_value ON entities USING gin ((content->>'value') gin_trgm_ops) WHERE etype = 'Fingerprint'; | ||
CREATE INDEX idx_fqdn_content_name ON entities USING gin ((content->>'name') gin_trgm_ops) WHERE etype = 'FQDN'; | ||
CREATE INDEX idx_ipaddr_content_address ON entities USING gin ((content->>'address') gin_trgm_ops) WHERE etype = 'IPAddress'; | ||
CREATE INDEX idx_ipnetrec_content_cidr ON entities USING gin ((content->>'cidr') gin_trgm_ops) WHERE etype = 'IPNetRecord'; | ||
CREATE INDEX idx_ipnetrec_content_handle ON entities USING gin ((content->>'handle') gin_trgm_ops) WHERE etype = 'IPNetRecord'; | ||
CREATE INDEX idx_netblock_content_cidr ON entities USING gin ((content->>'cidr') gin_trgm_ops) WHERE etype = 'Netblock'; | ||
CREATE INDEX idx_netend_content_address ON entities USING gin ((content->>'address') gin_trgm_ops) WHERE etype = 'NetworkEndpoint'; | ||
CREATE INDEX idx_org_content_name ON entities USING gin ((content->>'name') gin_trgm_ops) WHERE etype = 'Organization'; | ||
CREATE INDEX idx_person_content_full_name ON entities USING gin ((content->>'full_name') gin_trgm_ops) WHERE etype = 'Person'; | ||
CREATE INDEX idx_sockaddr_content_address ON entities USING gin ((content->>'address') gin_trgm_ops) WHERE etype = 'SocketAddress'; | ||
CREATE INDEX idx_tls_content_serial_number ON entities USING gin ((content->>'serial_number') gin_trgm_ops) WHERE etype = 'TLSCertificate'; | ||
CREATE INDEX idx_url_content_url ON entities USING gin ((content->>'url') gin_trgm_ops) WHERE etype = 'URL'; | ||
|
||
-- +migrate Down | ||
|
||
DROP INDEX IF EXISTS idx_url_content_url; | ||
DROP INDEX IF EXISTS idx_tls_content_serial_number; | ||
DROP INDEX IF EXISTS idx_sockaddr_content_address; | ||
DROP INDEX IF EXISTS idx_person_content_full_name; | ||
DROP INDEX IF EXISTS idx_org_content_name; | ||
DROP INDEX IF EXISTS idx_netend_content_address; | ||
DROP INDEX IF EXISTS idx_netblock_content_cidr; | ||
DROP INDEX IF EXISTS idx_ipnetrec_content_handle; | ||
DROP INDEX IF EXISTS idx_ipnetrec_content_cidr; | ||
DROP INDEX IF EXISTS idx_ipaddr_content_address; | ||
DROP INDEX IF EXISTS idx_fqdn_content_name; | ||
DROP INDEX IF EXISTS idx_finger_content_value; | ||
DROP INDEX IF EXISTS idx_email_content_address; | ||
DROP INDEX IF EXISTS idx_domainrec_content_domain; | ||
DROP INDEX IF EXISTS idx_autsys_content_number; | ||
DROP INDEX IF EXISTS idx_autnum_content_handle; | ||
DROP INDEX IF EXISTS idx_autnum_content_number; |
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
Oops, something went wrong.