Thread: Determine the time difference from records in a select
I apologize in advance, 'cause I think this was addressed a couple of months ago, but I cannot find it in the archives. I have a firewall hit database which keeps the date of the hit and the offenders IP (among other items). I would like to be able to execute a select which would show each unique IP and the time difference from the latest hit to the first hit. I can do this in scripts, but was wondering if there is a pure SQL query/queries way to accomplish this. Help? Rob Robert Creager Senior Software Engineer Client Server Library 303.673.2365 V 303.661.5379 F 888.912.4458 P StorageTek INFORMATION made POWERFUL
Robert, > I have a firewall hit database which keeps the date of the hit and > the > offenders IP (among other items). I would like to be able to execute > a > select which would show each unique IP and the time difference from > the > latest hit to the first hit. I can do this in scripts, but was > wondering if > there is a pure SQL query/queries way to accomplish this. You need to use a subselect in the FROM clause, which requires 7.1 or greater. SELECT agg_last.ip_addr, first_hit, last_hit, (last_hit- first_hit) AS hit_interval FROM (SELECT ip_addr, max(hit_date) FROM hits GROUP BY ip_addr) agg_last, (SELECT ip_addr, min(hit_date) FROM hits GROUP BY ip_addr) agg_first WHERE agg_last.ip_addr = agg_first.ip_addr; -Josh Berkus ______AGLIO DATABASE SOLUTIONS___________________________ Josh Berkus Complete informationtechnology josh@agliodbs.com and data management solutions (415) 565-7293 for law firms, small businesses fax 621-2533 and non-profit organizations. San Francisco
Robert: > I have a firewall hit database which keeps the date of the hit and > the > offenders IP (among other items). I would like to be able to execute > a > select which would show each unique IP and the time difference from > the > latest hit to the first hit. I can do this in scripts, but was > wondering if > there is a pure SQL query/queries way to accomplish this. You need to use a subselect, which means you need to be running 7.1 or better. Here's the basic idea: SELECT agg_last.ip_address, first_hit, last_hit, (last_hit - first_hit) AS hit_interval FROM (SELECT ip_address, min(hit_date) as first_hit ______AGLIO DATABASE SOLUTIONS___________________________ Josh Berkus Complete informationtechnology josh@agliodbs.com and data management solutions (415) 565-7293 for law firms, small businesses fax 621-2533 and non-profit organizations. San Francisco