Dplacement
darcs-hash:20050831233129-6d78a-2ef5f572a45e3e6178edeca255fbd1159444b780.gz
This commit is contained in:
parent
f3d04aa223
commit
db137d4ca3
5 changed files with 897 additions and 0 deletions
192
surveillance/filtrage.sql
Normal file
192
surveillance/filtrage.sql
Normal file
|
@ -0,0 +1,192 @@
|
|||
-- Fichier permttant de reconstituer la base de données de filtrage des logs
|
||||
-- de net-acct et du firewall
|
||||
-- Pour regénérer la base :
|
||||
-- Dropper la bose en tant qu'utilisateur postgres : dropdb filtrage
|
||||
-- Créer la base avec l'utilisateur crans (par exemple) :
|
||||
-- createdb -O crans filtrage
|
||||
-- exécuter en tant qu'utilisateur :
|
||||
-- psql filtrage -U crans < filtrage.sql
|
||||
|
||||
|
||||
BEGIN;
|
||||
-- Création de la table de protocole de type udp .. : index(1,16,17) | nom (,tcp,udp)
|
||||
CREATE TABLE protocole (
|
||||
id integer NOT NULL,
|
||||
nom text NOT NULL,
|
||||
CONSTRAINT id_protocole PRIMARY KEY (id));
|
||||
|
||||
|
||||
-- Création de la table de protocole p2p : (1,2,3,...)|(eMule,SoulSeak, ...)
|
||||
CREATE TABLE protocole_p2p (
|
||||
id_p2p serial NOT NULL,
|
||||
nom text NOT NULL,
|
||||
CONSTRAINT id_p2p_protocole PRIMARY KEY (id_p2p));
|
||||
|
||||
|
||||
-- Table Virus : date | source | destinataire | protocole | port source | port dest
|
||||
CREATE TABLE virus (
|
||||
date timestamp NOT NULL,
|
||||
ip_src inet NOT NULL,
|
||||
ip_dest inet NOT NULL,
|
||||
id integer NOT NULL,
|
||||
port_src integer NOT NULL,
|
||||
port_dest integer NOT NULL,
|
||||
CONSTRAINT virus_protocole FOREIGN KEY (id) REFERENCES protocole (id));
|
||||
|
||||
|
||||
-- Table upload : date | source | destinataire | protocole | port source | port dest | download | upload
|
||||
CREATE TABLE upload (
|
||||
date timestamp NOT NULL,
|
||||
ip_crans inet NOT NULL,
|
||||
ip_ext inet NOT NULL,
|
||||
id integer NOT NULL,
|
||||
port_crans integer NOT NULL,
|
||||
port_ext integer NOT NULL,
|
||||
download bigint NOT NULL,
|
||||
upload bigint NOT NULL,
|
||||
CONSTRAINT upload_protocole FOREIGN KEY (id) REFERENCES protocole (id));
|
||||
|
||||
-- Table p2p : date | source | destinataire | protocole p2p | port source | port dest
|
||||
CREATE TABLE p2p (
|
||||
date timestamp NOT NULL,
|
||||
ip_src inet NOT NULL,
|
||||
ip_dest inet NOT NULL,
|
||||
id_p2p integer NOT NULL,
|
||||
id integer NOT NULL,
|
||||
port_src integer NOT NULL,
|
||||
port_dest integer NOT NULL,
|
||||
CONSTRAINT p2p_id_protocole FOREIGN KEY (id) REFERENCES protocole (id),
|
||||
CONSTRAINT p2p_id_p2p_protocole FOREIGN KEY (id_p2p) REFERENCES protocole_p2p (id_p2p));
|
||||
|
||||
-- Table des avertis pour upload
|
||||
CREATE TABLE avertis_upload (
|
||||
date timestamp NOT NULL,
|
||||
ip_crans inet NOT NULL,
|
||||
soft boolean,
|
||||
hard boolean,
|
||||
sanctions boolean);
|
||||
|
||||
-- Table des infectes
|
||||
CREATE TABLE avertis_virus (
|
||||
date timestamp NOT NULL,
|
||||
ip_crans inet NOT NULL);
|
||||
|
||||
-- Table des infectes
|
||||
CREATE TABLE avertis_p2p (
|
||||
date timestamp NOT NULL,
|
||||
ip_crans inet NOT NULL,
|
||||
protocole text NOT NULL);
|
||||
|
||||
-- Table des sanctionnés pour upload :
|
||||
CREATE TABLE sanctions (
|
||||
date timestamp NOT NULL,
|
||||
aid integer NOT NULL,
|
||||
penalite integer NOT NULL);
|
||||
|
||||
-- Table des exemptés :
|
||||
CREATE TABLE exemptes (
|
||||
ip_crans inet NOT NULL,
|
||||
ip_dest inet NOT NULL);
|
||||
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.136.0/28','0.0.0.0/0'); -- crans vers le reste
|
||||
-- du monde
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.136.0/21','138.231.0.0/16'); -- crans vers ens
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.148.0/22','138.231.0.0/16'); -- wifi crans vers ens
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.149.10','129.104.17.0/24'); -- rivendell vers jussieux
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.141.187','129.104.17.0/24'); -- barad-dur vers jussieux
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.149.10','134.157.96.216'); -- rivendell vers polytechnique
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.141.187','134.157.96.216'); -- barad-dur vers polytechnique
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.137.230','129.175.100.221'); -- helene vers orsay
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.139.106','138.195.74.0/24'); -- schuss vers centrale
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.139.106','138.195.75.0/24'); -- schuss vers centrale
|
||||
INSERT INTO exemptes (ip_crans,ip_dest) VALUES
|
||||
('138.231.137.25','157.99.164.27'); -- sayan vers
|
||||
-- chile.sysbio.pasteur.fr
|
||||
|
||||
|
||||
|
||||
-- Protocole udp ...
|
||||
INSERT INTO protocole VALUES (1,'ICMP');
|
||||
INSERT INTO protocole VALUES (2,'IGMP');
|
||||
INSERT INTO protocole VALUES (3,'GGP');
|
||||
INSERT INTO protocole VALUES (4,'IPENCAP');
|
||||
INSERT INTO protocole VALUES (5,'ST');
|
||||
INSERT INTO protocole VALUES (6,'TCP');
|
||||
INSERT INTO protocole VALUES (8,'EGP');
|
||||
INSERT INTO protocole VALUES (9,'IGP');
|
||||
INSERT INTO protocole VALUES (12,'PUP');
|
||||
INSERT INTO protocole VALUES (17,'UDP');
|
||||
INSERT INTO protocole VALUES (20,'HMP');
|
||||
INSERT INTO protocole VALUES (22,'XNS-IDP');
|
||||
INSERT INTO protocole VALUES (27,'RDP');
|
||||
INSERT INTO protocole VALUES (29,'ISO-TP4');
|
||||
INSERT INTO protocole VALUES (36,'XTP');
|
||||
INSERT INTO protocole VALUES (37,'DDP');
|
||||
INSERT INTO protocole VALUES (38,'IDPR-CMTP');
|
||||
INSERT INTO protocole VALUES (41,'IPV6');
|
||||
INSERT INTO protocole VALUES (43,'IPV6-ROUTE');
|
||||
INSERT INTO protocole VALUES (44,'IPV6-FRAG');
|
||||
INSERT INTO protocole VALUES (45,'IDRP');
|
||||
INSERT INTO protocole VALUES (46,'RSVP');
|
||||
INSERT INTO protocole VALUES (47,'GRE');
|
||||
INSERT INTO protocole VALUES (50,'IPSEC-ESP');
|
||||
INSERT INTO protocole VALUES (51,'IPSEC-AH');
|
||||
INSERT INTO protocole VALUES (57,'SKIP');
|
||||
INSERT INTO protocole VALUES (58,'IPV6-ICMP');
|
||||
INSERT INTO protocole VALUES (59,'IPV6-NONXT');
|
||||
INSERT INTO protocole VALUES (60,'IPV6-OPTS');
|
||||
INSERT INTO protocole VALUES (73,'RSPF');
|
||||
INSERT INTO protocole VALUES (81,'VWTP');
|
||||
INSERT INTO protocole VALUES (88,'EIGRP');
|
||||
INSERT INTO protocole VALUES (89,'OSPFIGP');
|
||||
INSERT INTO protocole VALUES (93,'AX-25');
|
||||
INSERT INTO protocole VALUES (94,'IPIP');
|
||||
INSERT INTO protocole VALUES (97,'ETHERIP');
|
||||
INSERT INTO protocole VALUES (98,'ENCAP');
|
||||
INSERT INTO protocole VALUES (103,'PIM');
|
||||
INSERT INTO protocole VALUES (108,'IPCOMP');
|
||||
INSERT INTO protocole VALUES (112,'VRRP');
|
||||
INSERT INTO protocole VALUES (115,'LSTP');
|
||||
INSERT INTO protocole VALUES (124,'ISIS');
|
||||
INSERT INTO protocole VALUES (132,'SCTP');
|
||||
INSERT INTO protocole VALUES (133,'FC');
|
||||
|
||||
-- Protocoles p2p
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('Bittorrent');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('AppleJuice');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('SoulSeek');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('WinMX');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('eDonkey');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('DirectConnect');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('KaZaa');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('Ares');
|
||||
INSERT INTO protocole_p2p (nom) VALUES ('GNUtella');
|
||||
|
||||
|
||||
-- Création des index
|
||||
CREATE INDEX date_virus_idx ON virus (date);
|
||||
CREATE INDEX ip_src_virux_idx ON virus (ip_src);
|
||||
CREATE INDEX id_virus_idx ON virus (id);
|
||||
|
||||
CREATE INDEX date_upload_idx ON upload (date);
|
||||
CREATE INDEX id_upload_idx ON upload (id);
|
||||
CREATE INDEX ip_crans_upload_idx ON upload (ip_crans);
|
||||
|
||||
CREATE INDEX date_p2p_idx ON p2p (date);
|
||||
CREATE INDEX ip_src_p2p_idx ON p2p (ip_src);
|
||||
CREATE INDEX id_p2p_idx ON p2p (id);
|
||||
CREATE INDEX id_p2p_p2p_idx ON p2p (id_p2p);
|
||||
|
||||
|
||||
|
||||
COMMIT;
|
Loading…
Add table
Add a link
Reference in a new issue