Updated query for MySQL.

This commit is contained in:
Michael Herzberg 2017-09-01 20:00:28 +01:00
parent bb03a67a29
commit 4980bdbe9e
1 changed files with 33 additions and 48 deletions

View File

@ -1,51 +1,36 @@
select extid as e,name,min(date),permission
from extension natural join crx natural join permission
-- Ensure we have at least two different crx files, otherwise we have an empty permission
-- set in the previous where clause
where (
select count(*)
select extension_info.extid, extension_info.name, permission
from (
-- We generate a table containing every crx_etag that we crawled within the
-- last day and is an update, and a random date where we encountered the its
-- previous crx_etag. We only use it to find the crx_etag again later.
select
crx_first_date1.crx_etag,
crx_first_date1.extid,
crx_first_date1.md as most_recent_update,
crx_first_date2.md as some_date_with_previous_version
from (
select *
select crx_etag,extid,min(date) as md
from extension
where crx_etag not null
and extid=e
-- Ensure we have seen two different crx_etags of this extensions within the last two runs
and date in (
select date
from extension
where extid=e
order by date desc
limit 2
)
group by extid,crx_etag
-- order by date desc
limit 2
)
) = 2
-- Select newest crx file
and crx_etag=(
select crx_etag
from extension
where crx_etag not null
and extid=e
group by extid,crx_etag
order by date desc
limit 1
)
-- Ensure permission is not present in previous crx
and permission not in (
group by crx_etag
) crx_first_date1
inner join (
select extid,min(date) as md
from extension
group by crx_etag
) crx_first_date2
on crx_first_date1.extid=crx_first_date2.extid
where crx_first_date1.md>crx_first_date2.md
and DATEDIFF(CURDATE(), crx_first_date1.md) = 0
group by crx_first_date1.crx_etag
) crx_most_recent_and_prev
inner join permission
on crx_most_recent_and_prev.crx_etag=permission.crx_etag
inner join extension extension_info
on crx_most_recent_and_prev.extid=extension_info.extid
and extension_info.date=most_recent_update
and extension_info.crx_etag=crx_most_recent_and_prev.crx_etag
where permission not in (
select permission
from permission
-- Select the second newest crx that we have
where crx_etag=(
select crx_etag
from extension
where crx_etag not null
and extid=e
group by extid,crx_etag
order by date desc
limit 1
offset 1
)
)
group by extid,permission;
from extension natural join permission
where extid=extension_info.extid and date=some_date_with_previous_version
);