datasette: baked queries for pname, version, & platform stats
This commit is contained in:
parent
5f598ece03
commit
dc0fbe6242
4 changed files with 206 additions and 32 deletions
44
default.nix
44
default.nix
|
@ -88,7 +88,7 @@ lib.makeScope pkgs.newScope (
|
|||
datasette-settings = self.callPackage (
|
||||
{ formats }:
|
||||
(formats.json { }).generate "datasette-settings.json" {
|
||||
sql_time_limit_ms = 8000;
|
||||
sql_time_limit_ms = 16000;
|
||||
}
|
||||
) { };
|
||||
datasette-metadata = self.callPackage (
|
||||
|
@ -122,38 +122,18 @@ lib.makeScope pkgs.newScope (
|
|||
<code>CudaArtifact</code>s (identified by <code>sha256</code>)
|
||||
claiming the same <code>(pname, version, platform)</code> triple
|
||||
'';
|
||||
sql = ''
|
||||
SELECT
|
||||
COUNT(DISTINCT sha256) AS conflicts,
|
||||
pname.str AS pname,
|
||||
ver.str AS ver,
|
||||
plat.str AS plat,
|
||||
GROUP_CONCAT(name.str, char(10)) AS name,
|
||||
GROUP_CONCAT(tag.str, char(10)) AS tag,
|
||||
GROUP_CONCAT(h.hash, char(10)) AS sha256
|
||||
FROM
|
||||
(
|
||||
CudaArtifact AS cc,
|
||||
Str AS name,
|
||||
Str AS pname,
|
||||
Str as ver,
|
||||
Str as plat,
|
||||
Hash as h
|
||||
ON cc.name=name.id
|
||||
AND cc.pname=pname.id
|
||||
AND cc.version = ver.id
|
||||
AND cc.platform = plat.id
|
||||
AND cc.sha256 = h.id
|
||||
)
|
||||
LEFT JOIN Str AS tag
|
||||
ON
|
||||
cc.compat_tag=tag.id
|
||||
GROUP BY
|
||||
cc.pname, cc.version, cc.platform
|
||||
HAVING
|
||||
conflicts >= CAST(:min_conflicts AS INTEGER)
|
||||
ORDER BY conflicts DESC
|
||||
sql = builtins.readFile ./src/q/summary-cuda-conflicts.sql;
|
||||
};
|
||||
queries.cuda_pnames = {
|
||||
title = "Known CUDA Artifacts";
|
||||
description_html = ''
|
||||
Overview of known CUDA artifacts sorted by <code>pname</code>
|
||||
'';
|
||||
sql = builtins.readFile ./src/q/summary-cuda-pnames.sql;
|
||||
};
|
||||
queries.cuda_platforms = {
|
||||
title = "CUDA: Supported Platforms ";
|
||||
sql = builtins.readFile ./src/q/summary-cuda-platforms.sql;
|
||||
};
|
||||
};
|
||||
};
|
||||
|
|
34
src/q/summary-cuda-conflicts.sql
Normal file
34
src/q/summary-cuda-conflicts.sql
Normal file
|
@ -0,0 +1,34 @@
|
|||
SELECT
|
||||
COUNT(DISTINCT sha256) AS conflicts,
|
||||
pname.str AS pname,
|
||||
ver.str AS ver,
|
||||
plat.str AS plat,
|
||||
GROUP_CONCAT(name.str, char(10)) AS name,
|
||||
GROUP_CONCAT(IFNULL(tag.str, char(0x274C)), char(10)) AS tag,
|
||||
GROUP_CONCAT(h.hash, char(10)) AS sha256
|
||||
FROM
|
||||
(
|
||||
CudaArtifact AS cc,
|
||||
Str AS name,
|
||||
Str AS pname,
|
||||
Str as ver,
|
||||
Str as plat,
|
||||
Hash as h ON cc.name = name.id
|
||||
AND cc.pname = pname.id
|
||||
AND cc.version = ver.id
|
||||
AND cc.platform = plat.id
|
||||
AND cc.sha256 = h.id
|
||||
)
|
||||
LEFT JOIN Str AS tag ON cc.compat_tag = tag.id
|
||||
GROUP BY
|
||||
cc.pname,
|
||||
cc.version,
|
||||
cc.platform
|
||||
HAVING
|
||||
conflicts >= CAST(:min_conflicts AS INTEGER)
|
||||
ORDER BY
|
||||
conflicts DESC,
|
||||
cc.pname,
|
||||
cc.version,
|
||||
cc.platform,
|
||||
tag.str
|
73
src/q/summary-cuda-platforms.sql
Normal file
73
src/q/summary-cuda-platforms.sql
Normal file
|
@ -0,0 +1,73 @@
|
|||
WITH PerQuadruple AS (
|
||||
SELECT
|
||||
pname.str AS pname,
|
||||
IFNULL(ver.str, char(0x274C)) AS version,
|
||||
plat.str AS platform,
|
||||
IFNULL(ct.str, char(0x274C)) AS tag,
|
||||
COUNT(DISTINCT sha256.hash) AS uq_sha256s
|
||||
FROM
|
||||
(
|
||||
CudaArtifact AS ca,
|
||||
Str AS pname,
|
||||
Str AS plat,
|
||||
Hash AS sha256 ON ca.pname = pname.id
|
||||
AND ca.platform = plat.id
|
||||
AND sha256.id = ca.sha256
|
||||
)
|
||||
LEFT JOIN Str AS ver ON ver.id = ca.version
|
||||
LEFT JOIN Str AS ct ON ca.compat_tag = ct.id
|
||||
GROUP BY
|
||||
pname.id,
|
||||
version,
|
||||
platform,
|
||||
tag
|
||||
ORDER BY
|
||||
uq_sha256s DESC,
|
||||
pname.str,
|
||||
version,
|
||||
plat.str,
|
||||
tag
|
||||
),
|
||||
ByPname AS (
|
||||
SELECT
|
||||
pname,
|
||||
REPLACE(GROUP_CONCAT(DISTINCT pq.version), ',', char(10)) AS versions,
|
||||
REPLACE(
|
||||
GROUP_CONCAT(DISTINCT pq.platform),
|
||||
',',
|
||||
char(10)
|
||||
) AS platforms,
|
||||
REPLACE(GROUP_CONCAT(DISTINCT pq.tag), ',', char(10)) AS tags,
|
||||
SUM(pq.uq_sha256s) AS uq_sha256s
|
||||
FROM
|
||||
PerQuadruple AS pq
|
||||
GROUP BY
|
||||
pq.pname
|
||||
),
|
||||
VersionGroups AS (
|
||||
SELECT
|
||||
REPLACE(GROUP_CONCAT(DISTINCT pname), ',', char(10)) AS pnames,
|
||||
versions
|
||||
FROM
|
||||
ByPname AS bp
|
||||
GROUP BY
|
||||
versions
|
||||
ORDER BY
|
||||
LENGTH(pnames) DESC
|
||||
),
|
||||
PlatformGroups AS (
|
||||
SELECT
|
||||
REPLACE(GROUP_CONCAT(DISTINCT pname), ',', char(10)) AS pnames,
|
||||
platforms
|
||||
FROM
|
||||
ByPname AS bp
|
||||
GROUP BY
|
||||
platforms
|
||||
ORDER BY
|
||||
LENGTH(platforms) DESC,
|
||||
LENGTH(pnames)
|
||||
)
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
PlatformGroups
|
87
src/q/summary-cuda-pnames.sql
Normal file
87
src/q/summary-cuda-pnames.sql
Normal file
|
@ -0,0 +1,87 @@
|
|||
WITH PerQuadruple AS (
|
||||
SELECT
|
||||
pname.str AS pname,
|
||||
IFNULL(ver.str, char(0x274C)) AS version,
|
||||
plat.str AS platform,
|
||||
IFNULL(ct.str, char(0x274C)) AS tag,
|
||||
COUNT(DISTINCT sha256.hash) AS uq_sha256s
|
||||
FROM
|
||||
(
|
||||
CudaArtifact AS ca,
|
||||
Str AS pname,
|
||||
Str AS plat,
|
||||
Hash AS sha256 ON ca.pname = pname.id
|
||||
AND ca.platform = plat.id
|
||||
AND sha256.id = ca.sha256
|
||||
)
|
||||
LEFT JOIN Str AS ver ON ver.id = ca.version
|
||||
LEFT JOIN Str AS ct ON ca.compat_tag = ct.id
|
||||
GROUP BY
|
||||
pname.id,
|
||||
version,
|
||||
platform,
|
||||
tag
|
||||
ORDER BY
|
||||
uq_sha256s DESC,
|
||||
pname.str,
|
||||
version,
|
||||
plat.str,
|
||||
tag
|
||||
)
|
||||
SELECT
|
||||
pname,
|
||||
(
|
||||
SELECT
|
||||
GROUP_CONCAT(x, char(10))
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DISTINCT version AS x
|
||||
FROM
|
||||
PerQuadruple
|
||||
WHERE
|
||||
pname = pq.pname
|
||||
ORDER BY
|
||||
x
|
||||
)
|
||||
) AS versions,
|
||||
(
|
||||
SELECT
|
||||
GROUP_CONCAT(x, char(10))
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DISTINCT platform AS x
|
||||
FROM
|
||||
PerQuadruple
|
||||
WHERE
|
||||
pname = pq.pname
|
||||
ORDER BY
|
||||
x
|
||||
)
|
||||
) AS platforms,
|
||||
(
|
||||
SELECT
|
||||
GROUP_CONCAT(x, char(10))
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DISTINCT tag AS x
|
||||
FROM
|
||||
PerQuadruple
|
||||
WHERE
|
||||
pname = pq.pname
|
||||
ORDER BY
|
||||
x
|
||||
)
|
||||
) AS tags,
|
||||
(
|
||||
SELECT
|
||||
SUM(uq_sha256s)
|
||||
FROM
|
||||
PerQuadruple
|
||||
WHERE
|
||||
pname = pq.pname
|
||||
) AS uq_sha256s
|
||||
FROM
|
||||
PerQuadruple AS pq
|
Loading…
Add table
Add a link
Reference in a new issue