Skip to content

Commit

Permalink
added the names_to_addrs function
Browse files Browse the repository at this point in the history
  • Loading branch information
caffix committed Mar 8, 2024
1 parent b2afefe commit 3372618
Showing 1 changed file with 68 additions and 0 deletions.
68 changes: 68 additions & 0 deletions initdb-assetdb.sh
Original file line number Diff line number Diff line change
Expand Up @@ -22,4 +22,72 @@ psql -v ON_ERROR_STOP=1 --username "$POSTGRES_USER" --dbname "$AMASS_DB" <<-EOSQ
GRANT USAGE ON SCHEMA public TO :username;
GRANT CREATE ON SCHEMA public TO :username;
GRANT ALL ON ALL TABLES IN SCHEMA public TO :username;
CREATE OR REPLACE FUNCTION names_to_addrs(TEXT, TIMESTAMP WITH TIME ZONE, TIMESTAMP WITH TIME ZONE) RETURNS TABLE(fqdn TEXT, ip_addr TEXT) AS \$BODY\$
DECLARE
_name TEXT;
_names TEXT[];
_var_r RECORD;
_to TIMESTAMP;
_from TIMESTAMP;
BEGIN
_to = \$3;
_from = \$2;
_names = string_to_array(\$1, ',');
FOR _var_r IN (
SELECT srvs.content->>'name' AS "name", ips.content->>'address' AS "addr"
FROM ((((assets AS fqdns INNER JOIN relations AS r1 ON fqdns.id = r1.from_asset_id)
INNER JOIN assets AS srvs ON r1.to_asset_id = srvs.id) INNER JOIN relations AS r2 ON srvs.id =
r2.from_asset_id) INNER JOIN assets AS ips ON r2.to_asset_id = ips.id)
WHERE fqdns.type = 'FQDN' AND srvs.type = 'FQDN' AND ips.type = 'IPAddress'
AND r1.type IN ('srv_record','ns_record','mx_record') AND r2.type IN ('a_record','aaaa_record')
AND r1.last_seen >= _from AND r1.last_seen <= _to AND r2.last_seen >= _from AND r2.last_seen <= _to
AND fqdns.content->>'name' = ANY(_names)
) LOOP fqdn = _var_r.name;
ip_addr = _var_r.addr;
_names = array_remove(_names, _var_r.name);
RETURN NEXT;
END LOOP;
FOR _var_r IN (
SELECT fqdns.content->>'name' AS "name", ips.content->>'address' AS "addr"
FROM ((assets AS fqdns
INNER JOIN relations ON fqdns.id = relations.from_asset_id)
INNER JOIN assets AS ips ON relations.to_asset_id = ips.id)
WHERE fqdns.type = 'FQDN' AND ips.type = 'IPAddress'
AND relations.type IN ('a_record', 'aaaa_record')
AND relations.last_seen >= _from AND relations.last_seen <= _to
AND fqdns.content->>'name' = ANY(_names)
) LOOP fqdn = _var_r.name;
ip_addr = _var_r.addr;
_names = array_remove(_names, _var_r.name);
RETURN NEXT;
END LOOP;
FOREACH _name IN ARRAY _names LOOP
FOR _var_r IN (
WITH RECURSIVE traverse_cname(_fqdn) AS (
VALUES(_name)
UNION
SELECT cnames.content->>'name' FROM ((assets AS fqdns
INNER JOIN relations ON fqdns.id = relations.from_asset_id)
INNER JOIN assets AS cnames ON relations.to_asset_id = cnames.id), traverse_cname
WHERE fqdns.type = 'FQDN' AND cnames.type = 'FQDN'
AND relations.last_seen >= _from AND relations.last_seen <= _to
AND relations.type = 'cname_record' AND fqdns.content->>'name' = traverse_cname._fqdn)
SELECT fqdns.content->>'name' AS "name", ips.content->>'address' AS "addr"
FROM ((assets AS fqdns INNER JOIN relations ON fqdns.id = relations.from_asset_id)
INNER JOIN assets AS ips ON relations.to_asset_id = ips.id)
WHERE fqdns.type = 'FQDN' AND ips.type = 'IPAddress'
AND relations.last_seen >= _from AND relations.last_seen <= _to
AND relations.type IN ('a_record', 'aaaa_record')
AND fqdns.content->>'name' IN (SELECT _fqdn FROM traverse_cname)
) LOOP fqdn = _name;
ip_addr = _var_r.addr;
RETURN NEXT;
END LOOP;
END LOOP;
END
\$BODY\$ LANGUAGE plpgsql IMMUTABLE STRICT;
EOSQL

0 comments on commit 3372618

Please sign in to comment.