diff --git a/docs/GetSearchParamsFromCapabilityStatement.md b/docs/GetSearchParamsFromCapabilityStatement.md new file mode 100644 index 0000000000..bb78bff2b8 --- /dev/null +++ b/docs/GetSearchParamsFromCapabilityStatement.md @@ -0,0 +1,143 @@ +# GetSearchParamsFromCapabilityStatement SQL Function + +## Overview + +The `GetSearchParamsFromCapabilityStatement` function is a SQL Server table-valued function that extracts search parameter information from a FHIR Capability Statement JSON document. + +## Function Signature + +```sql +CREATE OR ALTER FUNCTION dbo.GetSearchParamsFromCapabilityStatement +( + @capabilityStatementJson NVARCHAR(MAX) +) +RETURNS TABLE +``` + +## Parameters + +- **@capabilityStatementJson** (NVARCHAR(MAX)): A FHIR Capability Statement in JSON format + +## Returns + +A table with the following columns: + +| Column Name | Data Type | Description | +|------------|-----------|-------------| +| ResourceType | NVARCHAR(128) | The FHIR resource type (e.g., 'Patient', 'Observation') | +| SearchParamUrl | NVARCHAR(512) | The canonical URL of the search parameter | +| SearchParamType | NVARCHAR(64) | The type of the search parameter (e.g., 'string', 'token', 'reference') | + +## Usage Examples + +### Example 1: Basic Usage + +```sql +DECLARE @capabilityStatement NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [ + { + "mode": "server", + "resource": [ + { + "type": "Patient", + "searchParam": [ + { + "name": "identifier", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-identifier", + "type": "token" + }, + { + "name": "name", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-name", + "type": "string" + } + ] + } + ] + } + ] +}'; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement); +``` + +**Output:** + +| ResourceType | SearchParamUrl | SearchParamType | +|-------------|----------------|-----------------| +| Patient | http://hl7.org/fhir/SearchParameter/Patient-identifier | token | +| Patient | http://hl7.org/fhir/SearchParameter/Patient-name | string | + +### Example 2: Filtering Results + +```sql +-- Get only token-type search parameters +SELECT * +FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement) +WHERE SearchParamType = 'token'; + +-- Get search parameters for a specific resource type +SELECT * +FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement) +WHERE ResourceType = 'Patient'; +``` + +### Example 3: Joining with Other Tables + +```sql +-- Join with SearchParam table to find matching search parameter IDs +SELECT + sp.SearchParamId, + caps.ResourceType, + caps.SearchParamUrl, + caps.SearchParamType +FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement) caps +INNER JOIN dbo.SearchParam sp ON sp.Uri = caps.SearchParamUrl; +``` + +### Example 4: Reading from Resource Table + +If the Capability Statement is stored in the Resource table: + +```sql +-- Extract search parameters from a stored CapabilityStatement resource +DECLARE @capabilityJson NVARCHAR(MAX); + +SELECT @capabilityJson = CONVERT(NVARCHAR(MAX), RawResource) +FROM dbo.Resource r +INNER JOIN dbo.ResourceType rt ON r.ResourceTypeId = rt.ResourceTypeId +WHERE rt.Name = 'CapabilityStatement' + AND r.IsHistory = 0 + AND r.IsDeleted = 0; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityJson); +``` + +## Implementation Details + +The function uses SQL Server's `OPENJSON` to parse the nested JSON structure: + +1. Parses the `rest` array from the Capability Statement +2. For each rest entry, parses the `resource` array +3. For each resource, extracts the resource type and parses the `searchParam` array +4. For each search parameter, extracts the definition (URL) and type +5. Filters out any rows where ResourceType, SearchParamUrl, or SearchParamType is NULL + +## Notes + +- The function requires SQL Server 2016 or later (for OPENJSON support) +- The function handles multiple `rest` entries in the Capability Statement +- The function handles multiple resources per rest entry +- The function handles multiple search parameters per resource +- NULL values in any of the required fields (type, definition, or type) are filtered out + +## Schema Version + +This function was introduced in schema version 100. + +## See Also + +- [FHIR Capability Statement Specification](http://hl7.org/fhir/capabilitystatement.html) +- [FHIR Search Parameters](http://hl7.org/fhir/searchparameter.html) +- [SQL Server OPENJSON](https://docs.microsoft.com/en-us/sql/t-sql/functions/openjson-transact-sql) diff --git a/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Schema/GetSearchParamsFromCapabilityStatementTests.cs b/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Schema/GetSearchParamsFromCapabilityStatementTests.cs new file mode 100644 index 0000000000..513e066be7 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Schema/GetSearchParamsFromCapabilityStatementTests.cs @@ -0,0 +1,116 @@ +// ------------------------------------------------------------------------------------------------- +// Copyright (c) Microsoft Corporation. All rights reserved. +// Licensed under the MIT License (MIT). See LICENSE in the repo root for license information. +// ------------------------------------------------------------------------------------------------- + +using Microsoft.Health.Fhir.Tests.Common; +using Microsoft.Health.Test.Utilities; +using Xunit; + +namespace Microsoft.Health.Fhir.SqlServer.UnitTests.Features.Schema +{ + [Trait(Traits.OwningTeam, OwningTeam.Fhir)] + [Trait(Traits.Category, Categories.Schema)] + public class GetSearchParamsFromCapabilityStatementTests + { + /// + /// Integration test for the GetSearchParamsFromCapabilityStatement function. + /// This test requires a SQL Server connection and should be run as an integration test. + /// + /// To test manually: + /// 1. Deploy the database with schema version 100 + /// 2. Run the following SQL: + /// + /// DECLARE @json NVARCHAR(MAX) = N'{ + /// "resourceType": "CapabilityStatement", + /// "rest": [ + /// { + /// "mode": "server", + /// "resource": [ + /// { + /// "type": "Patient", + /// "searchParam": [ + /// { + /// "name": "identifier", + /// "definition": "http://hl7.org/fhir/SearchParameter/Patient-identifier", + /// "type": "token" + /// }, + /// { + /// "name": "name", + /// "definition": "http://hl7.org/fhir/SearchParameter/Patient-name", + /// "type": "string" + /// } + /// ] + /// }, + /// { + /// "type": "Observation", + /// "searchParam": [ + /// { + /// "name": "code", + /// "definition": "http://hl7.org/fhir/SearchParameter/Observation-code", + /// "type": "token" + /// } + /// ] + /// } + /// ] + /// } + /// ] + /// }'; + /// + /// SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@json); + /// + /// Expected output: + /// ResourceType | SearchParamUrl | SearchParamType + /// -------------|----------------------------------------------------------------|---------------- + /// Patient | http://hl7.org/fhir/SearchParameter/Patient-identifier | token + /// Patient | http://hl7.org/fhir/SearchParameter/Patient-name | string + /// Observation | http://hl7.org/fhir/SearchParameter/Observation-code | token + /// + [Fact(Skip = "This is a documentation test. Run the SQL manually against a SQL Server instance.")] + public void GetSearchParamsFromCapabilityStatement_WithValidJson_ReturnsExpectedResults() + { + // This test is for documentation purposes. + // The actual testing should be done via integration tests with a real SQL Server instance. + Assert.True(true); + } + + [Fact(Skip = "This is a documentation test. Run the SQL manually against a SQL Server instance.")] + public void GetSearchParamsFromCapabilityStatement_WithEmptyRest_ReturnsEmptyTable() + { + // Test SQL: + // DECLARE @json NVARCHAR(MAX) = N'{"resourceType": "CapabilityStatement", "rest": []}'; + // SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@json); + // Expected: 0 rows + Assert.True(true); + } + + [Fact(Skip = "This is a documentation test. Run the SQL manually against a SQL Server instance.")] + public void GetSearchParamsFromCapabilityStatement_WithNoSearchParams_ReturnsEmptyTable() + { + // Test SQL: + // DECLARE @json NVARCHAR(MAX) = N'{ + // "resourceType": "CapabilityStatement", + // "rest": [{"mode": "server", "resource": [{"type": "Patient", "searchParam": []}]}] + // }'; + // SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@json); + // Expected: 0 rows + Assert.True(true); + } + + [Fact(Skip = "This is a documentation test. Run the SQL manually against a SQL Server instance.")] + public void GetSearchParamsFromCapabilityStatement_WithMultipleRestEntries_ReturnsAllSearchParams() + { + // Test SQL with multiple rest entries: + // DECLARE @json NVARCHAR(MAX) = N'{ + // "resourceType": "CapabilityStatement", + // "rest": [ + // {"mode": "server", "resource": [{"type": "Patient", "searchParam": [{"definition": "http://example.com/1", "type": "string"}]}]}, + // {"mode": "client", "resource": [{"type": "Observation", "searchParam": [{"definition": "http://example.com/2", "type": "token"}]}]} + // ] + // }'; + // SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@json); + // Expected: 2 rows (one for Patient, one for Observation) + Assert.True(true); + } + } +} diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/100.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/100.diff.sql new file mode 100644 index 0000000000..9e03d2e99a --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/100.diff.sql @@ -0,0 +1,51 @@ +/************************************************************* + Function: GetSearchParamsFromCapabilityStatement + + Description: + Extracts search parameter information (resource type, URL, and type) + from a FHIR Capability Statement JSON document. + + Parameters: + @capabilityStatementJson - NVARCHAR(MAX): The FHIR Capability Statement in JSON format + + Returns: + Table with the following columns: + - ResourceType: The FHIR resource type (e.g., 'Patient', 'Observation') + - SearchParamUrl: The canonical URL of the search parameter + - SearchParamType: The type of the search parameter (e.g., 'string', 'token', 'reference') + + Usage Example: + SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement( + '{"resourceType":"CapabilityStatement","rest":[{"mode":"server","resource":[{"type":"Patient","searchParam":[{"name":"identifier","definition":"http://hl7.org/fhir/SearchParameter/Patient-identifier","type":"token"}]}]}]}' + ) +**************************************************************/ + +CREATE OR ALTER FUNCTION dbo.GetSearchParamsFromCapabilityStatement +( + @capabilityStatementJson NVARCHAR(MAX) +) +RETURNS TABLE +AS +RETURN +( + SELECT + resource.ResourceType, + searchParam.SearchParamUrl, + searchParam.SearchParamType + FROM OPENJSON(@capabilityStatementJson, '$.rest') AS rest + CROSS APPLY OPENJSON(rest.value, '$.resource') + WITH ( + ResourceType NVARCHAR(128) '$.type', + SearchParams NVARCHAR(MAX) '$.searchParam' AS JSON + ) AS resource + CROSS APPLY OPENJSON(resource.SearchParams) + WITH ( + SearchParamUrl NVARCHAR(512) '$.definition', + SearchParamType NVARCHAR(64) '$.type' + ) AS searchParam + WHERE + resource.ResourceType IS NOT NULL + AND searchParam.SearchParamUrl IS NOT NULL + AND searchParam.SearchParamType IS NOT NULL +) +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs index 423d486d77..81cc3a361c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs @@ -109,5 +109,6 @@ public enum SchemaVersion V97 = 97, V98 = 98, V99 = 99, + V100 = 100, } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index be239afbf6..19e5031646 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -8,7 +8,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema public static class SchemaVersionConstants { public const int Min = (int)SchemaVersion.V94; - public const int Max = (int)SchemaVersion.V99; + public const int Max = (int)SchemaVersion.V100; public const int MinForUpgrade = (int)SchemaVersion.V94; // this is used for upgrade tests only public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6; public const int SupportForReferencesWithMissingTypeVersion = (int)SchemaVersion.V7; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TestGetSearchParamsFromCapabilityStatement.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TestGetSearchParamsFromCapabilityStatement.sql new file mode 100644 index 0000000000..5a86fd6830 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TestGetSearchParamsFromCapabilityStatement.sql @@ -0,0 +1,234 @@ +-- Manual Test Script for GetSearchParamsFromCapabilityStatement Function +-- Run this script against a SQL Server database with schema version 100 or later + +-- Test 1: Basic functionality with Patient and Observation resources +PRINT 'Test 1: Basic functionality with Patient and Observation resources' +DECLARE @capabilityStatement1 NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [ + { + "mode": "server", + "resource": [ + { + "type": "Patient", + "searchParam": [ + { + "name": "identifier", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-identifier", + "type": "token" + }, + { + "name": "name", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-name", + "type": "string" + }, + { + "name": "birthdate", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-birthdate", + "type": "date" + } + ] + }, + { + "type": "Observation", + "searchParam": [ + { + "name": "code", + "definition": "http://hl7.org/fhir/SearchParameter/Observation-code", + "type": "token" + }, + { + "name": "patient", + "definition": "http://hl7.org/fhir/SearchParameter/Observation-patient", + "type": "reference" + } + ] + } + ] + } + ] +}'; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement1); +-- Expected: 5 rows (3 for Patient, 2 for Observation) +GO + +-- Test 2: Empty rest array +PRINT 'Test 2: Empty rest array' +DECLARE @capabilityStatement2 NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [] +}'; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement2); +-- Expected: 0 rows +GO + +-- Test 3: Resource with no search parameters +PRINT 'Test 3: Resource with no search parameters' +DECLARE @capabilityStatement3 NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [ + { + "mode": "server", + "resource": [ + { + "type": "Patient", + "searchParam": [] + } + ] + } + ] +}'; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement3); +-- Expected: 0 rows +GO + +-- Test 4: Multiple rest entries (server and client) +PRINT 'Test 4: Multiple rest entries (server and client)' +DECLARE @capabilityStatement4 NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [ + { + "mode": "server", + "resource": [ + { + "type": "Patient", + "searchParam": [ + { + "name": "identifier", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-identifier", + "type": "token" + } + ] + } + ] + }, + { + "mode": "client", + "resource": [ + { + "type": "Observation", + "searchParam": [ + { + "name": "code", + "definition": "http://hl7.org/fhir/SearchParameter/Observation-code", + "type": "token" + } + ] + } + ] + } + ] +}'; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement4); +-- Expected: 2 rows (1 for Patient from server mode, 1 for Observation from client mode) +GO + +-- Test 5: Filter by resource type +PRINT 'Test 5: Filter by resource type' +DECLARE @capabilityStatement5 NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [ + { + "mode": "server", + "resource": [ + { + "type": "Patient", + "searchParam": [ + { + "name": "identifier", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-identifier", + "type": "token" + }, + { + "name": "name", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-name", + "type": "string" + } + ] + }, + { + "type": "Observation", + "searchParam": [ + { + "name": "code", + "definition": "http://hl7.org/fhir/SearchParameter/Observation-code", + "type": "token" + } + ] + } + ] + } + ] +}'; + +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement5) +WHERE ResourceType = 'Patient'; +-- Expected: 2 rows (only Patient search parameters) +GO + +-- Test 6: Filter by search parameter type +PRINT 'Test 6: Filter by search parameter type' +SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement5) +WHERE SearchParamType = 'token'; +-- Expected: 2 rows (Patient-identifier and Observation-code) +GO + +-- Test 7: Count search parameters by resource type +PRINT 'Test 7: Count search parameters by resource type' +SELECT + ResourceType, + COUNT(*) as SearchParamCount +FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement5) +GROUP BY ResourceType; +-- Expected: Patient: 2, Observation: 1 +GO + +-- Test 8: Get distinct search parameter types +PRINT 'Test 8: Get distinct search parameter types' +DECLARE @capabilityStatement8 NVARCHAR(MAX) = N'{ + "resourceType": "CapabilityStatement", + "rest": [ + { + "mode": "server", + "resource": [ + { + "type": "Patient", + "searchParam": [ + { + "name": "identifier", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-identifier", + "type": "token" + }, + { + "name": "name", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-name", + "type": "string" + }, + { + "name": "birthdate", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-birthdate", + "type": "date" + }, + { + "name": "general-practitioner", + "definition": "http://hl7.org/fhir/SearchParameter/Patient-general-practitioner", + "type": "reference" + } + ] + } + ] + } + ] +}'; + +SELECT DISTINCT SearchParamType +FROM dbo.GetSearchParamsFromCapabilityStatement(@capabilityStatement8) +ORDER BY SearchParamType; +-- Expected: date, reference, string, token (in alphabetical order) +GO + +PRINT 'All tests completed!' diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetSearchParamsFromCapabilityStatement.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetSearchParamsFromCapabilityStatement.sql new file mode 100644 index 0000000000..9e03d2e99a --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetSearchParamsFromCapabilityStatement.sql @@ -0,0 +1,51 @@ +/************************************************************* + Function: GetSearchParamsFromCapabilityStatement + + Description: + Extracts search parameter information (resource type, URL, and type) + from a FHIR Capability Statement JSON document. + + Parameters: + @capabilityStatementJson - NVARCHAR(MAX): The FHIR Capability Statement in JSON format + + Returns: + Table with the following columns: + - ResourceType: The FHIR resource type (e.g., 'Patient', 'Observation') + - SearchParamUrl: The canonical URL of the search parameter + - SearchParamType: The type of the search parameter (e.g., 'string', 'token', 'reference') + + Usage Example: + SELECT * FROM dbo.GetSearchParamsFromCapabilityStatement( + '{"resourceType":"CapabilityStatement","rest":[{"mode":"server","resource":[{"type":"Patient","searchParam":[{"name":"identifier","definition":"http://hl7.org/fhir/SearchParameter/Patient-identifier","type":"token"}]}]}]}' + ) +**************************************************************/ + +CREATE OR ALTER FUNCTION dbo.GetSearchParamsFromCapabilityStatement +( + @capabilityStatementJson NVARCHAR(MAX) +) +RETURNS TABLE +AS +RETURN +( + SELECT + resource.ResourceType, + searchParam.SearchParamUrl, + searchParam.SearchParamType + FROM OPENJSON(@capabilityStatementJson, '$.rest') AS rest + CROSS APPLY OPENJSON(rest.value, '$.resource') + WITH ( + ResourceType NVARCHAR(128) '$.type', + SearchParams NVARCHAR(MAX) '$.searchParam' AS JSON + ) AS resource + CROSS APPLY OPENJSON(resource.SearchParams) + WITH ( + SearchParamUrl NVARCHAR(512) '$.definition', + SearchParamType NVARCHAR(64) '$.type' + ) AS searchParam + WHERE + resource.ResourceType IS NOT NULL + AND searchParam.SearchParamUrl IS NOT NULL + AND searchParam.SearchParamType IS NOT NULL +) +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj index d180b21015..7c7bef5db2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj +++ b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj @@ -1,7 +1,7 @@  - 99 + 100 Features\Schema\Migrations\$(LatestSchemaVersion).sql