Browse Source

Fix error and add helper tables

master
Thomas Chevalier 2 years ago
parent
commit
9c48eda057
  1. 110
      pgsql-schema.sql
  2. 2
      ulogd.conf

110
pgsql-schema.sql

@ -1,17 +1,16 @@
-- vi: et ai ts=2
--
-- Warning: postgresql >= 8.2 is required for the 'DROP .. IF EXISTS'
-- Warning: this script DESTROYS EVERYTHING !
--
--
-- Warning: postgresql >= 9.1 is required for the 'CREATE TABLE IF NOT EXISTS'
--
-- 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 (
--
CREATE TABLE IF NOT EXISTS ct_logs (
ct_id bigint PRIMARY KEY UNIQUE NOT NULL,
oob_family smallint default NULL,
orig_ip_saddr_str inet default NULL,
@ -36,9 +35,39 @@ CREATE TABLE IF NOT EXISTS ulog2_ct (
ct_event smallint default 0
);
--
-- Table used to build the argument list passed by ulog
-- It contains the flow_{start, end}_{sec, usec} variables
-- instead of the timestamps
CREATE TABLE IF NOT EXISTS ulog2_ct_model (
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_sec bigint default 0,
flow_start_usec bigint default 0,
flow_end_sec bigint default 0,
flow_end_usec bigint default 0,
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);
@ -51,9 +80,54 @@ CREATE TABLE IF NOT EXISTS ulog2_ct (
-- CREATE INDEX ulog2_ct_reply_l4_dport ON ulog2_ct(reply_l4_dport);
-- CREATE INDEX ulog2_ct_event ON ulog2_ct(ct_event);
--
--
-- Helper tables
--
DROP TABLE IF EXISTS ip_proto;
CREATE TABLE ip_proto (
proto_id serial PRIMARY KEY UNIQUE NOT NULL,
proto_name varchar(16) default NULL,
proto_desc varchar(255) default NULL
);
-- see files /etc/protocols
-- or /usr/share/nmap/nmap-protocols
INSERT INTO ip_proto (proto_id,proto_name,proto_desc) VALUES
(0,'ip','internet protocol, pseudo protocol number'),
(1,'icmp','internet control message protocol'),
(2,'igmp','Internet Group Management'),
(3,'ggp','gateway-gateway protocol'),
(4,'ipencap',E'IP encapsulated in IP (officially \'IP\')'),
(5,'st','ST datagram mode'),
(6,'tcp','transmission control protocol'),
(17,'udp','user datagram protocol'),
(41,'ipv6','Internet Protocol, version 6'),
(132,'sctp','Stream Control Transmission Protocol'),
(58,'ipv6-icmp','ICMP for IPv6');
DROP TABLE IF EXISTS ct_event;
CREATE TABLE ct_event (
event_id serial PRIMARY KEY UNIQUE NOT NULL,
event_name varchar(16) default NULL
);
INSERT INTO ct_event (event_id,event_name) VALUES
(1,'NEW'),
(2,'UPDATE'),
(4,'DESTROY');
--
-- Views
--
CREATE OR REPLACE VIEW view_log AS
SELECT * FROM ct_logs
INNER JOIN ip_proto ON ct_logs.orig_ip_protocol = ip_proto.proto_id
INNER JOIN ct_event ON ct_logs.ct_event = ct_event.event_id;
--
-- Procedures
--
--
CREATE OR REPLACE FUNCTION INSERT_CT(
IN _ct_id bigint,
@ -84,14 +158,14 @@ CREATE OR REPLACE FUNCTION INSERT_CT(
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,
INSERT INTO ct_logs (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,
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($20) + $21 * interval '1 microsecond',
to_timestamp($22) + $23 * interval '1 microsecond',
$24);
_id = $1;
@ -131,7 +205,7 @@ DECLARE
BEGIN
IF (_ct_event = 4) THEN
if (_orig_ip_protocol = 1) THEN
UPDATE ulog2_ct SET (orig_raw_pktlen, orig_raw_pktcount,
UPDATE ct_logs 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)
@ -139,10 +213,10 @@ BEGIN
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 icmp_code = $17 AND icmp_type = $18
AND ct_event < 4;
ELSE
UPDATE ulog2_ct SET (orig_raw_pktlen, orig_raw_pktcount,
UPDATE ct_logs 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)
@ -151,7 +225,7 @@ BEGIN
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 reply_l4_dport = $14
AND ct_event < 4;
END IF;
ELSE

2
ulogd.conf

@ -66,6 +66,6 @@ db=""
host=""
user=""
pass=""
table="ulog2_ct"
table="ulog2_ct_model"
procedure="INSERT_OR_REPLACE_CT"
connstring="dbname=ulog user=ulog password=CHANGE_ME"

Loading…
Cancel
Save