firewall/pgsql-schema.sql

166 lines
6.7 KiB
PL/PgSQL

-- vi: et ai ts=2
--
-- Warning: postgresql >= 8.2 is required for the 'DROP .. IF EXISTS'
-- Warning: this script DESTROYS EVERYTHING !
--
-- NOTE : - we could / should use types cidr / inet / macaddr for IP ? (see http://www.postgresql.org/docs/8.2/static/datatype-net-types.html)
-- - ON UPDATE is not supported ?
-- - type 'integer' is used (we have to check for overflows ..)
-- - type 'datetime' has been replaced by 'timestamp'
--
-- conntrack
--
CREATE TABLE IF NOT EXISTS ulog2_ct (
ct_id bigint PRIMARY KEY UNIQUE NOT NULL,
oob_family smallint default NULL,
orig_ip_saddr_str inet default NULL,
orig_ip_daddr_str inet default NULL,
orig_ip_protocol smallint default NULL,
orig_l4_sport integer default NULL,
orig_l4_dport integer default NULL,
orig_raw_pktlen bigint default 0,
orig_raw_pktcount bigint default 0,
reply_ip_saddr_str inet default NULL,
reply_ip_daddr_str inet default NULL,
reply_ip_protocol smallint default NULL,
reply_l4_sport integer default NULL,
reply_l4_dport integer default NULL,
reply_raw_pktlen bigint default 0,
reply_raw_pktcount bigint default 0,
icmp_code smallint default NULL,
icmp_type smallint default NULL,
ct_mark bigint default 0,
flow_start timestamp default NULL,
flow_end timestamp default NULL,
ct_event smallint default 0
);
--
-- Additional INDEX
--
-- CREATE INDEX ulog2_ct_oob_family ON ulog2_ct(oob_family);
-- CREATE INDEX ulog2_ct_orig_ip_saddr ON ulog2_ct(orig_ip_saddr_str);
-- CREATE INDEX ulog2_ct_orig_ip_daddr ON ulog2_ct(orig_ip_daddr_str);
-- CREATE INDEX ulog2_ct_reply_ip_saddr ON ulog2_ct(reply_ip_saddr_str);
-- CREATE INDEX ulog2_ct_reply_ip_daddr ON ulog2_ct(reply_ip_daddr_str);
-- CREATE INDEX ulog2_ct_orig_l4_sport ON ulog2_ct(orig_l4_sport);
-- CREATE INDEX ulog2_ct_orig_l4_dport ON ulog2_ct(orig_l4_dport);
-- CREATE INDEX ulog2_ct_reply_l4_sport ON ulog2_ct(reply_l4_sport);
-- CREATE INDEX ulog2_ct_reply_l4_dport ON ulog2_ct(reply_l4_dport);
-- CREATE INDEX ulog2_ct_event ON ulog2_ct(ct_event);
--
-- Procedures
--
CREATE OR REPLACE FUNCTION INSERT_CT(
IN _ct_id bigint,
IN _oob_family integer,
IN _orig_ip_saddr inet,
IN _orig_ip_daddr inet,
IN _orig_ip_protocol integer,
IN _orig_l4_sport integer,
IN _orig_l4_dport integer,
IN _orig_raw_pktlen bigint,
IN _orig_raw_pktcount bigint,
IN _reply_ip_saddr inet,
IN _reply_ip_daddr inet,
IN _reply_ip_protocol integer,
IN _reply_l4_sport integer,
IN _reply_l4_dport integer,
IN _reply_raw_pktlen bigint,
IN _reply_raw_pktcount bigint,
IN _icmp_code integer,
IN _icmp_type integer,
IN _ct_mark bigint,
IN _flow_start_sec bigint,
IN _flow_start_usec bigint,
IN _flow_end_sec bigint,
IN _flow_end_usec bigint,
IN _ct_event integer
)
RETURNS bigint AS $$
DECLARE _id bigint;
BEGIN
INSERT INTO ulog2_ct (ct_id, oob_family, orig_ip_saddr_str, orig_ip_daddr_str, orig_ip_protocol,
orig_l4_sport, orig_l4_dport, orig_raw_pktlen, orig_raw_pktcount,
reply_ip_saddr_str, reply_ip_daddr_str, reply_ip_protocol,
reply_l4_sport, reply_l4_dport, reply_raw_pktlen, reply_raw_pktcount,
icmp_code, icmp_type, ct_mark,
flow_start, flow_end, ct_event)
VALUES ($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12,$13,$14,$15,$16,$17,$18,$19,
to_timestamp($20) + $21 * interval '1 microsecond'
to_timestamp($22) + $23 * interval '1 microsecond',
$24);
_id = $1;
RETURN _id;
END
$$ LANGUAGE plpgsql SECURITY INVOKER;
CREATE OR REPLACE FUNCTION INSERT_OR_REPLACE_CT(
IN _ct_id bigint,
IN _oob_family integer,
IN _orig_ip_saddr inet,
IN _orig_ip_daddr inet,
IN _orig_ip_protocol integer,
IN _orig_l4_sport integer,
IN _orig_l4_dport integer,
IN _orig_raw_pktlen bigint,
IN _orig_raw_pktcount bigint,
IN _reply_ip_saddr inet,
IN _reply_ip_daddr inet,
IN _reply_ip_protocol integer,
IN _reply_l4_sport integer,
IN _reply_l4_dport integer,
IN _reply_raw_pktlen bigint,
IN _reply_raw_pktcount bigint,
IN _icmp_code integer,
IN _icmp_type integer,
IN _ct_mark bigint,
IN _flow_start_sec bigint,
IN _flow_start_usec bigint,
IN _flow_end_sec bigint,
IN _flow_end_usec bigint,
IN _ct_event integer
)
RETURNS bigint AS $$
DECLARE
_id bigint;
BEGIN
IF (_ct_event = 4) THEN
if (_orig_ip_protocol = 1) THEN
UPDATE ulog2_ct SET (orig_raw_pktlen, orig_raw_pktcount,
reply_raw_pktlen, reply_raw_pktcount,
ct_mark, flow_end, ct_event)
= ($8,$9,$15,$16,$19,to_timestamp($22) + $23 * interval '1 microsecond',$24)
WHERE ct_id=$1 AND oob_family=$2 AND orig_ip_saddr_str = $3
AND orig_ip_daddr_str = $4 AND orig_ip_protocol = $5
AND reply_ip_saddr_str = $10 AND reply_ip_daddr_str = $11
AND reply_ip_protocol = $12
AND icmp_code = $17 AND icmp_type = $18
AND ct_event < 4;
ELSE
UPDATE ulog2_ct SET (orig_raw_pktlen, orig_raw_pktcount,
reply_raw_pktlen, reply_raw_pktcount,
ct_mark, flow_end, ct_event)
= ($8,$9,$15,$16,$19,to_timestamp($22) + $23 * interval '1 microsecond',$24)
WHERE ct_id=$1 AND oob_family=$2 AND orig_ip_saddr_str = $3
AND orig_ip_daddr_str = $4 AND orig_ip_protocol = $5
AND orig_l4_sport = $6 AND orig_l4_dport = $7
AND reply_ip_saddr_str = $10 AND reply_ip_daddr_str = $11
AND reply_ip_protocol = $12 AND reply_l4_sport = $13
AND reply_l4_dport = $14
AND ct_event < 4;
END IF;
ELSE
_id := INSERT_CT($1,$2,$3,$4,$5,$6,$7,$8,$9,$10,$11,$12,$13,$14,$15,$16,$17,$18,$19,$20,$21,$22,$23,$24);
END IF;
RETURN _id;
END
$$ LANGUAGE plpgsql SECURITY INVOKER;
-- Created by Pierre Chifflier <chifflier AT inl DOT fr>
-- Adapted by Thomas Chevalier <contact AT tchevalier DOT fr>