Displays a hierarchical list of possible values in a tree structure to the left and an ordered list of selected values to the right. The user can select nodes from the tree on the left and move them to the list on the right. It is also possible to reorder the list of selected items using arrows on the right.
This is an advanced control that may be difficult to understand for inexperienced users.
A Multi-picker can contain a hierarchial list. The left pane shows the available items. When an item is picked it disappears from the left and shows up in the right pane.
Here the user has selected "Nordic countries", and then expanded "Benelux" (clicked the plus-sign) to select "Belgium".
To pick the selected items, you click the right-arrow in the middle. Note that the item "Nordic countries" is a parent node. That means it's presence in the right pane implies that all it's child nodes are also considered as picked by the user.
Sometimes the order of the picked items matter. In this example the user has clicked "Belgium" and then the up-arrow to put it on top of the list.
SQL-statement that fills the tree with possible values to select.
Label for selected nodes.
SQL-statement executed when control makes server-side roundtrip for adding childs to a node when expanding it.
Label for selected nodes.
SQL-statement executed when control asks database for the values that are preselected.
Retrieves the default value for the control.
This call is only made if there is a field validation set for the field info and the field has any content. Fields used in an editable grid do not use this call.
Performs field validation when the user leaves the field or one of its dependencies is changed, initial values set by default value and initial values in edit-mode are not validated.
When saving the validation runs server side if the field value has changed. A field value is considered changed if in new mode the value is anything other than NULL
. In edit mode it is considered changed if it has a value that was not returned by the GetEditFields procedure.
Example procedure for a multipicker. In the example selected nodes are shown with their path.
SET ANSI_NULLS ON
SET QUOTED_IDENTIFIER ON
GO
ALTER PROCEDURE ContactLabel.MyMultiPicker
@Id varchar(max) = null,
@ServersideExpand int = NULL,
@Values bit = 0
AS
BEGIN
-----------------------------------
-- Fetch already selected values --
-----------------------------------
IF @Values = 1
BEGIN
;WITH
LabelFullPath AS
(
SELECT
L.LabelId,
L.LabelIdParent,
L.LabelName,
CONVERT(varchar(max), NULL) AS [LabelNameFullPath]
FROM
ContactLabel.Label L
WHERE
L.LabelIdParent IS NULL
UNION ALL
SELECT
L.LabelId,
L.LabelIdParent,
L.LabelName,
CONVERT(varchar(max), COALESCE(LFP.LabelNameFullPath + ' - ', '') + LFP.LabelName) AS [LabelNameFullPath]
FROM
LabelFullPath LFP
JOIN ContactLabel.Label L ON
L.LabelIdParent = LFP.LabelId
)
SELECT
LFP.LabelId AS [Id],
LFP.LabelName AS [Label],
LFP.LabelIdParent AS [Parent],
LFP.LabelName + COALESCE(' (' + LFP.LabelNameFullPath + ')', NULL) AS [SelectedLabel]
FROM
SoftadminUtil.Number_ParseList(@Id) X
JOIN LabelFullPath LFP ON
LFP.LabelId = X.i
RETURN
END
------------------------------------------
-- Fetch nodes for the multipicker tree --
------------------------------------------
;WITH
LabelFullPath AS
(
SELECT
L.LabelId,
L.LabelIdParent,
L.LabelName,
CONVERT(varchar(max), NULL) AS [LabelNameFullPath]
FROM
ContactLabel.Label L
WHERE
L.LabelIdParent IS NULL
UNION ALL
SELECT
L.LabelId,
L.LabelIdParent,
L.LabelName,
CONVERT(varchar(max), COALESCE(LFP.LabelNameFullPath + ' - ', '') + LFP.LabelName) AS [LabelNameFullPath]
FROM
LabelFullPath LFP
JOIN ContactLabel.Label L ON
L.LabelIdParent = LFP.LabelId
)
SELECT
LFP.LabelId AS [Id],
LFP.LabelName AS [Label],
LFP.LabelIdParent AS [Parent],
LFP.LabelName + COALESCE(' (' + LFP.LabelNameFullPath + ')', NULL) AS [SelectedLabel],
CONVERT(bit, 1) AS [Selectable],
NodeInfo.HasChildren AS [ServerSideExpand]
FROM
LabelFullPath LFP
CROSS APPLY
(
SELECT
CONVERT(
bit,
CASE
WHEN EXISTS
(
SELECT
*
FROM
ContactLabel.Label L1
WHERE
L1.LabelIdParent = LFP.LabelId
)
THEN
1
ELSE
0
END
) AS [HasChildren]
) NodeInfo
WHERE
-- When @ServersideExpand is NULL we only want nodes that have no parent
LFP.LabelIdParent = @ServersideExpand OR
(
@ServersideExpand IS NULL AND
LFP.LabelIdParent IS NULL
)
ORDER BY
LFP.LabelName
END
For stable and predictable behaviour, always use an explicit ORDER BY clause.