This query is marked as a draft This query has been published by ಮಲ್ನಾಡಾಚ್ ಕೊಂಕ್ಣೊ.

SQL

AخA
 
select CONCAT('[[User talk:', page_title, ']]') as 'IP talkpage' -- format as wikilink so that it can be read by AWB 
from page
join templatelinks on page_id = tl_from -- link with templatelinks table
join linktarget on tl_target_id = lt_id -- link with linktarget table
join revision on rev_id = page_latest and rev_timestamp < '20180110' -- 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 lt_title = 'Warning_archive_notice' -- name of the template being transcluded
and lt_namespace = 10 -- filter template namespace
and tl_from_namespace = 3 -- being transcluded in User talk namespace
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 >= '20180110') -- not edited since this timestamp
order by page_title asc -- get pages in ascending order
limit 5000;
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...