You could join your mappings table twice, once on src_ip and again on
dst_ip:
SELECT COUNT(signature) AS count,
MAX(timestamp) AS maxTime,
INET_NTOA(src_ip),
m.cc as src_cc,
INET_NTOA(dst_ip),
m2.cc as dst_cc,
signature,
signature_id,
ip_proto
FROM event
INNER JOIN mappings m ON event.src_ip = mappings.ip
INNER JOIN mappings m2 ON event.dst_ip = mappings.ip
WHERE timestamp BETWEEN "2010-10-12 03:00:00" AND "2010-10-13 03:00:00"
GROUP BY INET_NTOA(src_ip), m.cc, INET_NTOA(dst_ip), m2.cc, signature,
signature_id, ip_proto
ORDER BY maxTime DESC
LIMIT 10;
-Travis
-----Original Message-----
From: Paul Halliday [mailto:[email protected]]
Sent: Tuesday, October 12, 2010 10:49 AM
To: [email protected]
Subject: Can this query be done w/o adding another column?
Geez, really taking advantage of the list today :). This one is a little
more complicated, well, in my head anyway.
Same tables as before, event and mappings. Mappings is just IP to Country
info. I want to be able to join both a src and dst but the problem is the
mappings table just has one ip column.
My initial query looks like this:
SELECT COUNT(signature) as count, MAX(timestamp) AS maxTime,
INET_NTOA(src_ip), INET_NTOA(dst_ip), signature, signature_id, ip_proto FROM
event WHERE timestamp BETWEEN "2010-10-12 00:00:00" AND "2010-10-13
00:00:00" GROUP BY src_ip, dst_ip, signature,ip_proto ORDER BY maxTime DESC;
Which would return something like this:
2 | 2010-10-12 16:34:17 | 10.1.2.3 | 173.193.202.69 | ET P2P Vuze BT UDP
Connection | 2010144 | 17
Now I want to add the country info into the mix. I have made it this far:
SELECT COUNT(signature) as count, MAX(timestamp) AS maxTime,
INET_NTOA(src_ip), mappings.cc, INET_NTOA(dst_ip), mappings.cc, signature,
signature_id, ip_proto FROM event INNER JOIN mappings ON event.src_ip =
mappings.ip OR event.dst_ip = mappings.ip WHERE timestamp BETWEEN
"2010-10-12 03:00:00" AND "2010-10-13 03:00:00" GROUP BY src_ip, dst_ip,
signature,ip_proto ORDER BY maxTime DESC LIMIT 10;
gives me:
2 | 2010-10-12 16:34:17 | 10.1.2.3 | US | 173.193.202.69 | US | ET P2P Vuze
BT UDP Connection | 2010144 | 17
which obviously isn't right ;) but is close. I was just going to change the
columns in the mappings table to have src_ip and dst_ip just duplicating the
ip column but I have a nagging feeling that that probably isn't necessary.
Thanks.
--
Paul Halliday
Ideation | Individualization | Learner | Achiever | Analytical
http://www.pintumbler.org
--
MySQL General Mailing List
For list archives: http://lists.mysql.com/mysql
To unsubscribe: http://lists.mysql.com/[email protected]