Fork of Inactive IP talkpages by Certes
This query is marked as a draft This query has been published by ಮಲ್ನಾಡಾಚ್ ಕೊಂಕ್ಣೊ.

SQL

AخA
 
select CONCAT('[[User talk:', page_title, ']]') as user_talk -- format as wikilink so that it can be read by AWB 
from page
join revision on rev_id = page_latest and rev_timestamp < '20171020' -- latest page edit is older than the given date
join actor on actor_user is null and actor_name = page_title -- IP with User talk page
where page_namespace = 3 -- User talk namespace
and page_title like '80.1%' -- Temporary restriction to make query small enough to terminate
-- and page_title regexp '^(\\d{1,3}(\\.\\d{1,3}){3}|[\\dA-F]{1,4}(:[\\dA-F]{0,4}){1,7})$'
and not exists (select 1 -- Check that the IP is not blocked
                from ipblocks
                where ipb_user = 0 -- Blocked user is an IP
                and HEX(INET6_ATON(page_title)) between ipb_range_start and ipb_range_end) -- Hex of IP address to check for range blocks
and not exists (select 1 -- Check that the IP is inactive
                from revision_userindex
                where rev_actor = actor_id -- Choose same IP user as above
                and rev_timestamp >= '20171020') -- not edited since this timestamp
order by user_talk asc; -- get pages in ascending order
By running queries you agree to the Cloud Services Terms of Use and you irrevocably agree to release your SQL under CC0 License.
All SQL code is licensed under CC0 License.

Checking query status...