Skip to content

Conversation

@acwhite211
Copy link
Member

@acwhite211 acwhite211 commented Feb 7, 2025

Fixes #6089
Fixes #6016
Fixes #6271

Creates a new functions that builds a SQLAlchemy subquery that, in addition to the previous implementation's use case of filter CollectionObjects by all it's paths to chronostrat age, returns a formatted age range for a CollectionObject's maximum start age to its minimum end age. This allows the query QB to display this formatted range in the age column in the query results. This PR also implements the strict query behavior described in #6271.

image image

Here is a compiled SQLAlchemy query that get generated for a simple CollectionObject Age query:

SELECT
	collectionobject.`CollectionObjectID`,
	concat_ws(' - ',
			  ifnull(regexp_replace(CAST(agg_subq.max_start_period AS CHAR), '\\.(0+)$', ''), ''),
			  ifnull(regexp_replace(CAST(agg_subq.min_end_period AS CHAR), '\\.(0+)$', ''), '')) AS age
FROM
	collectionobject
INNER JOIN (
	SELECT
		unioned.coid AS coid,
		min(unioned.endperiod) AS min_end_period,
		max(unioned.startperiod) AS max_start_period
	FROM
		(
		SELECT
			absoluteage.`CollectionObjectID` AS coid,
			CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) - coalesce(absoluteage.`AgeUncertainty`, 0) AS startperiod,
			CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) + coalesce(absoluteage.`AgeUncertainty`, 0) AS endperiod
		FROM
			absoluteage
		WHERE
			CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) - coalesce(absoluteage.`AgeUncertainty`, 0) <= 2000.0
			AND CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) + coalesce(absoluteage.`AgeUncertainty`, 0) >= 2.0
	UNION ALL
		SELECT
			r.`CollectionObjectID` AS coid,
			CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN greatest(CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0), CAST(aend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(aend.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0))
				ELSE CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0)
			END AS startperiod,
			CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN least((CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0), (CAST(aend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(aend.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0))
				ELSE (CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0)
			END AS endperiod
		FROM
			relativeage AS r
		INNER JOIN geologictimeperiod AS a ON
			r.`AgeNameID` = a.`GeologicTimePeriodID`
		LEFT OUTER JOIN geologictimeperiod AS aend ON
			r.`AgeNameEndID` = aend.`GeologicTimePeriodID`
		WHERE
			a.`StartPeriod` IS NOT NULL
			AND a.`EndPeriod` IS NOT NULL
			AND a.`StartPeriod` >= a.`EndPeriod`
			AND (r.`AgeNameEndID` IS NULL
				OR aend.`StartPeriod` IS NOT NULL
				AND aend.`EndPeriod` IS NOT NULL
				AND aend.`StartPeriod` >= aend.`EndPeriod`)
			AND CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN greatest(CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0), CAST(aend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(aend.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0))
				ELSE CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0)
			END <= 2000.0
			AND CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN least((CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0), (CAST(aend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(aend.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0))
				ELSE (CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0)
			END >= 2.0
	UNION ALL
		SELECT
			DISTINCT c.`CollectionObjectID` AS coid,
			CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN least(CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0), CAST(csend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(csend.`StartUncertainty`, 0))
				ELSE CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0)
			END AS startperiod,
			CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN greatest(CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0), CAST(csend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(csend.`EndUncertainty`, 0))
				ELSE CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0)
			END AS endperiod
		FROM
			collectionobject AS c
		LEFT OUTER JOIN collectingevent AS ce ON
			c.`CollectingEventID` = ce.`CollectingEventID`
		LEFT OUTER JOIN locality AS l ON
			ce.`LocalityID` = l.`LocalityID`
		LEFT OUTER JOIN paleocontext AS p ON
			c.`PaleoContextID` = p.`PaleoContextID`
			OR ce.`PaleoContextID` = p.`PaleoContextID`
			OR l.`PaleoContextID` = p.`PaleoContextID`
		LEFT OUTER JOIN geologictimeperiod AS cs ON
			p.`ChronosStratID` = cs.`GeologicTimePeriodID`
		LEFT OUTER JOIN geologictimeperiod AS csend ON
			p.`ChronosStratEndID` = csend.`GeologicTimePeriodID`
		WHERE
			p.`PaleoContextID` IS NOT NULL
			AND cs.`StartPeriod` IS NOT NULL
			AND cs.`EndPeriod` IS NOT NULL
			AND cs.`StartPeriod` >= cs.`EndPeriod`
			AND (p.`ChronosStratEndID` IS NULL
				OR csend.`StartPeriod` IS NOT NULL
				AND csend.`EndPeriod` IS NOT NULL
				AND csend.`StartPeriod` >= csend.`EndPeriod`)
			AND CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN least(CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0), CAST(csend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(csend.`StartUncertainty`, 0))
				ELSE CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0)
			END <= 2000.0
			AND CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN greatest(CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0), CAST(csend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(csend.`EndUncertainty`, 0))
				ELSE CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0)
			END >= 2.0) AS unioned
	GROUP BY
		unioned.coid) AS agg_subq ON
	collectionobject.`CollectionObjectID` = agg_subq.coid
WHERE
	collectionobject.`CollectionID` = 98304;

Checklist

  • Self-review the PR after opening it to make sure the changes look good and
    self-explanatory (or properly documented)
  • Add relevant issue to release milestone

Testing instructions

  • Select a database with chronostart records, like ciscollections_2_15_24
  • Create an age query with a large range that will include lots of COs with an associated chronostrat.
  • See that the "Collection Object - Age" column has a date range.

@acwhite211 acwhite211 added 2 - Queries Issues that are related to the query builder or queries in general geospecify labels Feb 7, 2025
@acwhite211 acwhite211 added this to the 7.10.1 milestone Feb 7, 2025
@acwhite211 acwhite211 self-assigned this Feb 7, 2025
@acwhite211
Copy link
Member Author

Have some code cleanup to do before merging.

Here is another example of a compiled SQLAlchemy query that gets generated:

SELECT
	collectionobject.`CollectionObjectID`,
	concat_ws(' - ', ifnull(regexp_replace(CAST(agg_subq.max_start_period AS CHAR), '\\.(0+)$', ''), ''), ifnull(regexp_replace(CAST(agg_subq.min_end_period AS CHAR), '\\.(0+)$', ''), '')) AS age,
	absoluteage_1.`AbsoluteAge`,
	geologictimeperiod_1.`Name`,
	geologictimeperiod_2.`Name`,
	geologictimeperiod_3.`Name`,
	geologictimeperiod_4.`Name`,
	geologictimeperiod_5.`Name`,
	geologictimeperiod_6.`Name`
FROM
	collectionobject
INNER JOIN (
	SELECT
		unioned.coid AS coid,
		min(unioned.endperiod) AS min_end_period,
		max(unioned.startperiod) AS max_start_period
	FROM
		(
		SELECT
			absoluteage.`CollectionObjectID` AS coid,
			CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) - coalesce(absoluteage.`AgeUncertainty`, 0) AS startperiod,
			CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) + coalesce(absoluteage.`AgeUncertainty`, 0) AS endperiod
		FROM
			absoluteage
		WHERE
			CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) - coalesce(absoluteage.`AgeUncertainty`, 0) <= 2000.0
			AND CAST(absoluteage.`AbsoluteAge` AS DECIMAL(10, 6)) + coalesce(absoluteage.`AgeUncertainty`, 0) >= 2.0
	UNION ALL
		SELECT
			r.`CollectionObjectID` AS coid,
			CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN greatest(CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0), CAST(aend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(aend.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0))
				ELSE CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0)
			END AS startperiod,
			CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN least((CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0), (CAST(aend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(aend.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0))
				ELSE (CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0)
			END AS endperiod
		FROM
			relativeage AS r
		INNER JOIN geologictimeperiod AS a ON
			r.`AgeNameID` = a.`GeologicTimePeriodID`
		LEFT OUTER JOIN geologictimeperiod AS aend ON
			r.`AgeNameEndID` = aend.`GeologicTimePeriodID`
		WHERE
			a.`StartPeriod` IS NOT NULL
			AND a.`EndPeriod` IS NOT NULL
			AND a.`StartPeriod` >= a.`EndPeriod`
			AND (r.`AgeNameEndID` IS NULL
				OR aend.`StartPeriod` IS NOT NULL
				AND aend.`EndPeriod` IS NOT NULL
				AND aend.`StartPeriod` >= aend.`EndPeriod`)
			AND CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN greatest(CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0), CAST(aend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(aend.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0))
				ELSE CAST(a.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(a.`StartUncertainty`, 0) + coalesce(r.`AgeUncertainty`, 0)
			END <= 2000.0
			AND CASE
				WHEN (r.`AgeNameEndID` IS NOT NULL) THEN least((CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0), (CAST(aend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(aend.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0))
				ELSE (CAST(a.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(a.`EndUncertainty`, 0)) - coalesce(r.`AgeUncertainty`, 0)
			END >= 2.0
	UNION ALL
		SELECT
			DISTINCT c.`CollectionObjectID` AS coid,
			CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN least(CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0), CAST(csend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(csend.`StartUncertainty`, 0))
				ELSE CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0)
			END AS startperiod,
			CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN greatest(CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0), CAST(csend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(csend.`EndUncertainty`, 0))
				ELSE CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0)
			END AS endperiod
		FROM
			collectionobject AS c
		LEFT OUTER JOIN collectingevent AS ce ON
			c.`CollectingEventID` = ce.`CollectingEventID`
		LEFT OUTER JOIN locality AS l ON
			ce.`LocalityID` = l.`LocalityID`
		LEFT OUTER JOIN paleocontext AS p ON
			c.`PaleoContextID` = p.`PaleoContextID`
			OR ce.`PaleoContextID` = p.`PaleoContextID`
			OR l.`PaleoContextID` = p.`PaleoContextID`
		LEFT OUTER JOIN geologictimeperiod AS cs ON
			p.`ChronosStratID` = cs.`GeologicTimePeriodID`
		LEFT OUTER JOIN geologictimeperiod AS csend ON
			p.`ChronosStratEndID` = csend.`GeologicTimePeriodID`
		WHERE
			p.`PaleoContextID` IS NOT NULL
			AND cs.`StartPeriod` IS NOT NULL
			AND cs.`EndPeriod` IS NOT NULL
			AND cs.`StartPeriod` >= cs.`EndPeriod`
			AND (p.`ChronosStratEndID` IS NULL
				OR csend.`StartPeriod` IS NOT NULL
				AND csend.`EndPeriod` IS NOT NULL
				AND csend.`StartPeriod` >= csend.`EndPeriod`)
			AND CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN least(CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0), CAST(csend.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(csend.`StartUncertainty`, 0))
				ELSE CAST(cs.`StartPeriod` AS DECIMAL(10, 6)) + coalesce(cs.`StartUncertainty`, 0)
			END <= 2000.0
			AND CASE
				WHEN (p.`ChronosStratEndID` IS NOT NULL) THEN greatest(CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0), CAST(csend.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(csend.`EndUncertainty`, 0))
				ELSE CAST(cs.`EndPeriod` AS DECIMAL(10, 6)) - coalesce(cs.`EndUncertainty`, 0)
			END >= 2.0) AS unioned
	GROUP BY
		unioned.coid) AS agg_subq ON
	collectionobject.`CollectionObjectID` = agg_subq.coid
LEFT OUTER JOIN absoluteage AS absoluteage_1 ON
	collectionobject.`CollectionObjectID` = absoluteage_1.`CollectionObjectID`
LEFT OUTER JOIN relativeage AS relativeage_1 ON
	collectionobject.`CollectionObjectID` = relativeage_1.`CollectionObjectID`
LEFT OUTER JOIN geologictimeperiod AS geologictimeperiod_1 ON
	geologictimeperiod_1.`GeologicTimePeriodID` = relativeage_1.`AgeNameID`
LEFT OUTER JOIN geologictimeperiod AS geologictimeperiod_2 ON
	geologictimeperiod_2.`GeologicTimePeriodID` = relativeage_1.`AgeNameEndID`
LEFT OUTER JOIN paleocontext AS paleocontext_1 ON
	paleocontext_1.`PaleoContextID` = collectionobject.`PaleoContextID`
LEFT OUTER JOIN geologictimeperiod AS geologictimeperiod_3 ON
	geologictimeperiod_3.`GeologicTimePeriodID` = paleocontext_1.`ChronosStratID`
LEFT OUTER JOIN geologictimeperiod AS geologictimeperiod_4 ON
	geologictimeperiod_4.`GeologicTimePeriodID` = paleocontext_1.`ChronosStratEndID`
LEFT OUTER JOIN collectingevent AS collectingevent_1 ON
	paleocontext_1.`PaleoContextID` = collectingevent_1.`PaleoContextID`
LEFT OUTER JOIN paleocontext AS paleocontext_2 ON
	paleocontext_2.`PaleoContextID` = collectingevent_1.`PaleoContextID`
LEFT OUTER JOIN geologictimeperiod AS geologictimeperiod_5 ON
	geologictimeperiod_5.`GeologicTimePeriodID` = paleocontext_2.`ChronosStratID`
LEFT OUTER JOIN geologictimeperiod AS geologictimeperiod_6 ON
	geologictimeperiod_6.`GeologicTimePeriodID` = paleocontext_2.`ChronosStratEndID`
WHERE
	collectionobject.`CollectionID` = 98304;

@acwhite211
Copy link
Member Author

It seems that the behavior for querying by the time period name isn't working as expected now. Investigating...

@CarolineDenis CarolineDenis requested review from a team and sharadsw February 13, 2025 21:08
@CarolineDenis CarolineDenis removed the request for review from a team February 13, 2025 21:20
@acwhite211 acwhite211 requested a review from a team February 24, 2025 15:38
@CarolineDenis CarolineDenis requested a review from a team February 24, 2025 17:08
@CarolineDenis CarolineDenis marked this pull request as ready for review February 24, 2025 17:08
@pashiav
Copy link
Contributor

pashiav commented Feb 25, 2025

@specify/ux-testing note:

@acwhite211 is going to make a new DB that we can test on for this PR. There are DB issues with the current ones on the test panel.

@acwhite211
Copy link
Member Author

Hold off on testing temporarily. This PR will be effected by the solution to #6271. I'll also create a new database to make testing this PR better.

@combs-a
Copy link
Collaborator

combs-a commented Feb 28, 2025

Though this PR isn't ready for testing review yet, ran into this issue and was asked to note it in Github. If you have Age in the query set to Any, the results will still display Collection Object ID.

Query: AgeTest.json

Query results:
image

Query results (Same query except changing Age to Range -> 2000 - 2):

image

@CarolineDenis CarolineDenis modified the milestones: 7.10.2, 7.10 Feb 28, 2025
@acwhite211
Copy link
Member Author

Hey @specify/ux-testing, we can go ahead and start retesting this PR for 7.10.

I put a database up on the test panel named age_geo_test. Use that for testing.

We might need to push the issue of the age range not showing up when using an "Any" age query. I'm looking into a fix, but it might not be done in time for 7.10, so ignore issue that for now.

@grantfitzsimmons checkout if the strict age filter logic is working how you envision, let me know of any CO record examples that are wrong in the query results and I should be able to do a quick fix. Thanks!

@emenslin
Copy link
Collaborator

Some results are still showing up when they aren't supposed to, I didn't get a lot of time to test though so this could be me misunderstanding how strict is supposed to work.
image

Copy link
Contributor

@CarolineDenis CarolineDenis left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Tested the functionality on a geo DB, the results returned are not correct.

@github-project-automation github-project-automation bot moved this from 📋Back Log to Dev Attention Needed in General Tester Board Mar 3, 2025
@acwhite211
Copy link
Member Author

acwhite211 commented Mar 3, 2025

Just to clarify the new intended behavior for the age query.

Given:

  • an age query start period x
  • an age query end period y
  • with constraint that x >= y
  • for each collection object, a meta start period a is decided, and a meta end period b is decided.
  • with constraint that a >= b

Strict Filter: (full overlap, a-b is within x-y)
a <= x and b >= y

Non-Strict Filter: (partial age range overlap, any overlap so x-y can be within a-b or a-b can be within x-y)
( a<= x and a >= y) or (b <= x and b >= y) or (a >= x and b <= y)

This is omitting the complication of uncertainty values.

The meta age range for each collection object should appear in the age column of the query results.

@CarolineDenis
Copy link
Contributor

@acwhite211 , seems correct to me

@acwhite211
Copy link
Member Author

@specify/ux-testing try retesting this PR. Start of by using the age_geo_test database, and use the guidance of this comment for determining which results should appear. #6206 (comment)

The "Any" age query bug is being push to a later issue. For now, do a Age Range query from "13800" to "0" to get all COs with age data (query all of time, the age of the universe :).

Just to clarify the new intended behavior for the age query.

Given:

* an age query start period `x`

* an age query end period `y`

* with constraint that `x >= y`

* for each collection object, a meta start period `a` is decided, and a meta end period `b` is decided.

* with constraint that `a >= b`

Strict Filter: (full overlap, a-b is within x-y) a <= x and b >= y

Non-Strict Filter: (partial age range overlap, any overlap so x-y can be within a-b or a-b can be within x-y) ( a<= x and a >= y) or (b <= x and b >= y) or (a >= x and b <= y)

This is omitting the complication of uncertainty values.

The meta age range for each collection object should appear in the age column of the query results.

Copy link
Member

@grantfitzsimmons grantfitzsimmons left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Fixes #6016

One note here is that you still see the CO ID whenever there is no computed range, which would ideally not show anything. Can this be adjusted?

  • See that the "Collection Object - Age" column has a date range.

🎉
image

Fixes #6271

Wonderful.

Tested with this query, and all searching worked as I would expect!
Extended Age Query.json

@grantfitzsimmons grantfitzsimmons requested a review from a team March 3, 2025 22:31
@acwhite211 acwhite211 requested a review from CarolineDenis March 3, 2025 22:55
Copy link
Collaborator

@emenslin emenslin left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

  • See that the "Collection Object - Age" column has a date range.

Looks good, previous issues seem to be fixed!

@acwhite211 acwhite211 merged commit 5818e6c into production Mar 4, 2025
12 checks passed
@acwhite211 acwhite211 deleted the issue-6089 branch March 4, 2025 15:05
@github-project-automation github-project-automation bot moved this from Dev Attention Needed to ✅Done in General Tester Board Mar 4, 2025
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

2 - Queries Issues that are related to the query builder or queries in general geospecify

Projects

Status: Done

8 participants