--- /dev/null
+--
+-- Populate P2P database with test data.
+--
+
+-- insert swarms in `swarms` table
+
+INSERT INTO swarms(torrent_filename, data_size)
+VALUES('DarkKnight.torrent', '123000');
+INSERT INTO swarms(torrent_filename, data_size)
+VALUES('Fedora.torrent', '1024');
+
+-- insert sessions in `client_sessions` table
+
+INSERT INTO client_sessions(swarm_id, btclient_id, system_os,
+ system_os_version, system_ram, system_cpu, public_ip, public_port,
+ ds_limit, us_limit, start_time)
+VALUES ('1', '2', 'Linux', '2.6.26', '512', '1500', '141.85.224.205',
+ '50500', '512', '64', '2010-10-09 12:43:21');
+INSERT INTO client_sessions(swarm_id, btclient_id, system_os,
+ system_os_version, system_ram, system_cpu, public_ip, public_port,
+ ds_limit, us_limit, start_time)
+VALUES('2', '4', 'Linux', '2.6.26', '512', '1500', '141.85.224.209',
+ '40400', '512', '64', '2010-10-09 12:29:41');
+
+-- insert messages in `status_messages` table
+
+INSERT INTO status_messages(client_session_id, timestamp, num_peers,
+ num_dht_peers, download_speed, upload_speed,
+ download_size, upload_size)
+VALUES('1', '2010-09-23 09:32:43', '222', '0', '213',
+ '56', '200', '300');
+INSERT INTO status_messages(client_session_id, timestamp, num_peers,
+ num_dht_peers, download_speed, upload_speed,
+ download_size, upload_size)
+VALUES('2', '2010-09-23 09:32:44', '222', '0', '213',
+ '56', '200', '300');
+
+-- insert messages in `peer_status_messages` table
+
+INSERT INTO peer_status_messages(client_session_id, timestamp, peer_ip,
+ peer_port, download_speed, upload_speed)
+VALUES('1', '2010-09-23 09:30:00', '141.85.37.24',
+ '12345', '23', '74');
+INSERT INTO peer_status_messages(client_session_id, timestamp, peer_ip,
+ peer_port, download_speed, upload_speed)
+VALUES('2', '2010-09-23 09:30:05', '141.85.37.29',
+ '13254', '32', '47');
+
+-- insert messages in `verbose_messages` table
+
+INSERT INTO verbose_messages(client_session_id, timestamp,
+ transfer_direction_id, peer_ip, peer_port, message_type_id)
+VALUES('1', '2010-09-23 09:32:45', '1', '127.0.0.1',
+ '1345', '2');
+INSERT INTO verbose_messages(client_session_id, timestamp,
+ transfer_direction_id, peer_ip, peer_port, message_type_id)
+VALUES('2', '2010-09-23 09:32:46', '2', '127.0.0.1',
+ '1345', '3');
--- /dev/null
+--
+-- Create tables in BitTorrent log analysis database in MySQL.
+-- Use indexes for fast access.
+--
+-- 2011, Mariana Marasoiu, mariana.marasoiu@gmail.com
+-- 2011, Razvan Deaconescu, razvan.deaconescu@cs.pub.ro
+-- - add foreign key support
+-- - add indexes
+-- - add message_types and peer_status_messages tables
+-- - update column types
+--
+
+DROP TABLE IF EXISTS btclients;
+DROP TABLE IF EXISTS swarms;
+DROP TABLE IF EXISTS client_sessions;
+DROP TABLE IF EXISTS status_messages;
+DROP TABLE IF EXISTS peer_status_messages;
+DROP TABLE IF EXISTS transfer_directions;
+DROP TABLE IF EXISTS message_types;
+DROP TABLE IF EXISTS verbose_messages;
+
+CREATE TABLE btclients (
+ id INTEGER UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ name VARCHAR(100) NOT NULL,
+ language VARCHAR(100) NOT NULL,
+ url VARCHAR(255),
+ dht_support BOOLEAN NOT NULL DEFAULT FALSE,
+ streaming_support BOOLEAN NOT NULL DEFAULT FALSE,
+ pxe_support BOOLEAN NOT NULL DEFAULT FALSE,
+ features VARCHAR(1024)
+) ENGINE=InnoDB;
+
+CREATE TABLE swarms (
+ id INTEGER UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ torrent_filename VARCHAR(255),
+ data_size INTEGER UNSIGNED,
+ description VARCHAR(4096)
+) ENGINE=InnoDB;
+
+CREATE TABLE client_sessions (
+ id INTEGER UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ swarm_id INTEGER UNSIGNED NOT NULL REFERENCES swarms(id) ON DELETE CASCADE ON UPDATE CASCADE,
+ btclient_id INTEGER UNSIGNED NOT NULL REFERENCES btclients(id) ON DELETE CASCADE ON UPDATE CASCADE,
+ system_os VARCHAR(100),
+ system_os_version VARCHAR(100),
+ -- system RAM in megabytes
+ system_ram SMALLINT UNSIGNED,
+ -- system CPU in MHz
+ system_cpu SMALLINT UNSIGNED,
+ -- beware of IPv6
+ public_ip VARCHAR(100),
+ public_port SMALLINT UNSIGNED,
+ -- KB/s
+ ds_limit INTEGER UNSIGNED,
+ -- KB/s
+ us_limit INTEGER UNSIGNED,
+ start_time DATETIME,
+ dht_enabled BOOLEAN NOT NULL DEFAULT FALSE,
+ pxe_enabled BOOLEAN NOT NULL DEFAULT FALSE,
+ streaming_enabled BOOLEAN NOT NULL DEFAULT FALSE,
+ features VARCHAR(1024),
+ description VARCHAR(4096)
+) ENGINE=InnoDB;
+
+CREATE TABLE status_messages (
+ id INTEGER UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ client_session_id INTEGER UNSIGNED NOT NULL REFERENCES client_sessions(id) ON DELETE CASCADE ON UPDATE CASCADE,
+ timestamp DATETIME NOT NULL,
+ num_peers SMALLINT UNSIGNED,
+ num_dht_peers SMALLINT UNSIGNED,
+ -- KB/s
+ download_speed INTEGER UNSIGNED,
+ -- KB/s
+ upload_speed INTEGER UNSIGNED,
+ -- KB
+ download_size INTEGER UNSIGNED,
+ -- KB
+ upload_size INTEGER UNSIGNED,
+ -- seconds
+ eta INTEGER UNSIGNED
+) ENGINE=InnoDB;
+
+CREATE TABLE peer_status_messages (
+ id INTEGER UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ client_session_id INTEGER UNSIGNED NOT NULL REFERENCES client_sessions(id) ON DELETE CASCADE ON UPDATE CASCADE,
+ timestamp DATETIME NOT NULL,
+ -- beware of IPv6
+ peer_ip VARCHAR(100) NOT NULL,
+ peer_port SMALLINT UNSIGNED NOT NULL,
+ -- KB/s
+ download_speed INTEGER UNSIGNED,
+ -- KB/s
+ upload_speed INTEGER UNSIGNED
+) ENGINE=InnoDB;
+
+CREATE TABLE transfer_directions (
+ id TINYINT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ value VARCHAR(100) NOT NULL
+) ENGINE=InnoDB;
+
+CREATE TABLE message_types (
+ id TINYINT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ value VARCHAR(100) NOT NULL,
+ -- message parameters such as index, begin, length, listen port
+ parameters VARCHAR(256)
+) ENGINE=InnoDB;
+
+CREATE TABLE verbose_messages (
+ id INTEGER UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ client_session_id INTEGER UNSIGNED NOT NULL REFERENCES client_sessions(id) ON DELETE CASCADE ON UPDATE CASCADE,
+ timestamp DATETIME,
+ transfer_direction_id TINYINT UNSIGNED NOT NULL REFERENCES transfer_directions(id),
+ -- beware of IPv6
+ peer_ip VARCHAR(100) NOT NULL,
+ peer_port SMALLINT UNSIGNED NOT NULL,
+ message_type_id TINYINT UNSIGNED NOT NULL REFERENCES message_types(id),
+ _index INTEGER UNSIGNED,
+ begin INTEGER UNSIGNED,
+ length INTEGER UNSIGNED,
+ listen_port SMALLINT UNSIGNED
+) ENGINE=InnoDB;
+
+-- create indexes
+CREATE INDEX swarm_id_index ON client_sessions(swarm_id);
+CREATE INDEX btclient_id_index ON client_sessions(btclient_id);
+
+CREATE INDEX client_session_id_index ON status_messages(client_session_id);
+CREATE INDEX timestamp_index ON status_messages(timestamp);
+CREATE INDEX download_speed_index ON status_messages(download_speed);
+CREATE INDEX upload_speed_index ON status_messages(upload_speed);
+
+CREATE INDEX client_session_id_index ON peer_status_messages(client_session_id);
+CREATE INDEX timestamp_index ON peer_status_messages(timestamp);
+CREATE INDEX download_speed_index ON peer_status_messages(download_speed);
+CREATE INDEX upload_speed_index ON peer_status_messages(upload_speed);
+CREATE INDEX peer_ip_port_index ON peer_status_messages(peer_ip, peer_port);
+
+CREATE INDEX client_session_id_index ON verbose_messages(client_session_id);
+CREATE INDEX timestamp_index ON verbose_messages(timestamp);
+CREATE INDEX direction_id_index ON verbose_messages(transfer_direction_id);
+CREATE INDEX peer_ip_port_index ON verbose_messages(peer_ip, peer_port);
+CREATE INDEX message_type_id_index ON verbose_messages(message_type_id);
+
+-- insert BitTorrent clients in `btclients` table
+
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('Tribler', 'Python', 'http://www.tribler.org/trac', TRUE, TRUE);
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('NextShare', 'Python', 'https://trac.p2p-next.org/', TRUE, TRUE);
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('libtorrent-rasterbar', 'C++', 'http://www.rasterbar.com/products/libtorrent/', TRUE, TRUE);
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('Vuze', 'Java', 'http://www.vuze.com/', TRUE, TRUE);
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('Transmission', 'C', 'http://www.transmissionbt.com/', TRUE, FALSE);
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('Aria', 'C', 'http://aria2.sourceforge.net/', TRUE, FALSE);
+INSERT INTO btclients(name, language, url, dht_support, streaming_support)
+ VALUES('Mainline', 'Python', 'http://www.bittorrent.com/', TRUE, FALSE);
+
+-- insert into `transfer_directions` table
+
+INSERT INTO transfer_directions(value) VALUES('receive');
+INSERT INTO transfer_directions(value) VALUES('send');
+
+-- insert into `message_types` table
+
+INSERT INTO message_types(value) VALUES('CHOKE');
+INSERT INTO message_types(value) VALUES('UNCHOKE');
+INSERT INTO message_types(value) VALUES('INTERESTED');
+INSERT INTO message_types(value) VALUES('NOT_INTERESTED');
+INSERT INTO message_types(value) VALUES('HAVE');
+INSERT INTO message_types(value) VALUES('BITFIELD');
+INSERT INTO message_types(value) VALUES('REQUEST');
+INSERT INTO message_types(value) VALUES('PIECE');
+INSERT INTO message_types(value) VALUES('CANCEL');
+INSERT INTO message_types(value) VALUES('DHT_PORT');