How to create a dependent dropdown list for whole column in Excel using XlsIO?
This article explains about creating a dependent dropdown list for the whole column in Excel using XlsIO.
What is data validation?
Data validation is a feature of Excel that helps control the kind of information that is entered into a worksheet.
List-type data validation allows creating a drop-down list with the actual data that has to be selected in the preferred cell. Users can quickly select an item from the list and then move on to the next entry without typing unwanted data.
The INDIRECT function is used for creating a data validation list that depends on the value from another cell.
How does the INDIRECT function work?
The INDIRECT function returns the reference specified by a text string. References are immediately evaluated to display their contents. INDIRECT is used when the reference to a cell within a formula needs to be changed without changing the formula itself.
Code snippet for creating a dependent dropdown list for the whole column in Excel using XlsIO
// Adding data validation to column A IDataValidation validation1 = worksheet.Range["A1:A5000"].DataValidation; validation1.AllowType = ExcelDataType.User; validation1.FirstFormula = "=Name"; // Adding data validation to column B IDataValidation validation2 = worksheet.Range["B1:B5000"].DataValidation; validation2.AllowType = ExcelDataType.User; validation2.FirstFormula = "=INDIRECT($A1)";
The following C#/VB complete code snippet shows the creation of dependent data validation for an entire column in Excel using XlsIO.
C#
using Syncfusion.XlsIO; using System.IO; namespace Dependent_Dropdown { class Program { static void Main(string[] args) { using (ExcelEngine excelEngine = new ExcelEngine()) { // Instantiate the Excel application object IApplication application = excelEngine.Excel; // Workbook is created IWorkbook workbook = application.Workbooks.Create(1); // The first worksheet object in the worksheets collection is accessed. IWorksheet worksheet = workbook.Worksheets[0]; // Defining names for ranges of cells IName name1 = workbook.Names.Add("Name"); name1.RefersToRange = worksheet["E1:E3"]; IName name2 = workbook.Names.Add("X"); name2.RefersToRange = worksheet["F1:F2"]; IName name3 = workbook.Names.Add("Y"); name3.RefersToRange = worksheet["G1:G2"]; IName name4 = workbook.Names.Add("Z"); name4.RefersToRange = worksheet["H1:H2"]; worksheet.Range["E1"].Value = "X"; worksheet.Range["E2"].Value = "Y"; worksheet.Range["E3"].Value = "Z"; worksheet.Range["F1"].Value = "xx1"; worksheet.Range["F2"].Value = "xx2"; worksheet.Range["G1"].Value = "yy1"; worksheet.Range["G2"].Value = "yy2"; worksheet.Range["H1"].Value = "zz1"; worksheet.Range["H2"].Value = "zz2"; // Adding data validation to column A IDataValidation validation1 = worksheet.Range["A1:A5000"].DataValidation; validation1.AllowType = ExcelDataType.User; validation1.FirstFormula = "=Name"; // Adding data validation to column B IDataValidation validation2 = worksheet.Range["B1:B5000"].DataValidation; validation2.AllowType = ExcelDataType.User; validation2.FirstFormula = "=INDIRECT($A1)"; // Saving and closing the workbook Stream stream = File.Create("Output.xlsx"); workbook.SaveAs(stream); } } } }
VB
Imports Syncfusion.XlsIO Imports System.IO Namespace Dependent_Dropdown Class Program Private Shared Sub Main(ByVal args() As String) Dim excelEngine As ExcelEngine = New ExcelEngine 'Instantiate the Excel application object Dim application As IApplication = excelEngine.Excel 'Workbook is created Dim workbook As IWorkbook = application.Workbooks.Create(1) 'The first worksheet object in the worksheets collection is accessed. Dim worksheet As IWorksheet = workbook.Worksheets(0) 'Defining names for ranges of cells Dim name1 As IName = workbook.Names.Add("Name") name1.RefersToRange = worksheet("E1:E3") Dim name2 As IName = workbook.Names.Add("X") name2.RefersToRange = worksheet("F1:F2") Dim name3 As IName = workbook.Names.Add("Y") name3.RefersToRange = worksheet("G1:G2") Dim name4 As IName = workbook.Names.Add("Z") name4.RefersToRange = worksheet("H1:H2") worksheet.Range("E1").Value = "X" worksheet.Range("E2").Value = "Y" worksheet.Range("E3").Value = "Z" worksheet.Range("F1").Value = "xx1" worksheet.Range("F2").Value = "xx2" worksheet.Range("G1").Value = "yy1" worksheet.Range("G2").Value = "yy2" worksheet.Range("H1").Value = "zz1" worksheet.Range("H2").Value = "zz2" 'Adding data validation to column A Dim validation1 As IDataValidation = worksheet.Range("A1:A5000").DataValidation validation1.AllowType = ExcelDataType.User validation1.FirstFormula = "=Name" 'Adding data validation to column B Dim validation2 As IDataValidation = worksheet.Range("B1:B5000").DataValidation validation2.AllowType = ExcelDataType.User validation2.FirstFormula = "=INDIRECT($A1)" 'Saving and closing the workbook Dim stream As Stream = File.Create("Output.xlsx") workbook.SaveAs(stream) End Sub End Class End Namespace
Take a moment to peruse the documentation where you can find basic Excel document processing options along with the features like import and export data, chart, formulas, conditional formatting, data validation, tables, pivot tables and, protect the Excel documents, and most importantly, the PDF, CSV and Image conversions with code examples.
Conclusion
I hope you enjoyed learning about How to create a dependent dropdown list for whole column in Excel using XlsIO.
You can refer to our XIsIO’s feature tour page to learn about its other groundbreaking features. Explore our UG documentation and online demos to understand how to manipulate data in Excel documents.
If you are an existing user, you can access our latest components from the License and Downloads page. For new users, you can try our 30-day free trial to check out XlsIO and other Syncfusion® components.
If you have any queries or require clarification, please let us know in the comments below or contact us through our support forums, Support Tickets, or feedback portal. We are always happy to assist you!