Many updates
This commit is contained in:
@@ -56,11 +56,10 @@ class AnalyticsController < ApplicationController
|
||||
end
|
||||
end
|
||||
|
||||
# Top countries by event count - cached (this is the expensive JOIN query)
|
||||
# Top countries by event count - cached (now uses denormalized country column)
|
||||
@top_countries = Rails.cache.fetch("#{cache_key_base}/top_countries", expires_in: cache_ttl) do
|
||||
Event.joins("JOIN network_ranges ON events.ip_address <<= network_ranges.network")
|
||||
.where("timestamp >= ? AND network_ranges.country IS NOT NULL", @start_time)
|
||||
.group("network_ranges.country")
|
||||
Event.where("timestamp >= ? AND country IS NOT NULL", @start_time)
|
||||
.group(:country)
|
||||
.count
|
||||
.sort_by { |_, count| -count }
|
||||
.first(10)
|
||||
@@ -126,10 +125,10 @@ class AnalyticsController < ApplicationController
|
||||
@time_period = params[:period]&.to_sym || :day
|
||||
@start_time = calculate_start_time(@time_period)
|
||||
|
||||
# Top networks by request volume
|
||||
@top_networks = NetworkRange.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
# Top networks by request volume (using denormalized network_range_id)
|
||||
@top_networks = NetworkRange.joins("LEFT JOIN events ON events.network_range_id = network_ranges.id")
|
||||
.where("events.timestamp >= ? OR events.timestamp IS NULL", @start_time)
|
||||
.group("network_ranges.id", "network_ranges.network", "network_ranges.company", "network_ranges.asn", "network_ranges.country", "network_ranges.is_datacenter", "network_ranges.is_vpn", "network_ranges.is_proxy")
|
||||
.group("network_ranges.id")
|
||||
.select("network_ranges.*, COUNT(events.id) as event_count, COUNT(DISTINCT events.ip_address) as unique_ips")
|
||||
.order("event_count DESC")
|
||||
.limit(50)
|
||||
@@ -137,29 +136,26 @@ class AnalyticsController < ApplicationController
|
||||
# Network type breakdown with traffic stats
|
||||
@network_breakdown = calculate_network_type_stats(@start_time)
|
||||
|
||||
# Company breakdown for top traffic sources
|
||||
@top_companies = NetworkRange.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ? AND network_ranges.company IS NOT NULL", @start_time)
|
||||
.group("network_ranges.company")
|
||||
.select("network_ranges.company, COUNT(events.id) as event_count, COUNT(DISTINCT events.ip_address) as unique_ips, COUNT(DISTINCT network_ranges.id) as network_count")
|
||||
.order("event_count DESC")
|
||||
.limit(20)
|
||||
# Company breakdown for top traffic sources (using denormalized company column)
|
||||
@top_companies = Event.where("timestamp >= ? AND company IS NOT NULL", @start_time)
|
||||
.group(:company)
|
||||
.select("company, COUNT(*) as event_count, COUNT(DISTINCT ip_address) as unique_ips")
|
||||
.order("event_count DESC")
|
||||
.limit(20)
|
||||
|
||||
# ASN breakdown
|
||||
@top_asns = NetworkRange.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ? AND network_ranges.asn IS NOT NULL", @start_time)
|
||||
.group("network_ranges.asn", "network_ranges.asn_org")
|
||||
.select("network_ranges.asn, network_ranges.asn_org, COUNT(events.id) as event_count, COUNT(DISTINCT events.ip_address) as unique_ips, COUNT(DISTINCT network_ranges.id) as network_count")
|
||||
.order("event_count DESC")
|
||||
.limit(15)
|
||||
# ASN breakdown (using denormalized asn columns)
|
||||
@top_asns = Event.where("timestamp >= ? AND asn IS NOT NULL", @start_time)
|
||||
.group(:asn, :asn_org)
|
||||
.select("asn, asn_org, COUNT(*) as event_count, COUNT(DISTINCT ip_address) as unique_ips")
|
||||
.order("event_count DESC")
|
||||
.limit(15)
|
||||
|
||||
# Geographic breakdown
|
||||
@top_countries = NetworkRange.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ? AND network_ranges.country IS NOT NULL", @start_time)
|
||||
.group("network_ranges.country")
|
||||
.select("network_ranges.country, COUNT(events.id) as event_count, COUNT(DISTINCT events.ip_address) as unique_ips, COUNT(DISTINCT network_ranges.id) as network_count")
|
||||
.order("event_count DESC")
|
||||
.limit(15)
|
||||
# Geographic breakdown (using denormalized country column)
|
||||
@top_countries = Event.where("timestamp >= ? AND country IS NOT NULL", @start_time)
|
||||
.group(:country)
|
||||
.select("country, COUNT(*) as event_count, COUNT(DISTINCT ip_address) as unique_ips")
|
||||
.order("event_count DESC")
|
||||
.limit(15)
|
||||
|
||||
# Suspicious network activity patterns
|
||||
@suspicious_patterns = calculate_suspicious_patterns(@start_time)
|
||||
@@ -297,51 +293,41 @@ class AnalyticsController < ApplicationController
|
||||
end
|
||||
|
||||
def calculate_network_type_stats(start_time)
|
||||
# Get all network types with their traffic statistics
|
||||
# Get all network types with their traffic statistics using denormalized columns
|
||||
network_types = [
|
||||
{ type: 'datacenter', label: 'Datacenter' },
|
||||
{ type: 'vpn', label: 'VPN' },
|
||||
{ type: 'proxy', label: 'Proxy' }
|
||||
{ type: 'datacenter', label: 'Datacenter', column: :is_datacenter },
|
||||
{ type: 'vpn', label: 'VPN', column: :is_vpn },
|
||||
{ type: 'proxy', label: 'Proxy', column: :is_proxy }
|
||||
]
|
||||
|
||||
results = {}
|
||||
total_events = Event.where("timestamp >= ?", start_time).count
|
||||
|
||||
network_types.each do |network_type|
|
||||
scope = case network_type[:type]
|
||||
when 'datacenter' then NetworkRange.datacenter
|
||||
when 'vpn' then NetworkRange.vpn
|
||||
when 'proxy' then NetworkRange.proxy
|
||||
end
|
||||
# Query events directly using denormalized flags
|
||||
event_stats = Event.where("timestamp >= ? AND #{network_type[:column]} = ?", start_time, true)
|
||||
.select("COUNT(*) as event_count, COUNT(DISTINCT ip_address) as unique_ips, COUNT(DISTINCT network_range_id) as network_count")
|
||||
.first
|
||||
|
||||
if scope
|
||||
network_stats = scope.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ? OR events.timestamp IS NULL", start_time)
|
||||
.select("COUNT(events.id) as event_count, COUNT(DISTINCT events.ip_address) as unique_ips, COUNT(DISTINCT network_ranges.id) as network_count")
|
||||
.first
|
||||
|
||||
results[network_type[:type]] = {
|
||||
label: network_type[:label],
|
||||
networks: network_stats.network_count,
|
||||
events: network_stats.event_count,
|
||||
unique_ips: network_stats.unique_ips,
|
||||
percentage: total_events > 0 ? ((network_stats.event_count.to_f / total_events) * 100).round(1) : 0
|
||||
}
|
||||
end
|
||||
results[network_type[:type]] = {
|
||||
label: network_type[:label],
|
||||
networks: event_stats.network_count || 0,
|
||||
events: event_stats.event_count || 0,
|
||||
unique_ips: event_stats.unique_ips || 0,
|
||||
percentage: total_events > 0 ? ((event_stats.event_count.to_f / total_events) * 100).round(1) : 0
|
||||
}
|
||||
end
|
||||
|
||||
# Calculate standard networks (everything else)
|
||||
standard_stats = NetworkRange.where(is_datacenter: false, is_vpn: false, is_proxy: false)
|
||||
.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ? OR events.timestamp IS NULL", start_time)
|
||||
.select("COUNT(events.id) as event_count, COUNT(DISTINCT events.ip_address) as unique_ips, COUNT(DISTINCT network_ranges.id) as network_count")
|
||||
.first
|
||||
standard_stats = Event.where("timestamp >= ? AND is_datacenter = ? AND is_vpn = ? AND is_proxy = ?", start_time, false, false, false)
|
||||
.select("COUNT(*) as event_count, COUNT(DISTINCT ip_address) as unique_ips, COUNT(DISTINCT network_range_id) as network_count")
|
||||
.first
|
||||
|
||||
results['standard'] = {
|
||||
label: 'Standard',
|
||||
networks: standard_stats.network_count,
|
||||
events: standard_stats.event_count,
|
||||
unique_ips: standard_stats.unique_ips,
|
||||
networks: standard_stats.network_count || 0,
|
||||
events: standard_stats.event_count || 0,
|
||||
unique_ips: standard_stats.unique_ips || 0,
|
||||
percentage: total_events > 0 ? ((standard_stats.event_count.to_f / total_events) * 100).round(1) : 0
|
||||
}
|
||||
|
||||
@@ -351,51 +337,51 @@ class AnalyticsController < ApplicationController
|
||||
def calculate_suspicious_patterns(start_time)
|
||||
patterns = {}
|
||||
|
||||
# High volume networks (top 1% by request count)
|
||||
total_networks = NetworkRange.joins("LEFT JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ?", start_time)
|
||||
.distinct.count
|
||||
# High volume networks (top 1% by request count) - using denormalized network_range_id
|
||||
total_networks = Event.where("timestamp >= ? AND network_range_id IS NOT NULL", start_time)
|
||||
.distinct.count(:network_range_id)
|
||||
|
||||
high_volume_threshold = [total_networks * 0.01, 1].max
|
||||
high_volume_networks = NetworkRange.joins("INNER JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ?", start_time)
|
||||
.group("network_ranges.id")
|
||||
.having("COUNT(events.id) > ?", Event.where("timestamp >= ?", start_time).count / total_networks)
|
||||
.count
|
||||
if total_networks > 0
|
||||
avg_events_per_network = Event.where("timestamp >= ?", start_time).count / total_networks
|
||||
high_volume_networks = Event.where("timestamp >= ? AND network_range_id IS NOT NULL", start_time)
|
||||
.group(:network_range_id)
|
||||
.having("COUNT(*) > ?", avg_events_per_network * 5)
|
||||
.count
|
||||
|
||||
patterns[:high_volume] = {
|
||||
count: high_volume_networks.count,
|
||||
networks: high_volume_networks.keys
|
||||
}
|
||||
patterns[:high_volume] = {
|
||||
count: high_volume_networks.count,
|
||||
networks: high_volume_networks.keys
|
||||
}
|
||||
else
|
||||
patterns[:high_volume] = { count: 0, networks: [] }
|
||||
end
|
||||
|
||||
# Networks with high deny rates (> 50% blocked requests)
|
||||
high_deny_networks = NetworkRange.joins("INNER JOIN events ON events.ip_address <<= network_ranges.network")
|
||||
.where("events.timestamp >= ?", start_time)
|
||||
.group("network_ranges.id")
|
||||
.select("network_ranges.id,
|
||||
COUNT(CASE WHEN events.waf_action = 1 THEN 1 END) as denied_count,
|
||||
COUNT(events.id) as total_count")
|
||||
.having("COUNT(CASE WHEN events.waf_action = 1 THEN 1 END)::float / COUNT(events.id) > 0.5")
|
||||
.having("COUNT(events.id) >= 10") # minimum threshold
|
||||
# Networks with high deny rates (> 50% blocked requests) - using denormalized network_range_id
|
||||
high_deny_networks = Event.where("timestamp >= ? AND network_range_id IS NOT NULL", start_time)
|
||||
.group(:network_range_id)
|
||||
.select("network_range_id,
|
||||
COUNT(CASE WHEN waf_action = 1 THEN 1 END) as denied_count,
|
||||
COUNT(*) as total_count")
|
||||
.having("COUNT(CASE WHEN waf_action = 1 THEN 1 END)::float / COUNT(*) > 0.5")
|
||||
.having("COUNT(*) >= 10") # minimum threshold
|
||||
|
||||
patterns[:high_deny_rate] = {
|
||||
count: high_deny_networks.count,
|
||||
network_ids: high_deny_networks.map(&:id)
|
||||
network_ids: high_deny_networks.map(&:network_range_id)
|
||||
}
|
||||
|
||||
# Networks appearing as multiple subnets (potential botnets)
|
||||
company_subnets = NetworkRange.where("company IS NOT NULL")
|
||||
.where("timestamp >= ? OR timestamp IS NULL", start_time)
|
||||
.group(:company)
|
||||
.select(:company, "COUNT(DISTINCT network) as subnet_count")
|
||||
.having("COUNT(DISTINCT network) > 5")
|
||||
.order("subnet_count DESC")
|
||||
.limit(10)
|
||||
# Companies appearing with multiple IPs (potential botnets) - using denormalized company column
|
||||
company_subnets = Event.where("timestamp >= ? AND company IS NOT NULL", start_time)
|
||||
.group(:company)
|
||||
.select("company, COUNT(DISTINCT ip_address) as ip_count")
|
||||
.having("COUNT(DISTINCT ip_address) > 5")
|
||||
.order("ip_count DESC")
|
||||
.limit(10)
|
||||
|
||||
patterns[:distributed_companies] = company_subnets.map do |company|
|
||||
patterns[:distributed_companies] = company_subnets.map do |stat|
|
||||
{
|
||||
company: company.company,
|
||||
subnets: company.subnet_count
|
||||
company: stat.company,
|
||||
subnets: stat.ip_count
|
||||
}
|
||||
end
|
||||
|
||||
|
||||
Reference in New Issue
Block a user