Skip to content

Commit

Permalink
latest checkin
Browse files Browse the repository at this point in the history
  • Loading branch information
vishallakhotia committed Apr 27, 2024
1 parent 7683196 commit b009291
Show file tree
Hide file tree
Showing 11 changed files with 142 additions and 71 deletions.
74 changes: 35 additions & 39 deletions README.md

Large diffs are not rendered by default.

9 changes: 5 additions & 4 deletions sql/alllabels_byip.sql
Original file line number Diff line number Diff line change
@@ -1,11 +1,12 @@
-- This sql is to show the count of IPs matching a label over a period of 7 days. If a request has no label attached, then it would be recorded against NOLABEL
SELECT count(*) AS count,httprequest.clientip,
label_item.name
FROM "waf_logs", UNNEST( CASE WHEN cardinality(labels) >= 1
THEN labels
ELSE array[ cast( row('NOLABEL') as row(name varchar)) ]
ELSE ARRAY[ cast( row('NOLABEL') as row(name varchar)) ]
END
) as t(label_item)
) AS t(label_item)
WHERE
date >=date_format(current_date - interval '8' day, '%Y/%m/%d')
date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
GROUP BY httprequest.clientip,label_item.name
order by clientip
ORDER BY clientip
15 changes: 10 additions & 5 deletions sql/alltraffic_byip.sql
Original file line number Diff line number Diff line change
@@ -1,12 +1,17 @@
-- this sql is used to identify all traffic received from a single client IP or range of IPs .
-- The results are group by the terminating rule id ,the URI and the arguments of the request and the associated labels that were attached to the requests.
-- The results are sorted by the number of requests in descending order.
-- The results are limited to the last 7 days.

SELECT count(*) AS countRequests,terminatingruleid, httprequest.uri, httprequest.args, label_item.name
FROM "waf_logs_5" ,
FROM "waf_logs" ,
UNNEST( CASE WHEN cardinality(labels) >= 1
THEN labels
ELSE array[ cast( row('NOLABEL') as row(name varchar)) ]
END
) as t(label_item)
) AS t(label_item)
WHERE
date >=date_format(current_date - interval '8' day, '%Y/%m/%d')
and httprequest.clientip like '185.254%'
date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
AND httprequest.clientip LIKE 'XXX.YYY%'
GROUP BY terminatingruleid, httprequest.uri, httprequest.args, label_item.name
order by count(*) desc
ORDER BY count(*) DESC
20 changes: 20 additions & 0 deletions sql/alltraffic_byip_including_token.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
-- This sql gathers all tokens issued and then identifies the client IP
-- Then it gathers main elements of the traffic for those IPs such as URI accessed even before the token was issued.

WITH t1 AS (
SELECT distinct httprequest.clientip clientip, label_item.name AS token_id
FROM waf_logs ,
UNNEST( CASE WHEN cardinality(labels) >= 1
THEN labels
ELSE array[ cast( row('NOLABEL') AS row(name varchar)) ]
END
) AS t(label_item)
WHERE
date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
AND label_item.name like 'awswaf:managed:token:id:%'
)
SELECT DISTINCT regexp_extract( json_format(cast(labels AS json)),'awswaf:managed:token:id:(.*?)\"', 0) AS issued_token, clientip, responsecodesent,httprequest.uri, to_iso8601(from_unixtime(timestamp / 1000))date_time , timestamp
FROM t1, waf_logs
WHERE httprequest.clientip = t1.clientip
AND date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
ORDER BY clientip, timestamp DESC
13 changes: 13 additions & 0 deletions sql/alltraffic_bywaftoken.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
-- This sql retrieves all requests that were passed a specific waf token
-- This analysis is useful to determine if a token is being used to attack the site
SELECT *
FROM "waf_logs" ,
UNNEST( CASE WHEN cardinality(labels) >= 1
THEN labels
ELSE array[ cast( row('NOLABEL') as row(name varchar)) ]
END
) AS t(label_item)
WHERE
date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
AND label_item.name = 'INSERT_THE_TOKEN_ID_HERE'
ORDER BY timestamp
15 changes: 12 additions & 3 deletions sql/bot.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@
-- This sql is categorizing all requests based on the labels attached such as relating to bots, amazon managed rules, types of requests
SELECT
date,
--baseline rule groups
Expand Down Expand Up @@ -113,8 +114,16 @@
x -> LOWER(x.name) = 'host'
)[1].value
)) AS unique_header_host,
count(1) AS total_requests
FROM waf_logs, UNNEST(labels) t(label_items)
count(DISTINCT(httprequest.requestid)) AS total_requests
FROM waf_logs,

UNNEST( CASE WHEN cardinality(labels) >= 1
THEN labels
ELSE array[ cast( row('NOLABEL') as row(name varchar)) ]
END
) AS t(label_items)


WHERE
date >= date_format(current_date - interval '3' day, '%Y/%m/%d')
date >= date_format(current_date - interval '7' day, '%Y/%m/%d')
GROUP BY date
15 changes: 9 additions & 6 deletions sql/top10ip.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,9 @@
select httprequest.clientip, count(httprequest.clientip) as requests
from waf_logs
where date >= date_format(current_date - interval '2' day, '%Y/%m/%d')
group by httprequest.clientip
order by requests desc
limit 10
-- This sql is used to identify the top 10 IPs which have made most requests in the past 7 days.
-- It allows you to identify which IPs are making the most requests in your WAF logs.
-- This can help you troubleshoot issues with your WAF logs and identify which IPs are causing issues.
SELECT httprequest.clientip, count(httprequest.clientip) AS requests
FROM waf_logs
WHERE date >= date_format(current_date - interval '7' day, '%Y/%m/%d')
GROUP BY httprequest.clientip
ORDER BY requests DESC
LIMIT 10
13 changes: 7 additions & 6 deletions sql/top10uri.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
select httprequest.uri, count(httprequest.uri) as requests
from waf_logs
where date >= date_format(current_date - interval '2' day, '%Y/%m/%d')
group by httprequest.uri
order by requests desc
limit 10
-- This sql is used to identify which are the most accessed URI for the last 7 days.
SELECT httprequest.uri, count(httprequest.uri) as requests
FROM waf_logs
WHERE date >= date_format(current_date - interval '7' day, '%Y/%m/%d')
GROUP BY httprequest.uri
ORDER BY requests DESC
LIMIT 10
7 changes: 5 additions & 2 deletions sql/toptraffic.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,9 @@
-- This sql identifies the count of requests group across client IP, the terminating rule and URI accessed
-- This would analyze the top talker client IP are accessing certain URIs for a large number of times and if its being ALLOW / BLOCK / CHALLENGE / CAPTCHA.

SELECT count(*) AS countRequests,httprequest.clientip, terminatingruleid, httprequest.uri
FROM "waf_logs"
WHERE
date >=date_format(current_date - interval '2' day, '%Y/%m/%d')
date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
GROUP BY httprequest.clientip,terminatingruleid, httprequest.uri
order by count(*) desc
ORDER BY count(*) DESC
18 changes: 18 additions & 0 deletions sql/waftoken_analysis.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
-- This sql calculates for each client ip the total number of requests, the number of challenge requests, the number of captcha requests,
-- the number of challenge requests with token invalid, the number of captcha requests with token invalid,
-- the number of challenge requests with token domain mismatch, the number of captcha requests with token domain mismatch,
SELECT httprequest.clientip AS clientip, COUNT(*) AS "Total_Requests",
SUM(CASE WHEN action = 'CHALLENGE' THEN 1 ELSE 0 END ) CHALLENGE,
SUM(CASE WHEN action = 'CAPTCHA' THEN 1 ELSE 0 END ) CAPTCHA,
SUM(CASE WHEN challengeresponse.failurereason = 'TOKEN_INVALID' THEN 1 ELSE 0 END ) CHALLENGE_TOKEN_INVALID,
SUM(CASE WHEN captcharesponse.failurereason = 'TOKEN_INVALID' THEN 1 ELSE 0 END ) CAPTCHA_TOKEN_INVALID,
SUM(CASE WHEN challengeresponse.failurereason = 'TOKEN_DOMAIN_MISMATCH' THEN 1 ELSE 0 END ) CHALLENGE_TOKEN_DOMAIN_MISMATCH,
SUM(CASE WHEN captcharesponse.failurereason = 'TOKEN_DOMAIN_MISMATCH' THEN 1 ELSE 0 END ) CAPTCHA_TOKEN_DOMAIN_MISMATCH,
SUM(CASE WHEN challengeresponse.failurereason = 'TOKEN_EXPIRED' THEN 1 ELSE 0 END ) CHALLENGE_TOKEN_EXPIRED,
SUM(CASE WHEN captcharesponse.failurereason = 'TOKEN_EXPIRED' THEN 1 ELSE 0 END ) CAPTCHA_TOKEN_EXPIRED,
SUM(CASE WHEN challengeresponse.failurereason = 'TOKEN_MISSING' THEN 1 ELSE 0 END ) CHALLENGE_TOKEN_MISSING,
SUM(CASE WHEN captcharesponse.failurereason = 'TOKEN_MISSING' THEN 1 ELSE 0 END ) CAPTCHA_TOKEN_MISSING
FROM waf_logs
WHERE date >= date_format(current_date - interval '7' day, '%Y/%m/%d')
GROUP BY httprequest.clientip
ORDER BY Total_Requests DESC
14 changes: 8 additions & 6 deletions sql/waftoken_byip.sql
Original file line number Diff line number Diff line change
@@ -1,12 +1,14 @@
SELECT label_item.name,count(distinct httprequest.clientip )
-- This sql identified for each waf token how many unique IPs were associated. Ideally this should be 1 or 2.
-- If the token has values > 2, the IPs associated with that token should be further analysed for possible fraud.
SELECT label_item.name,count( distinct httprequest.clientip ) as numberOfRequests
FROM "waf_logs" ,
UNNEST( CASE WHEN cardinality(labels) >= 1
THEN labels
ELSE array[ cast( row('NOLABEL') as row(name varchar)) ]
END
) as t(label_item)
) AS t(label_item)
WHERE
date >=date_format(current_date - interval '8' day, '%Y/%m/%d')
and label_item.name like 'awswaf:managed:token:id:%'
group by label_item.name
order by label_item.name
date >=date_format(current_date - interval '7' day, '%Y/%m/%d')
AND label_item.name LIKE 'awswaf:managed:token:id:%'
GROUP BY label_item.name
ORDER BY label_item.name

0 comments on commit b009291

Please sign in to comment.