mirror of https://github.com/cowrie/cowrie.git
Changes to the MySQL schema to be more like jfbethlehem's SQLite schema.
An update2.sql is provided that might update the schema without data loss, however if you value your data, it's a good idea to create a backup first. git-svn-id: https://kippo.googlecode.com/svn/trunk@127 951d7100-d841-11de-b865-b3884708a8e2
This commit is contained in:
parent
bd23dd9fd4
commit
7cb8e06949
|
@ -8,7 +8,6 @@ CREATE TABLE IF NOT EXISTS `auth` (
|
|||
PRIMARY KEY (`id`)
|
||||
) ;
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `input` (
|
||||
`id` int(11) NOT NULL auto_increment,
|
||||
`session` int(11) NOT NULL,
|
||||
|
@ -20,14 +19,25 @@ CREATE TABLE IF NOT EXISTS `input` (
|
|||
KEY `session` (`session`,`timestamp`,`realm`)
|
||||
) ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `sensors` (
|
||||
`id` int(11) NOT NULL auto_increment,
|
||||
`ip` varchar(15) NOT NULL,
|
||||
PRIMARY KEY (`id`)
|
||||
) ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `session` (
|
||||
CREATE TABLE IF NOT EXISTS `sessions` (
|
||||
`id` int(11) NOT NULL auto_increment,
|
||||
`starttime` datetime NOT NULL,
|
||||
`endtime` datetime default NULL,
|
||||
`sensor` varchar(50) NOT NULL,
|
||||
`sensor` int(4) NOT NULL,
|
||||
`ip` varchar(15) NOT NULL default '',
|
||||
`ttylog` mediumblob,
|
||||
PRIMARY KEY (`id`),
|
||||
KEY `starttime` (`starttime`,`sensor`)
|
||||
) ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `ttylog` (
|
||||
`id` int(11) NOT NULL auto_increment,
|
||||
`session` int(11) NOT NULL,
|
||||
`ttylog` mediumblob NOT NULL,
|
||||
PRIMARY KEY (`id`)
|
||||
) ;
|
||||
|
|
|
@ -0,0 +1,30 @@
|
|||
--
|
||||
-- WARNING: Existing data may be lost & messed up
|
||||
--
|
||||
|
||||
ALTER TABLE `session` RENAME `sessions` ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `sensors` (
|
||||
`id` int(11) NOT NULL auto_increment,
|
||||
`ip` varchar(15) NOT NULL,
|
||||
PRIMARY KEY (`id`)
|
||||
) ;
|
||||
|
||||
INSERT INTO `sensors` (`ip`) (SELECT DISTINCT `sensor` FROM `sessions`) ;
|
||||
|
||||
UPDATE `sessions` SET `sensor` =
|
||||
(SELECT `id` FROM `sensors` WHERE `sensors`.`ip` = `sessions`.`sensor`) ;
|
||||
|
||||
ALTER TABLE `sessions` CHANGE `sensor` `sensor` INT( 4 ) NOT NULL ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `ttylog` (
|
||||
`id` int(11) NOT NULL auto_increment,
|
||||
`session` int(11) NOT NULL,
|
||||
`ttylog` mediumblob NOT NULL,
|
||||
PRIMARY KEY (`id`)
|
||||
) ;
|
||||
|
||||
INSERT INTO `ttylog` (`session`, `ttylog`)
|
||||
(SELECT `id`, `ttylog` FROM `sessions` WHERE LENGTH(`ttylog`) > 0) ;
|
||||
|
||||
ALTER TABLE `sessions` DROP `ttylog` ;
|
|
@ -10,68 +10,71 @@ class DBLogger(dblog.DBLogger):
|
|||
passwd = cfg.get('database', 'password'),
|
||||
reconnect = True)
|
||||
|
||||
def query(self, sql, params = None):
|
||||
def query(self, sql, params):
|
||||
cursor = self.db.cursor()
|
||||
try:
|
||||
if params is None:
|
||||
cursor.execute(sql)
|
||||
else:
|
||||
cursor.execute(sql, params)
|
||||
cursor.execute(sql, params)
|
||||
return cursor
|
||||
except MySQLdb.MySQLError:
|
||||
except MySQLdb.MySQLError, e:
|
||||
print 'MySQL error:', e
|
||||
return None
|
||||
|
||||
def createSession(self, peerIP, peerPort, hostIP, hostPort):
|
||||
sql = 'INSERT INTO `session` (`starttime`, `sensor`, `ip`)' + \
|
||||
' VALUES (FROM_UNIXTIME(%s), %s, %s)'
|
||||
params = (self.nowUnix(), self.getSensor() or hostIP, peerIP)
|
||||
cursor = self.query(sql, params)
|
||||
if cursor is not None:
|
||||
return int(cursor.lastrowid)
|
||||
else:
|
||||
sensorid = self.getSensorID(self.getSensor() or hostIP)
|
||||
cursor = self.query(
|
||||
'INSERT INTO `sessions` (`starttime`, `sensor`, `ip`)' + \
|
||||
' VALUES (FROM_UNIXTIME(%s), %s, %s)',
|
||||
(self.nowUnix(), sensorid, peerIP))
|
||||
if not cursor:
|
||||
return None
|
||||
return int(cursor.lastrowid)
|
||||
|
||||
def getSensorID(self, ip):
|
||||
cursor = self.query(
|
||||
'SELECT `id` FROM `sensors` WHERE `ip` = %s', (ip,))
|
||||
if cursor.rowcount:
|
||||
return cursor.fetchone()[0]
|
||||
|
||||
cursor = self.query(
|
||||
'INSERT INTO `sensors` (`ip`) VALUES (%s)', (ip,))
|
||||
return cursor.lastrowid
|
||||
|
||||
def handleConnectionLost(self, session, args):
|
||||
sql = 'UPDATE `session` SET `endtime` = FROM_UNIXTIME(%s)' + \
|
||||
', `ttylog` = %s WHERE `id` = %s'
|
||||
params = (self.nowUnix(), self.ttylog(session), session)
|
||||
self.query(sql, params)
|
||||
self.query(
|
||||
'INSERT INTO `ttylog` (`session`, `ttylog`) VALUES (%s, %s)',
|
||||
(session, self.ttylog(session)))
|
||||
self.query('UPDATE `sessions` SET `endtime` = FROM_UNIXTIME(%s)' + \
|
||||
' WHERE `id` = %s',
|
||||
(self.nowUnix(), session))
|
||||
|
||||
def handleLoginFailed(self, session, args):
|
||||
sql = 'INSERT INTO `auth` (`session`, `success`' + \
|
||||
self.query('INSERT INTO `auth` (`session`, `success`' + \
|
||||
', `username`, `password`, `timestamp`)' + \
|
||||
' VALUES (%s, %s, %s, %s, FROM_UNIXTIME(%s))'
|
||||
params = (session, 0, args['username'], args['password'],
|
||||
self.nowUnix())
|
||||
self.query(sql, params)
|
||||
' VALUES (%s, %s, %s, %s, FROM_UNIXTIME(%s))',
|
||||
(session, 0, args['username'], args['password'], self.nowUnix()))
|
||||
|
||||
def handleLoginSucceeded(self, session, args):
|
||||
sql = 'INSERT INTO `auth` (`session`, `success`' + \
|
||||
self.query('INSERT INTO `auth` (`session`, `success`' + \
|
||||
', `username`, `password`, `timestamp`)' + \
|
||||
' VALUES (%s, %s, %s, %s, FROM_UNIXTIME(%s))'
|
||||
params = (session, 1, args['username'], args['password'],
|
||||
self.nowUnix())
|
||||
self.query(sql, params)
|
||||
' VALUES (%s, %s, %s, %s, FROM_UNIXTIME(%s))',
|
||||
(session, 1, args['username'], args['password'], self.nowUnix()))
|
||||
|
||||
def handleCommand(self, session, args):
|
||||
sql = 'INSERT INTO `input`' + \
|
||||
self.query('INSERT INTO `input`' + \
|
||||
' (`session`, `timestamp`, `success`, `input`)' + \
|
||||
' VALUES (%s, FROM_UNIXTIME(%s), %s, %s)'
|
||||
params = (session, self.nowUnix(), 1, args['input'])
|
||||
self.query(sql, params)
|
||||
' VALUES (%s, FROM_UNIXTIME(%s), %s, %s)',
|
||||
(session, self.nowUnix(), 1, args['input']))
|
||||
|
||||
def handleUnknownCommand(self, session, args):
|
||||
sql = 'INSERT INTO `input`' + \
|
||||
self.query('INSERT INTO `input`' + \
|
||||
' (`session`, `timestamp`, `success`, `input`)' + \
|
||||
' VALUES (%s, FROM_UNIXTIME(%s), %s, %s)'
|
||||
params = (session, self.nowUnix(), 0, args['input'])
|
||||
self.query(sql, params)
|
||||
' VALUES (%s, FROM_UNIXTIME(%s), %s, %s)',
|
||||
(session, self.nowUnix(), 0, args['input']))
|
||||
|
||||
def handleInput(self, session, args):
|
||||
sql = 'INSERT INTO `input`' + \
|
||||
self.query('INSERT INTO `input`' + \
|
||||
' (`session`, `timestamp`, `realm`, `input`)' + \
|
||||
' VALUES (%s, FROM_UNIXTIME(%s), %s, %s)'
|
||||
params = (session, self.nowUnix(), args['realm'], args['input'])
|
||||
self.query(sql, params)
|
||||
' VALUES (%s, FROM_UNIXTIME(%s), %s, %s)',
|
||||
(session, self.nowUnix(), args['realm'], args['input']))
|
||||
|
||||
# vim: set sw=4 et:
|
||||
|
|
Loading…
Reference in New Issue