pgsql: Move queries to corresponding files

Aggregate queries in their corresponding files instead of having the
single file for every queries because the database is more complicated.
This commit is contained in:
Sida Chen 2018-09-19 15:38:07 -04:00
parent 53bf19aecf
commit 9c49d9dc55
9 changed files with 225 additions and 237 deletions

View File

@ -10,6 +10,38 @@ import (
"github.com/coreos/clair/pkg/commonerr"
)
const (
insertAncestry = `
INSERT INTO ancestry (name) VALUES ($1) RETURNING id`
searchAncestryLayer = `
SELECT layer.hash, layer.id, ancestry_layer.ancestry_index
FROM layer, ancestry_layer
WHERE ancestry_layer.ancestry_id = $1
AND ancestry_layer.layer_id = layer.id
ORDER BY ancestry_layer.ancestry_index ASC`
searchAncestryFeatures = `
SELECT namespace.name, namespace.version_format, feature.name, feature.version, feature.version_format, ancestry_layer.ancestry_index
FROM namespace, feature, namespaced_feature, ancestry_layer, ancestry_feature
WHERE ancestry_layer.ancestry_id = $1
AND ancestry_feature.ancestry_layer_id = ancestry_layer.id
AND ancestry_feature.namespaced_feature_id = namespaced_feature.id
AND namespaced_feature.feature_id = feature.id
AND namespaced_feature.namespace_id = namespace.id`
searchAncestry = `SELECT id FROM ancestry WHERE name = $1`
removeAncestry = `DELETE FROM ancestry WHERE name = $1`
insertAncestryLayer = `
INSERT INTO ancestry_layer (ancestry_id, ancestry_index, layer_id) VALUES
($1, $2, (SELECT layer.id FROM layer WHERE hash = $3 LIMIT 1))
RETURNING id`
insertAncestryLayerFeature = `
INSERT INTO ancestry_feature
(ancestry_layer_id, namespaced_feature_id, feature_detector_id, namespace_detector_id) VALUES
($1, $2, $3, $4)`
)
type ancestryLayerWithID struct {
database.AncestryLayer

View File

@ -27,6 +27,44 @@ import (
"github.com/coreos/clair/pkg/commonerr"
)
const (
// feature.go
soiNamespacedFeature = `
WITH new_feature_ns AS (
INSERT INTO namespaced_feature(feature_id, namespace_id)
SELECT CAST ($1 AS INTEGER), CAST ($2 AS INTEGER)
WHERE NOT EXISTS ( SELECT id FROM namespaced_feature WHERE namespaced_feature.feature_id = $1 AND namespaced_feature.namespace_id = $2)
RETURNING id
)
SELECT id FROM namespaced_feature WHERE namespaced_feature.feature_id = $1 AND namespaced_feature.namespace_id = $2
UNION
SELECT id FROM new_feature_ns`
searchPotentialAffectingVulneraibilities = `
SELECT nf.id, v.id, vaf.affected_version, vaf.id
FROM vulnerability_affected_feature AS vaf, vulnerability AS v,
namespaced_feature AS nf, feature AS f
WHERE nf.id = ANY($1)
AND nf.feature_id = f.id
AND nf.namespace_id = v.namespace_id
AND vaf.feature_name = f.name
AND vaf.vulnerability_id = v.id
AND v.deleted_at IS NULL`
searchNamespacedFeaturesVulnerabilities = `
SELECT vanf.namespaced_feature_id, v.name, v.description, v.link,
v.severity, v.metadata, vaf.fixedin, n.name, n.version_format
FROM vulnerability_affected_namespaced_feature AS vanf,
Vulnerability AS v,
vulnerability_affected_feature AS vaf,
namespace AS n
WHERE vanf.namespaced_feature_id = ANY($1)
AND vaf.id = vanf.added_by
AND v.id = vanf.vulnerability_id
AND n.id = v.namespace_id
AND v.deleted_at IS NULL`
)
var (
errFeatureNotFound = errors.New("Feature not found")
)

View File

@ -23,6 +23,15 @@ import (
"github.com/coreos/clair/pkg/commonerr"
)
const (
searchKeyValue = `SELECT value FROM KeyValue WHERE key = $1`
upsertKeyValue = `
INSERT INTO KeyValue(key, value)
VALUES ($1, $2)
ON CONFLICT ON CONSTRAINT keyvalue_key_key
DO UPDATE SET key=$1, value=$2`
)
func (tx *pgSession) UpdateKeyValue(key, value string) (err error) {
if key == "" || value == "" {
log.Warning("could not insert a flag which has an empty name or value")

View File

@ -22,15 +22,31 @@ import (
"github.com/coreos/clair/pkg/commonerr"
)
func (tx *pgSession) FindLayer(hash string) (database.Layer, bool, error) {
var (
layer database.Layer
layerID int64
ok bool
err error
)
const (
soiLayer = `
WITH new_layer AS (
INSERT INTO layer (hash)
SELECT CAST ($1 AS VARCHAR)
WHERE NOT EXISTS (SELECT id FROM layer WHERE hash = $1)
RETURNING id
)
SELECT id FROM new_Layer
UNION
SELECT id FROM layer WHERE hash = $1`
layer.LayerMetadata, layerID, ok, err = tx.findLayer(hash)
searchLayerFeatures = `
SELECT feature_id, detector_id
FROM layer_feature
WHERE layer_id = $1`
searchLayerNamespaces = `
SELECT namespace.Name, namespace.version_format
FROM namespace, layer_namespace
WHERE layer_namespace.layer_id = $1
AND layer_namespace.namespace_id = namespace.id`
searchLayer = `SELECT id FROM layer WHERE hash = $1`
)
if err != nil {
return layer, false, err
}

View File

@ -23,6 +23,14 @@ import (
"github.com/coreos/clair/pkg/commonerr"
)
const (
soiLock = `INSERT INTO lock(name, owner, until) VALUES ($1, $2, $3)`
searchLock = `SELECT owner, until FROM Lock WHERE name = $1`
updateLock = `UPDATE Lock SET until = $3 WHERE name = $1 AND owner = $2`
removeLock = `DELETE FROM Lock WHERE name = $1 AND owner = $2`
removeLockExpired = `DELETE FROM LOCK WHERE until < CURRENT_TIMESTAMP`
)
var (
errLockNotFound = errors.New("lock is not in database")
)

View File

@ -23,6 +23,10 @@ import (
"github.com/coreos/clair/pkg/commonerr"
)
const (
searchNamespaceID = `SELECT id FROM Namespace WHERE name = $1 AND version_format = $2`
)
var (
errNamespaceNotFound = errors.New("Requested Namespace is not in database")
)

View File

@ -26,6 +26,49 @@ import (
"github.com/coreos/clair/pkg/pagination"
)
const (
// notification.go
insertNotification = `
INSERT INTO Vulnerability_Notification(name, created_at, old_vulnerability_id, new_vulnerability_id)
VALUES ($1, $2, $3, $4)`
updatedNotificationAsRead = `
UPDATE Vulnerability_Notification
SET notified_at = CURRENT_TIMESTAMP
WHERE name = $1`
removeNotification = `
UPDATE Vulnerability_Notification
SET deleted_at = CURRENT_TIMESTAMP
WHERE name = $1 AND deleted_at IS NULL`
searchNotificationAvailable = `
SELECT name, created_at, notified_at, deleted_at
FROM Vulnerability_Notification
WHERE (notified_at IS NULL OR notified_at < $1)
AND deleted_at IS NULL
AND name NOT IN (SELECT name FROM Lock)
ORDER BY Random()
LIMIT 1`
searchNotification = `
SELECT created_at, notified_at, deleted_at, old_vulnerability_id, new_vulnerability_id
FROM Vulnerability_Notification
WHERE name = $1`
searchNotificationVulnerableAncestry = `
SELECT DISTINCT ON (a.id)
a.id, a.name
FROM vulnerability_affected_namespaced_feature AS vanf,
ancestry_layer AS al, ancestry_feature AS af
WHERE vanf.vulnerability_id = $1
AND al.ancestry_id >= $2
AND al.id = af.ancestry_layer_id
AND af.namespaced_feature_id = vanf.namespaced_feature_id
ORDER BY a.id ASC
LIMIT $3;`
)
var (
errNotificationNotFound = errors.New("requested notification is not found")
)

View File

@ -21,235 +21,6 @@ import (
"github.com/lib/pq"
)
const (
lockVulnerabilityAffects = `LOCK vulnerability_affected_namespaced_feature IN SHARE ROW EXCLUSIVE MODE`
// keyvalue.go
searchKeyValue = `SELECT value FROM KeyValue WHERE key = $1`
upsertKeyValue = `
INSERT INTO KeyValue(key, value)
VALUES ($1, $2)
ON CONFLICT ON CONSTRAINT keyvalue_key_key
DO UPDATE SET key=$1, value=$2`
// namespace.go
searchNamespaceID = `SELECT id FROM Namespace WHERE name = $1 AND version_format = $2`
// feature.go
soiNamespacedFeature = `
WITH new_feature_ns AS (
INSERT INTO namespaced_feature(feature_id, namespace_id)
SELECT CAST ($1 AS INTEGER), CAST ($2 AS INTEGER)
WHERE NOT EXISTS ( SELECT id FROM namespaced_feature WHERE namespaced_feature.feature_id = $1 AND namespaced_feature.namespace_id = $2)
RETURNING id
)
SELECT id FROM namespaced_feature WHERE namespaced_feature.feature_id = $1 AND namespaced_feature.namespace_id = $2
UNION
SELECT id FROM new_feature_ns`
searchPotentialAffectingVulneraibilities = `
SELECT nf.id, v.id, vaf.affected_version, vaf.id
FROM vulnerability_affected_feature AS vaf, vulnerability AS v,
namespaced_feature AS nf, feature AS f
WHERE nf.id = ANY($1)
AND nf.feature_id = f.id
AND nf.namespace_id = v.namespace_id
AND vaf.feature_name = f.name
AND vaf.vulnerability_id = v.id
AND v.deleted_at IS NULL`
searchNamespacedFeaturesVulnerabilities = `
SELECT vanf.namespaced_feature_id, v.name, v.description, v.link,
v.severity, v.metadata, vaf.fixedin, n.name, n.version_format
FROM vulnerability_affected_namespaced_feature AS vanf,
Vulnerability AS v,
vulnerability_affected_feature AS vaf,
namespace AS n
WHERE vanf.namespaced_feature_id = ANY($1)
AND vaf.id = vanf.added_by
AND v.id = vanf.vulnerability_id
AND n.id = v.namespace_id
AND v.deleted_at IS NULL`
// layer.go
soiLayer = `
WITH new_layer AS (
INSERT INTO layer (hash)
SELECT CAST ($1 AS VARCHAR)
WHERE NOT EXISTS (SELECT id FROM layer WHERE hash = $1)
RETURNING id
)
SELECT id FROM new_Layer
UNION
SELECT id FROM layer WHERE hash = $1`
searchLayerFeatures = `
SELECT feature.Name, feature.Version, feature.version_format
FROM feature, layer_feature
WHERE layer_feature.layer_id = $1
AND layer_feature.feature_id = feature.id`
searchLayerNamespaces = `
SELECT namespace.Name, namespace.version_format
FROM namespace, layer_namespace
WHERE layer_namespace.layer_id = $1
AND layer_namespace.namespace_id = namespace.id`
searchLayer = `SELECT id FROM layer WHERE hash = $1`
searchLayerDetectors = `SELECT detector FROM layer_detector WHERE layer_id = $1`
searchLayerListers = `SELECT lister FROM layer_lister WHERE layer_id = $1`
// lock.go
soiLock = `INSERT INTO lock(name, owner, until) VALUES ($1, $2, $3)`
searchLock = `SELECT owner, until FROM Lock WHERE name = $1`
updateLock = `UPDATE Lock SET until = $3 WHERE name = $1 AND owner = $2`
removeLock = `DELETE FROM Lock WHERE name = $1 AND owner = $2`
removeLockExpired = `DELETE FROM LOCK WHERE until < CURRENT_TIMESTAMP`
// vulnerability.go
searchVulnerability = `
SELECT v.id, v.description, v.link, v.severity, v.metadata, n.version_format
FROM vulnerability AS v, namespace AS n
WHERE v.namespace_id = n.id
AND v.name = $1
AND n.name = $2
AND v.deleted_at IS NULL
`
insertVulnerabilityAffected = `
INSERT INTO vulnerability_affected_feature(vulnerability_id, feature_name, affected_version, fixedin)
VALUES ($1, $2, $3, $4)
RETURNING ID
`
searchVulnerabilityAffected = `
SELECT vulnerability_id, feature_name, affected_version, fixedin
FROM vulnerability_affected_feature
WHERE vulnerability_id = ANY($1)
`
searchVulnerabilityByID = `
SELECT v.name, v.description, v.link, v.severity, v.metadata, n.name, n.version_format
FROM vulnerability AS v, namespace AS n
WHERE v.namespace_id = n.id
AND v.id = $1`
searchVulnerabilityPotentialAffected = `
WITH req AS (
SELECT vaf.id AS vaf_id, n.id AS n_id, vaf.feature_name AS name, v.id AS vulnerability_id
FROM vulnerability_affected_feature AS vaf,
vulnerability AS v,
namespace AS n
WHERE vaf.vulnerability_id = ANY($1)
AND v.id = vaf.vulnerability_id
AND n.id = v.namespace_id
)
SELECT req.vulnerability_id, nf.id, f.version, req.vaf_id AS added_by
FROM feature AS f, namespaced_feature AS nf, req
WHERE f.name = req.name
AND nf.namespace_id = req.n_id
AND nf.feature_id = f.id`
insertVulnerabilityAffectedNamespacedFeature = `
INSERT INTO vulnerability_affected_namespaced_feature(vulnerability_id, namespaced_feature_id, added_by)
VALUES ($1, $2, $3)`
insertVulnerability = `
WITH ns AS (
SELECT id FROM namespace WHERE name = $6 AND version_format = $7
)
INSERT INTO Vulnerability(namespace_id, name, description, link, severity, metadata, created_at)
VALUES((SELECT id FROM ns), $1, $2, $3, $4, $5, CURRENT_TIMESTAMP)
RETURNING id`
removeVulnerability = `
UPDATE Vulnerability
SET deleted_at = CURRENT_TIMESTAMP
WHERE namespace_id = (SELECT id FROM Namespace WHERE name = $1)
AND name = $2
AND deleted_at IS NULL
RETURNING id`
// notification.go
insertNotification = `
INSERT INTO Vulnerability_Notification(name, created_at, old_vulnerability_id, new_vulnerability_id)
VALUES ($1, $2, $3, $4)`
updatedNotificationAsRead = `
UPDATE Vulnerability_Notification
SET notified_at = CURRENT_TIMESTAMP
WHERE name = $1`
removeNotification = `
UPDATE Vulnerability_Notification
SET deleted_at = CURRENT_TIMESTAMP
WHERE name = $1 AND deleted_at IS NULL`
searchNotificationAvailable = `
SELECT name, created_at, notified_at, deleted_at
FROM Vulnerability_Notification
WHERE (notified_at IS NULL OR notified_at < $1)
AND deleted_at IS NULL
AND name NOT IN (SELECT name FROM Lock)
ORDER BY Random()
LIMIT 1`
searchNotification = `
SELECT created_at, notified_at, deleted_at, old_vulnerability_id, new_vulnerability_id
FROM Vulnerability_Notification
WHERE name = $1`
searchNotificationVulnerableAncestry = `
SELECT DISTINCT ON (a.id)
a.id, a.name
FROM vulnerability_affected_namespaced_feature AS vanf,
ancestry_layer AS al, ancestry_feature AS af
WHERE vanf.vulnerability_id = $1
AND al.ancestry_id >= $2
AND al.id = af.ancestry_layer_id
AND af.namespaced_feature_id = vanf.namespaced_feature_id
ORDER BY a.id ASC
LIMIT $3;`
// ancestry.go
persistAncestryLister = `
INSERT INTO ancestry_lister (ancestry_id, lister)
SELECT CAST ($1 AS INTEGER), CAST ($2 AS TEXT)
WHERE NOT EXISTS (SELECT id FROM ancestry_lister WHERE ancestry_id = $1 AND lister = $2) ON CONFLICT DO NOTHING`
persistAncestryDetector = `
INSERT INTO ancestry_detector (ancestry_id, detector)
SELECT CAST ($1 AS INTEGER), CAST ($2 AS TEXT)
WHERE NOT EXISTS (SELECT id FROM ancestry_detector WHERE ancestry_id = $1 AND detector = $2) ON CONFLICT DO NOTHING`
insertAncestry = `INSERT INTO ancestry (name) VALUES ($1) RETURNING id`
searchAncestryLayer = `
SELECT layer.hash, layer.id, ancestry_layer.ancestry_index
FROM layer, ancestry_layer
WHERE ancestry_layer.ancestry_id = $1
AND ancestry_layer.layer_id = layer.id
ORDER BY ancestry_layer.ancestry_index ASC`
searchAncestryFeatures = `
SELECT namespace.name, namespace.version_format, feature.name, feature.version, feature.version_format, ancestry_layer.ancestry_index
FROM namespace, feature, namespaced_feature, ancestry_layer, ancestry_feature
WHERE ancestry_layer.ancestry_id = $1
AND ancestry_feature.ancestry_layer_id = ancestry_layer.id
AND ancestry_feature.namespaced_feature_id = namespaced_feature.id
AND namespaced_feature.feature_id = feature.id
AND namespaced_feature.namespace_id = namespace.id`
searchAncestry = `SELECT id FROM ancestry WHERE name = $1`
searchAncestryDetectors = `SELECT detector FROM ancestry_detector WHERE ancestry_id = $1`
searchAncestryListers = `SELECT lister FROM ancestry_lister WHERE ancestry_id = $1`
removeAncestry = `DELETE FROM ancestry WHERE name = $1`
insertAncestryLayer = `INSERT INTO ancestry_layer(ancestry_id, ancestry_index, layer_id) VALUES($1,$2, (SELECT layer.id FROM layer WHERE hash = $3 LIMIT 1)) RETURNING id`
insertAncestryLayerFeature = `INSERT INTO ancestry_feature(ancestry_layer_id, namespaced_feature_id) VALUES ($1, $2)`
)
// NOTE(Sida): Every search query can only have count less than postgres set
// stack depth. IN will be resolved to nested OR_s and the parser might exceed
// stack depth. TODO(Sida): Generate different queries for different count: if

View File

@ -26,6 +26,73 @@ import (
"github.com/coreos/clair/ext/versionfmt"
)
const (
lockVulnerabilityAffects = `LOCK vulnerability_affected_namespaced_feature IN SHARE ROW EXCLUSIVE MODE`
searchVulnerability = `
SELECT v.id, v.description, v.link, v.severity, v.metadata, n.version_format
FROM vulnerability AS v, namespace AS n
WHERE v.namespace_id = n.id
AND v.name = $1
AND n.name = $2
AND v.deleted_at IS NULL
`
insertVulnerabilityAffected = `
INSERT INTO vulnerability_affected_feature(vulnerability_id, feature_name, affected_version, fixedin)
VALUES ($1, $2, $3, $4)
RETURNING ID
`
searchVulnerabilityAffected = `
SELECT vulnerability_id, feature_name, affected_version, fixedin
FROM vulnerability_affected_feature
WHERE vulnerability_id = ANY($1)
`
searchVulnerabilityByID = `
SELECT v.name, v.description, v.link, v.severity, v.metadata, n.name, n.version_format
FROM vulnerability AS v, namespace AS n
WHERE v.namespace_id = n.id
AND v.id = $1`
searchVulnerabilityPotentialAffected = `
WITH req AS (
SELECT vaf.id AS vaf_id, n.id AS n_id, vaf.feature_name AS name, v.id AS vulnerability_id
FROM vulnerability_affected_feature AS vaf,
vulnerability AS v,
namespace AS n
WHERE vaf.vulnerability_id = ANY($1)
AND v.id = vaf.vulnerability_id
AND n.id = v.namespace_id
)
SELECT req.vulnerability_id, nf.id, f.version, req.vaf_id AS added_by
FROM feature AS f, namespaced_feature AS nf, req
WHERE f.name = req.name
AND nf.namespace_id = req.n_id
AND nf.feature_id = f.id`
insertVulnerabilityAffectedNamespacedFeature = `
INSERT INTO vulnerability_affected_namespaced_feature(vulnerability_id, namespaced_feature_id, added_by)
VALUES ($1, $2, $3)`
insertVulnerability = `
WITH ns AS (
SELECT id FROM namespace WHERE name = $6 AND version_format = $7
)
INSERT INTO Vulnerability(namespace_id, name, description, link, severity, metadata, created_at)
VALUES((SELECT id FROM ns), $1, $2, $3, $4, $5, CURRENT_TIMESTAMP)
RETURNING id`
removeVulnerability = `
UPDATE Vulnerability
SET deleted_at = CURRENT_TIMESTAMP
WHERE namespace_id = (SELECT id FROM Namespace WHERE name = $1)
AND name = $2
AND deleted_at IS NULL
RETURNING id`
)
var (
errVulnerabilityNotFound = errors.New("vulnerability is not in database")
)