Skip to content

Commit

Permalink
Merge pull request #168 from waveform80/fix-build-rate-stats
Browse files Browse the repository at this point in the history
Fix a couple of db issues
  • Loading branch information
waveform80 committed Jun 27, 2019
2 parents 951eda2 + 745be75 commit 26d1749
Show file tree
Hide file tree
Showing 2 changed files with 176 additions and 12 deletions.
34 changes: 26 additions & 8 deletions piwheels/initdb/sql/create_piwheels.sql
Original file line number Diff line number Diff line change
Expand Up @@ -612,15 +612,25 @@ BEGIN
)
RETURNING build_id
INTO new_build_id;
INSERT INTO output VALUES (new_build_id, output);
INSERT INTO output (build_id, output) VALUES (new_build_id, output);
-- We delete the existing entries from files rather than using INSERT..ON
-- CONFLICT UPDATE because we need to delete dependencies associated with
-- those files too. This is considerably simpler than a multi-layered
-- upsert across tables.
DELETE FROM files f
USING UNNEST(build_files) AS b
WHERE f.filename = b.filename;
INSERT INTO files
INSERT INTO files (
filename,
build_id,
filesize,
filehash,
package_tag,
package_version_tag,
py_version_tag,
abi_tag,
platform_tag
)
SELECT
b.filename,
new_build_id,
Expand All @@ -633,7 +643,11 @@ BEGIN
b.platform_tag
FROM
UNNEST(build_files) AS b;
INSERT INTO dependencies
INSERT INTO dependencies (
filename,
tool,
dependency
)
SELECT
d.filename,
d.tool,
Expand Down Expand Up @@ -679,7 +693,7 @@ BEGIN
)
RETURNING build_id
INTO new_build_id;
INSERT INTO output VALUES (new_build_id, output);
INSERT INTO output (build_id, output) VALUES (new_build_id, output);
RETURN new_build_id;
END;
$sql$;
Expand Down Expand Up @@ -822,7 +836,7 @@ AS $sql$
build_latest AS (
SELECT COUNT(*) AS builds_count_last_hour
FROM builds
WHERE built_at > CURRENT_TIMESTAMP - INTERVAL '1 hour'
WHERE built_at > CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - INTERVAL '1 hour'
),
file_count AS (
SELECT
Expand All @@ -841,7 +855,7 @@ AS $sql$
download_stats AS (
SELECT
COUNT(*) FILTER (
WHERE accessed_at > CURRENT_TIMESTAMP - INTERVAL '30 days'
WHERE accessed_at > CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - INTERVAL '30 days'
) AS downloads_last_month,
COUNT(*) AS downloads_all
FROM downloads
Expand Down Expand Up @@ -887,7 +901,7 @@ AS $sql$
SELECT
p.package,
CAST(COALESCE(COUNT(d.filename) FILTER (
WHERE d.accessed_at > CURRENT_TIMESTAMP - INTERVAL '30 days'
WHERE d.accessed_at > CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - INTERVAL '30 days'
), 0) AS INTEGER) AS downloads_recent,
CAST(COALESCE(COUNT(d.filename), 0) AS INTEGER) AS downloads_all
FROM
Expand Down Expand Up @@ -1056,7 +1070,11 @@ CREATE FUNCTION save_rewrites_pending(data rewrites_pending ARRAY)
SET search_path = public, pg_temp
AS $sql$
DELETE FROM rewrites_pending;
INSERT INTO rewrites_pending
INSERT INTO rewrites_pending (
package,
added_at,
command
)
SELECT
d.package,
d.added_at,
Expand Down
154 changes: 150 additions & 4 deletions piwheels/initdb/sql/update_piwheels_0.14_to_0.15.sql
Original file line number Diff line number Diff line change
Expand Up @@ -240,7 +240,7 @@ AS $sql$
build_latest AS (
SELECT COUNT(*) AS builds_count_last_hour
FROM builds
WHERE built_at > CURRENT_TIMESTAMP - INTERVAL '1 hour'
WHERE built_at > CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - INTERVAL '1 hour'
),
file_count AS (
SELECT
Expand All @@ -259,7 +259,7 @@ AS $sql$
download_stats AS (
SELECT
COUNT(*) FILTER (
WHERE accessed_at > CURRENT_TIMESTAMP - INTERVAL '30 days'
WHERE accessed_at > CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - INTERVAL '30 days'
) AS downloads_last_month,
COUNT(*) AS downloads_all
FROM downloads
Expand Down Expand Up @@ -298,7 +298,7 @@ AS $sql$
SELECT
p.package,
CAST(COALESCE(COUNT(d.filename) FILTER (
WHERE d.accessed_at > CURRENT_TIMESTAMP - INTERVAL '30 days'
WHERE d.accessed_at > CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - INTERVAL '30 days'
), 0) AS INTEGER) AS downloads_recent,
CAST(COALESCE(COUNT(d.filename), 0) AS INTEGER) AS downloads_all
FROM
Expand Down Expand Up @@ -429,7 +429,11 @@ CREATE FUNCTION save_rewrites_pending(data rewrites_pending ARRAY)
SET search_path = public, pg_temp
AS $sql$
DELETE FROM rewrites_pending;
INSERT INTO rewrites_pending
INSERT INTO rewrites_pending (
package,
added_at,
command
)
SELECT
d.package,
d.added_at,
Expand Down Expand Up @@ -458,4 +462,146 @@ $sql$;
REVOKE ALL ON FUNCTION load_rewrites_pending() FROM PUBLIC;
GRANT EXECUTE ON FUNCTION load_rewrites_pending() TO {username};

DROP FUNCTION log_build_success(TEXT, TEXT, INTEGER, INTERVAL, TEXT, TEXT,
files ARRAY, dependencies ARRAY);
CREATE FUNCTION log_build_success(
package TEXT,
version TEXT,
built_by INTEGER,
duration INTERVAL,
abi_tag TEXT,
output TEXT,
build_files files ARRAY,
build_deps dependencies ARRAY
)
RETURNS INTEGER
LANGUAGE plpgsql
CALLED ON NULL INPUT
SECURITY DEFINER
SET search_path = public, pg_temp
AS $sql$
DECLARE
new_build_id INTEGER;
BEGIN
IF ARRAY_LENGTH(build_files, 1) = 0 THEN
RAISE EXCEPTION integrity_constraint_violation
USING MESSAGE = 'Successful build must include at least one file';
END IF;
INSERT INTO builds (
package,
version,
built_by,
duration,
status,
abi_tag
)
VALUES (
package,
version,
built_by,
duration,
TRUE,
abi_tag
)
RETURNING build_id
INTO new_build_id;
INSERT INTO output (build_id, output) VALUES (new_build_id, output);
-- We delete the existing entries from files rather than using INSERT..ON
-- CONFLICT UPDATE because we need to delete dependencies associated with
-- those files too. This is considerably simpler than a multi-layered
-- upsert across tables.
DELETE FROM files f
USING UNNEST(build_files) AS b
WHERE f.filename = b.filename;
INSERT INTO files (
filename,
build_id,
filesize,
filehash,
package_tag,
package_version_tag,
py_version_tag,
abi_tag,
platform_tag
)
SELECT
b.filename,
new_build_id,
b.filesize,
b.filehash,
b.package_tag,
b.package_version_tag,
b.py_version_tag,
b.abi_tag,
b.platform_tag
FROM
UNNEST(build_files) AS b;
INSERT INTO dependencies (
filename,
tool,
dependency
)
SELECT
d.filename,
d.tool,
d.dependency
FROM
UNNEST(build_deps) AS d;
RETURN new_build_id;
END;
$sql$;
REVOKE ALL ON FUNCTION log_build_success(
TEXT, TEXT, INTEGER, INTERVAL, TEXT, TEXT, files ARRAY, dependencies ARRAY
) FROM PUBLIC;
GRANT EXECUTE ON FUNCTION log_build_success(
TEXT, TEXT, INTEGER, INTERVAL, TEXT, TEXT, files ARRAY, dependencies ARRAY
) TO {username};

DROP FUNCTION log_build_failure(TEXT, TEXT, INTEGER, INTERVAL, TEXT, TEXT);
CREATE FUNCTION log_build_failure(
package TEXT,
version TEXT,
built_by INTEGER,
duration INTERVAL,
abi_tag TEXT,
output TEXT
)
RETURNS INTEGER
LANGUAGE plpgsql
CALLED ON NULL INPUT
SECURITY DEFINER
SET search_path = public, pg_temp
AS $sql$
DECLARE
new_build_id INTEGER;
BEGIN
INSERT INTO builds (
package,
version,
built_by,
duration,
status,
abi_tag
)
VALUES (
package,
version,
built_by,
duration,
FALSE,
abi_tag
)
RETURNING build_id
INTO new_build_id;
INSERT INTO output (build_id, output) VALUES (new_build_id, output);
RETURN new_build_id;
END;
$sql$;
REVOKE ALL ON FUNCTION log_build_failure(
TEXT, TEXT, INTEGER, INTERVAL, TEXT, TEXT
) FROM PUBLIC;
GRANT EXECUTE ON FUNCTION log_build_failure(
TEXT, TEXT, INTEGER, INTERVAL, TEXT, TEXT
) TO {username};

COMMIT;

0 comments on commit 26d1749

Please sign in to comment.