Toggle navigation
Home
New Query
Recent Queries
Discuss
Database tables
Database names
MediaWiki
Wikibase
Replicas browser and optimizer
Login
History
Fork
Fork of
Carlossuarez46 Iranian villages limited (without coordinates)
by
BilledMammal
This query is marked as a draft
This query has been published
by
BilledMammal
.
Toggle Highlighting
SQL
WITH RECURSIVE entries (page_title, page_id, page_namespace, inc, parent_title, parent_namespace, page_len) AS ( ( SELECT page_title, page_id, page_namespace, 1, page_title, page_namespace, page_len FROM page WHERE page_title IN ("Towns_and_villages_in_Iran_by_county") AND page_namespace = 14 ) UNION ( SELECT child.page_title, child.page_id, child.page_namespace, inc + 1, parent.page_title, parent.page_namespace, child.page_len FROM page AS child JOIN categorylinks as childLinks ON child.page_id = childLinks.cl_from JOIN entries AS parent ON childLinks.cl_to = parent.page_title LEFT JOIN page_props ON childLinks.cl_from = pp_page AND pp_propname = "hiddencat" WHERE (child.page_namespace = 14 OR child.page_namespace = 0) AND parent.page_namespace = 14 AND pp_propname IS NULL AND page_is_redirect = 0 #AND inc < 4 ) ), articles AS ( SELECT DISTINCT(Article.page_title), Article.page_id, rev_timestamp, rev_len as "InitialSize", Article.page_len as "CurrentSize" FROM revision_userindex JOIN page AS Article ON Article.page_id = rev_page AND Article.page_namespace = 0 WHERE rev_parent_id = 0 AND Article.page_is_redirect = 0 AND rev_actor = 10795 AND Article.page_len < 2500 AND Article.page_id IN (SELECT page_id FROM entries) ), articledaycount AS ( SELECT LEFT(rev_timestamp, 8) AS date, COUNT(*) as datecount FROM revision_userindex JOIN page ON page_id = rev_page WHERE rev_parent_id = 0 AND page_is_redirect = 0 AND rev_actor = 10795 AND page_namespace = 0 GROUP BY date ), contributions AS ( SELECT articles.page_title, articles.page_id, articles.InitialSize, articles.CurrentSize, articles.rev_timestamp, childRev.rev_len as "ChildRevLen", parentRev.rev_len as "ParentRevLen", childRev.rev_actor FROM articles LEFT JOIN revision_userindex AS childRev ON page_id = childRev.rev_page LEFT JOIN revision AS parentRev ON childRev.rev_parent_id = parentRev.rev_id LEFT JOIN change_tag ON childRev.rev_id = ct_rev_id AND ct_tag_id IN (590, 1, 539, 582) #reverted or undo WHERE ct_tag_id IS NULL ), contribution_count AS ( SELECT page_title, page_id, InitialSize, CurrentSize, CAST(CurrentSize AS SIGNED) - CAST(InitialSize AS SIGNED) as Growth, rev_timestamp, SUM(CASE WHEN ABS(CAST(ChildRevLen as SIGNED) - CAST(ParentRevLen as SIGNED)) > 200 THEN 1 ELSE 0 END) as ContributorCount FROM contributions WHERE rev_actor != 10795 GROUP BY page_id ), reference AS ( SELECT DISTINCT(page_id) FROM articles JOIN externallinks ON el_from = page_id WHERE LEFT(el_index,20) NOT IN ("https://org.archive.", "https://ir.org.amar.", "http://org.toolforge", "https://org.toolforg", "http://mil.nga.geona", "http://net.iranatlas", "http://ir.org.ncc.ge", "https://com.google.w", "http://com.google.ww", "https://org.wikipedi", "https://com.deepl./") ) SELECT page_title, InitialSize, CurrentSize, (CAST(CurrentSize AS SIGNED) - CAST(InitialSize AS SIGNED)) as Growth, rev_timestamp, datecount FROM contribution_count JOIN articledaycount ON date = LEFT(rev_timestamp, 8) WHERE page_id NOT IN (SELECT * FROM reference) AND ContributorCount = 0 ORDER BY page_title ASC
By running queries you agree to the
Cloud Services Terms of Use
and you irrevocably agree to release your SQL under
CC0 License
.
Submit Query
Stop Query
All SQL code is licensed under
CC0 License
.
Checking query status...