Skip to content
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
143 changes: 143 additions & 0 deletions docs/GetSearchParamsFromCapabilityStatement.md
Original file line number Diff line number Diff line change
@@ -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)
Original file line number Diff line number Diff line change
@@ -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
{
/// <summary>
/// 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
/// </summary>
[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);
}
}
}
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
Expand Up @@ -109,5 +109,6 @@ public enum SchemaVersion
V97 = 97,
V98 = 98,
V99 = 99,
V100 = 100,
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -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;
Expand Down
Loading