Skip to content

Commit 9022fb3

Browse files
committed
refactor: Move SQL queries from module to separate files
1 parent b479001 commit 9022fb3

18 files changed

+201
-245
lines changed

src/db/queries/getMainLanguages.sql

+3
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
SELECT DISTINCT COALESCE(JSON_EXTRACT(r.languages, '$[0]'), 'Other') mainLanguage
2+
FROM repositories r
3+
ORDER BY mainLanguage;

src/db/queries/getRepositories.sql

+11
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,11 @@
1+
SELECT r.*,
2+
l.name licenseName,
3+
l.nickname licenseNickname,
4+
l.url licenseUrl,
5+
o.login ownerLogin,
6+
o.url ownerUrl,
7+
o.isOrganization ownerIsOrganization
8+
FROM repositories AS r
9+
LEFT JOIN licenses l ON l.spdxId = r.license
10+
JOIN owners o ON o.login = r.owner
11+
ORDER BY r.starredAt DESC;
+6
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
SELECT t.name,
2+
t.stargazerCount
3+
FROM repositories_topics rt
4+
JOIN topics t ON t.name = rt.topicPk
5+
WHERE rt.repoPk = $repoPk
6+
ORDER BY t.stargazerCount DESC;

src/db/queries/getStats.sql

+12
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
SELECT COUNT(id) FILTER (
2+
WHERE unstarredAt IS NULL
3+
) AS starredCount,
4+
COUNT(id) FILTER (
5+
WHERE unstarredAt IS NOT NULL
6+
) AS unstarredCount,
7+
id AS lastRepoId,
8+
starredAt AS lastStarDate,
9+
importedAt AS lastImportDate
10+
FROM repositories
11+
ORDER BY starredAt DESC
12+
LIMIT 1;

src/db/queries/insertLicenses.sql

+2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
INSERT INTO licenses (spdxId, name, nickname, url)
2+
VALUES ($spdxId, $name, $nickname, $url) ON CONFLICT (spdxId) DO NOTHING;

src/db/queries/insertOwners.sql

+2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
INSERT INTO owners (login, url, isOrganization)
2+
VALUES ($login, $url, $isOrganization) ON CONFLICT (login) DO NOTHING;

src/db/queries/insertRepositories.sql

+64
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,64 @@
1+
INSERT INTO repositories (
2+
id,
3+
name,
4+
description,
5+
url,
6+
homepageUrl,
7+
owner,
8+
isArchived,
9+
isFork,
10+
isPrivate,
11+
isTemplate,
12+
latestRelease,
13+
license,
14+
stargazerCount,
15+
forkCount,
16+
createdAt,
17+
pushedAt,
18+
starredAt,
19+
updatedAt,
20+
importedAt,
21+
languages,
22+
fundingLinks
23+
)
24+
VALUES (
25+
$id,
26+
$name,
27+
$description,
28+
$url,
29+
$homepageUrl,
30+
$owner,
31+
$isArchived,
32+
$isFork,
33+
$isPrivate,
34+
$isTemplate,
35+
$latestRelease,
36+
$license,
37+
$stargazerCount,
38+
$forkCount,
39+
$createdAt,
40+
$pushedAt,
41+
$starredAt,
42+
$updatedAt,
43+
$importedAt,
44+
$languages,
45+
$fundingLinks
46+
) ON CONFLICT (id) DO
47+
UPDATE
48+
SET description = excluded.description,
49+
homepageUrl = excluded.homepageUrl,
50+
isArchived = excluded.isArchived,
51+
isFork = excluded.isFork,
52+
isPrivate = excluded.isPrivate,
53+
isTemplate = excluded.isTemplate,
54+
latestRelease = excluded.latestRelease,
55+
license = excluded.license,
56+
stargazerCount = excluded.stargazerCount,
57+
forkCount = excluded.forkCount,
58+
createdAt = excluded.createdAt,
59+
pushedAt = excluded.pushedAt,
60+
starredAt = excluded.starredAt,
61+
updatedAt = excluded.updatedAt,
62+
unstarredAt = NULL,
63+
languages = excluded.languages,
64+
fundingLinks = excluded.fundingLinks;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
INSERT INTO repositories_topics (repoPk, topicPk)
2+
VALUES ($repoPk, $topicPk) ON CONFLICT (repoPk, topicPk) DO NOTHING;

src/db/queries/insertTopics.sql

+4
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,4 @@
1+
INSERT INTO topics (name, stargazerCount)
2+
VALUES ($name, $stargazerCount) ON CONFLICT (name) DO
3+
UPDATE
4+
SET stargazerCount = excluded.stargazerCount;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
DELETE FROM licenses
2+
WHERE spdxId NOT IN (
3+
SELECT DISTINCT license
4+
FROM repositories
5+
)
6+
RETURNING spdxId;
+6
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
DELETE FROM owners
2+
WHERE login NOT IN (
3+
SELECT DISTINCT owner
4+
FROM repositories
5+
)
6+
RETURNING login;
+6
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
DELETE FROM topics
2+
WHERE name NOT IN (
3+
SELECT DISTINCT topicPk
4+
FROM repositories_topics
5+
)
6+
RETURNING name;

src/db/queries/removeRepositories.sql

+2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
DELETE FROM repositories_topics
2+
WHERE repoPk = $repoPk;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
DELETE FROM repositories_topics
2+
WHERE repoPk = $repoPk;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,4 @@
1+
DELETE FROM repositories
2+
WHERE unstarredAt IS NOT NULL
3+
RETURNING name,
4+
owner;

src/db/queries/schema.sql

+50
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
CREATE TABLE IF NOT EXISTS licenses (
2+
spdxId TEXT PRIMARY KEY UNIQUE NOT NULL,
3+
name TEXT NULL,
4+
nickname TEXT NULL,
5+
url TEXT NULL
6+
);
7+
CREATE TABLE IF NOT EXISTS owners (
8+
login TEXT PRIMARY KEY UNIQUE NOT NULL,
9+
url TEXT NOT NULL,
10+
isOrganization boolean DEFAULT FALSE
11+
);
12+
CREATE TABLE IF NOT EXISTS topics (
13+
name TEXT PRIMARY KEY UNIQUE NOT NULL,
14+
stargazerCount INTEGER
15+
);
16+
CREATE TABLE IF NOT EXISTS repositories (
17+
id TEXT PRIMARY KEY UNIQUE NOT NULL,
18+
name TEXT NOT NULL,
19+
description TEXT NULL,
20+
url TEXT NOT NULL,
21+
homepageUrl TEXT NULL,
22+
owner REFERENCES owners (login) ON DELETE CASCADE ON UPDATE CASCADE NOT NULL,
23+
isArchived boolean NOT NULL,
24+
isFork boolean NOT NULL,
25+
isPrivate boolean NOT NULL,
26+
isTemplate boolean NOT NULL,
27+
latestRelease TEXT NULL,
28+
license REFERENCES licenses (spdxId) ON DELETE
29+
SET NULL ON UPDATE CASCADE NULL,
30+
stargazerCount INTEGER NOT NULL,
31+
forkCount INTEGER NOT NULL,
32+
createdAt datetime NOT NULL,
33+
pushedAt datetime NOT NULL,
34+
starredAt datetime NOT NULL,
35+
updatedAt datetime NOT NULL,
36+
importedAt datetime NOT NULL,
37+
unstarredAt datetime NULL,
38+
languages TEXT NULL,
39+
fundingLinks TEXT NULL
40+
);
41+
CREATE INDEX IF NOT EXISTS idx__repositoriesNames ON repositories (name);
42+
CREATE INDEX IF NOT EXISTS idx__repositoriesOwners ON repositories (owner);
43+
CREATE INDEX IF NOT EXISTS idx__repositoriesLicenses ON repositories (license);
44+
CREATE INDEX IF NOT EXISTS idx__repositoriesStarredAt ON repositories (starredAt);
45+
CREATE INDEX IF NOT EXISTS idx__repositoriesImportedAt ON repositories (importedAt);
46+
CREATE TABLE IF NOT EXISTS repositories_topics (
47+
repoPk REFERENCES repositories (id) ON DELETE CASCADE ON UPDATE CASCADE NOT NULL,
48+
topicPk REFERENCES topics (name) ON DELETE CASCADE ON UPDATE CASCADE NOT NULL
49+
);
50+
CREATE UNIQUE INDEX IF NOT EXISTS uidx__repositories_topics ON repositories_topics (repoPk, topicPk);

0 commit comments

Comments
 (0)