Skip to content

Commit

Permalink
Materialize project hierarchies in separate table
Browse files Browse the repository at this point in the history
Signed-off-by: nscuro <[email protected]>
  • Loading branch information
nscuro committed Mar 8, 2025
1 parent 85f87a0 commit d8f8df7
Show file tree
Hide file tree
Showing 7 changed files with 159 additions and 200 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -95,71 +95,6 @@ public List<Policy> getAllPolicies() {
return query.executeList();
}

/**
* Fetch all {@link Policy}s that are applicable to a given {@link Project}.
*
* @param project The {@link Project} to fetch {@link Policy}s for
* @return A {@link List} of {@link Policy}s.
* @since 5.0.0
*/
public List<Policy> getApplicablePolicies(final Project project) {
var filter = """
(this.projects.isEmpty() && this.tags.isEmpty())
|| (this.projects.contains(:project)
""";
var params = new HashMap<String, Object>();
params.put("project", project);

// To compensate for missing support for recursion of Common Table Expressions (CTEs)
// in JDO, we have to fetch the UUIDs of all parent projects upfront. Otherwise, we'll
// not be able to evaluate whether the policy is inherited from parent projects.
var variables = "";
final List<UUID> parentUuids = getParents(project);
if (!parentUuids.isEmpty()) {
filter += """
|| (this.includeChildren
&& this.projects.contains(parentVar)
&& :parentUuids.contains(parentVar.uuid))
""";
variables += "org.dependencytrack.model.Project parentVar";
params.put("parentUuids", parentUuids);
}
filter += ")";

// DataNucleus generates an invalid SQL query when using the idiomatic solution.
// The following works, but it's ugly and likely doesn't perform well if the project
// has many tags. Worth trying the idiomatic way again once DN has been updated to > 6.0.4.
//
// filter += "m|| (this.tags.contains(commonTag) && :project.tags.contains(commonTag))";
// variables += "org.dependencytrack.model.Tag commonTag";
if (project.getTags() != null && !project.getTags().isEmpty()) {
filter += " || (";
for (int i = 0; i < project.getTags().size(); i++) {
filter += "this.tags.contains(:tag" + i + ")";
params.put("tag" + i, project.getTags().get(i));
if (i < (project.getTags().size() - 1)) {
filter += " || ";
}
}
filter += ")";
}

final List<Policy> policies;
final Query<Policy> query = pm.newQuery(Policy.class);
try {
query.setFilter(filter);
query.setNamedParameters(params);
if (!variables.isEmpty()) {
query.declareVariables(variables);
}
policies = List.copyOf(query.executeList());
} finally {
query.closeAll();
}

return policies;
}

/**
* Returns a policy by it's name.
* @param name the name of the policy (required)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -1242,37 +1242,6 @@ public PaginatedResult getProjectsWithoutDescendantsOf(final String name, final
return result;
}

/**
* Fetch the {@link UUID}s of all parents of a given {@link Project}.
*
* @param project The {@link Project} to fetch the parent {@link UUID}s for
* @return A {@link List} of {@link UUID}s
*/
@Override
public List<UUID> getParents(final Project project) {
return getParents(project.getUuid(), new ArrayList<>());
}

private List<UUID> getParents(final UUID uuid, final List<UUID> parents) {
final UUID parentUuid;
final Query<Project> query = pm.newQuery(Project.class);
try {
query.setFilter("uuid == :uuid && parent != null");
query.setParameters(uuid);
query.setResult("parent.uuid");
parentUuid = query.executeResultUnique(UUID.class);
} finally {
query.closeAll();
}

if (parentUuid == null) {
return parents;
}

parents.add(parentUuid);
return getParents(parentUuid, parents);
}

/**
* Check whether a {@link Project} with a given {@code name} and {@code version} exists.
*
Expand Down Expand Up @@ -1307,30 +1276,43 @@ public boolean doesProjectExist(final String name, final String version) {
}
}

private static boolean isChildOf(Project project, UUID uuid) {
boolean isChild = false;
if (project.getParent() != null) {
if (project.getParent().getUuid().equals(uuid)) {
return true;
} else {
isChild = isChildOf(project.getParent(), uuid);
}
private boolean isChildOf(Project project, UUID uuid) {
final Query<?> query = pm.newQuery(Query.SQL, /* language=SQL */ """
SELECT EXISTS(
SELECT 1
FROM "PROJECT_HIERARCHY"
WHERE "PARENT_PROJECT_ID" = (SELECT "ID" FROM "PROJECT" WHERE "UUID" = ?)
AND "CHILD_PROJECT_ID" = ?
)
""");
query.setParameters(uuid, project.getId());
try {
return (boolean) query.executeUnique();
} finally {
query.closeAll();
}
return isChild;
}

private static boolean hasActiveChild(Project project) {
boolean hasActiveChild = false;
if (project.getChildren() != null) {
for (Project child : project.getChildren()) {
if (child.isActive() || hasActiveChild) {
return true;
} else {
hasActiveChild = hasActiveChild(child);
}
}
private boolean hasActiveChild(Project project) {
final Query<?> query = pm.newQuery(Query.SQL, /* language=SQL */ """
SELECT EXISTS(
SELECT 1
FROM "PROJECT" AS "PARENT_PROJECT"
INNER JOIN "PROJECT_HIERARCHY"
ON "PROJECT_HIERARCHY"."PARENT_PROJECT_ID" = "PARENT_PROJECT"."ID"
INNER JOIN "PROJECT" AS "CHILD_PROJECT"
ON "CHILD_PROJECT"."ID" = "PROJECT_HIERARCHY"."CHILD_PROJECT_ID"
WHERE "PARENT_PROJECT"."ID" = ?
AND "CHILD_PROJECT"."INACTIVE_SINCE" IS NULL
AND "PROJECT_HIERARCHY"."DEPTH" > 0
)
""");
query.setParameters(project.getId());
try {
return (boolean) query.executeUnique();
} finally {
query.closeAll();
}
return hasActiveChild;
}

private List<ProjectVersion> getProjectVersions(Project project) {
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -566,10 +566,6 @@ public PaginatedResult getProjectsWithoutDescendantsOf(final String name, final
return getProjectQueryManager().getProjectsWithoutDescendantsOf(name, excludeInactive, project);
}

public List<UUID> getParents(final Project project) {
return getProjectQueryManager().getParents(project);
}

public boolean hasAccess(final Principal principal, final Project project) {
return getProjectQueryManager().hasAccess(principal, project);
}
Expand Down Expand Up @@ -781,10 +777,6 @@ public List<Policy> getAllPolicies() {
return getPolicyQueryManager().getAllPolicies();
}

public List<Policy> getApplicablePolicies(final Project project) {
return getPolicyQueryManager().getApplicablePolicies(project);
}

public Policy getPolicy(final String name) {
return getPolicyQueryManager().getPolicy(name);
}
Expand Down
121 changes: 121 additions & 0 deletions src/main/resources/migration/changelog-v5.6.0.xml
Original file line number Diff line number Diff line change
Expand Up @@ -636,4 +636,125 @@
onDelete="CASCADE" onUpdate="NO ACTION" referencedColumnNames="ID"
referencedTableName="WORKFLOW_STATE" validate="true"/>
</changeSet>

<changeSet id="v5.6.0-13" author="nscuro">
<createTable tableName="PROJECT_HIERARCHY">
<column name="PARENT_PROJECT_ID" type="BIGINT"/>
<column name="CHILD_PROJECT_ID" type="BIGINT"/>
<column name="DEPTH" type="SMALLINT">
<constraints nullable="false"/>
</column>
</createTable>

<addPrimaryKey
tableName="PROJECT_HIERARCHY"
columnNames="PARENT_PROJECT_ID, CHILD_PROJECT_ID"
constraintName="PROJECT_HIERARCHY_PK"/>
<addForeignKeyConstraint
baseTableName="PROJECT_HIERARCHY"
baseColumnNames="PARENT_PROJECT_ID"
constraintName="PROJECT_HIERARCHY_PARENT_PROJECT_FK"
referencedTableName="PROJECT"
referencedColumnNames="ID"
deferrable="true"
initiallyDeferred="true"/>
<addForeignKeyConstraint
baseTableName="PROJECT_HIERARCHY"
baseColumnNames="CHILD_PROJECT_ID"
constraintName="PROJECT_HIERARCHY_CHILD_PROJECT_FK"
referencedTableName="PROJECT"
referencedColumnNames="ID"
deferrable="true"
initiallyDeferred="true"/>

<sql splitStatements="false">
create function project_hierarchy_maintenance_on_project_insert()
returns trigger as $$
begin
insert into "PROJECT_HIERARCHY"("PARENT_PROJECT_ID", "CHILD_PROJECT_ID", "DEPTH")
values(new."ID", new."ID", 0);

insert into "PROJECT_HIERARCHY"("PARENT_PROJECT_ID", "CHILD_PROJECT_ID", "DEPTH")
select "PARENT_PROJECT_ID", new."ID", "DEPTH" + 1
from "PROJECT_HIERARCHY"
where "CHILD_PROJECT_ID" = new."PARENT_PROJECT_ID";

return new;
end;
$$ language plpgsql;
</sql>

<sql splitStatements="false">
create function project_hierarchy_maintenance_on_project_update()
returns trigger as $$
begin
delete from "PROJECT_HIERARCHY" where "CHILD_PROJECT_ID" = old."ID";

insert into "PROJECT_HIERARCHY"("PARENT_PROJECT_ID", "CHILD_PROJECT_ID", "DEPTH")
values(new."ID", new."ID", 0);

insert into "PROJECT_HIERARCHY"("PARENT_PROJECT_ID", "CHILD_PROJECT_ID", "DEPTH")
select "PARENT_PROJECT_ID", new."ID", "DEPTH" + 1
from "PROJECT_HIERARCHY"
where "CHILD_PROJECT_ID" = new."PARENT_PROJECT_ID";

return new;
end;
$$ language plpgsql;
</sql>

<sql splitStatements="false">
create function project_hierarchy_maintenance_on_project_delete()
returns trigger as $$
begin
delete from "PROJECT_HIERARCHY"
where "PARENT_PROJECT_ID" in (select "ID" from old_table)
or "CHILD_PROJECT_ID" in (select "ID" from old_table);

return null;
end;
$$ language plpgsql;
</sql>

<sql splitStatements="true">
create trigger trigger_project_hierarchy_maintenance_on_project_insert
after insert on "PROJECT"
for each row
execute function project_hierarchy_maintenance_on_project_insert();

create trigger trigger_project_hierarchy_maintenance_on_project_update
after update of "PARENT_PROJECT_ID" on "PROJECT"
for each row
execute function project_hierarchy_maintenance_on_project_update();

create trigger trigger_project_hierarchy_maintenance_on_project_delete
after delete on "PROJECT"
referencing old table as old_table
for each statement
execute function project_hierarchy_maintenance_on_project_delete();
</sql>

<!-- Populate hierarchy table with existing relationships -->
<sql splitStatements="true">
insert into "PROJECT_HIERARCHY"("PARENT_PROJECT_ID", "CHILD_PROJECT_ID", "DEPTH")
select "ID", "ID", 0 from "PROJECT";

with recursive cte_project_hierarchy as(
select "ID" as child_id
, "PARENT_PROJECT_ID" as parent_id
, 1 as depth
from "PROJECT"
union all
select child_id
, "PARENT_PROJECT_ID" as parent_id
, depth + 1 as depth
from cte_project_hierarchy
inner join "PROJECT"
on "PROJECT"."ID" = cte_project_hierarchy.parent_id
where "PROJECT"."PARENT_PROJECT_ID" is not null
)
insert into "PROJECT_HIERARCHY"("PARENT_PROJECT_ID", "CHILD_PROJECT_ID", "DEPTH")
select parent_id, child_id, depth from cte_project_hierarchy;
</sql>
</changeSet>
</databaseChangeLog>
Original file line number Diff line number Diff line change
Expand Up @@ -7,23 +7,12 @@ create or replace function has_project_access(
stable
as
$$
with recursive project_hierarchy(id, parent_id) as(
select "ID" as id
, "PARENT_PROJECT_ID" as parent_id
from "PROJECT"
where "ID" = project_id
union all
select "PROJECT"."ID" as id
, "PROJECT"."PARENT_PROJECT_ID" as parent_id
from "PROJECT"
inner join project_hierarchy
on project_hierarchy.parent_id = "PROJECT"."ID"
)
select exists(
select 1
from project_hierarchy
inner join "PROJECT_ACCESS_TEAMS"
on "PROJECT_ACCESS_TEAMS"."PROJECT_ID" = project_hierarchy.id
from "PROJECT_ACCESS_TEAMS"
inner join "PROJECT_HIERARCHY"
on "PROJECT_HIERARCHY"."PARENT_PROJECT_ID" = "PROJECT_ACCESS_TEAMS"."PROJECT_ID"
where "PROJECT_ACCESS_TEAMS"."TEAM_ID" = any(team_ids)
and "PROJECT_HIERARCHY"."CHILD_PROJECT_ID" = project_id
)
$$;
Loading

0 comments on commit d8f8df7

Please sign in to comment.