jqgrid + EF + MVC: How to export in excel? Which method you suggest?
Asked Answered
M

2

4

I am using jqgrid (standard) with EF 4 + MVC3. I'd like to implement excel export. Which method you would suggest me?

To generate excel, I'd like to use this library by Dr Stephen Walther, which has three types of output and allows to define headers too. Please tell me if you find it valid for my purpose.

I ask this question because I am still approaching to implement excel export and I found several techniques. Some suggest making a csv export, others indicate that it should return a JSON output and it is not clear to me whether this capability is present in the free version of jqgrid. In any case, I would like to pass the data to Walther's object.

About the jqgrid code, I found this interesting answer by Oleg, but I do not understand if could be applied to my needs.

Unfortunately, by now I only found parts of solutions for excel export with EF MVC, but no solution or complete examples...

About the MVC logic, I am going to implement and develop this code as kindly suggested by @Tommy.

Please sorry if the question could be silly, I am just a (enthusiast) beginner.

Thanks for your precious help! Best Regards

Musetta answered 18/2, 2012 at 8:30 Comment(0)
S
11

As I wrote before (see here and here for example) the best way to export grid data to XML is the usage of Open XML SDK 2.0.

The post of Dr Stephen Walther shows how to create HTML file which can be read by Excel. It's not Excel file and have to be still converted to Excel format. The usage of CSV has even more problems. Depend on the content in the source table the automatic conversion to Excel data types can be absolutely wrong. In one project which I developed for a customer the grid contained information about software products: product name, version, and so on. The software version looks sometime as the date (1.3.1963 for example) and such cells will be wrong converted (in German one use '.' as the separator in the date). As the result one had really hard problems. The usage of CSV with texts having commas inside will be also frequently wrong imported. Even when one quotes the cells having commas (,) and escaped the texts having quotas the import still be wrong especially in the first column. I don't want to explain here the whole history of all attempts and errors, but after all I decide to give up with the usage of CSV and HTML and started to use Open XML SDK 2.0 which allows to create real Excel files with extension XLSX. The way seems me perfect because one don't need any Office components installed on the server, no additional licenses.

The only restriction is that one should be able to use DocumentFormat.OpenXml.dll, so your server program should run on any Windows operation system. As it's well known, XLSX file is ZIP file which contains some XML files inside. If you still don't know that I recommend you to rename the XLSX file to ZIP file and extract it. The Open XML SDK 2.0 is the library which works with XLSX file like with XML files. So no additional Office components are required.

One can find a lot of information how to use Open XML SDK 2.0 (see here, here and here). Many helpful code examples one cam find directly on the MSDN (see here). Nevertheless the practical usage of Open XML SDK 2.0 is not so easy at least at the first time. So I created a demo from the parts of the code which I used myself.

You can download the demo project from here. The demo is an extension of the demos from the answer and this one.

To export data I use the DataForExcel helper class. It has constructor in the form

DataForExcel(string[] headers, DataType[] colunmTypes, List<string[]> data,
             string sheetName)

or in a little simplified form

DataForExcel(string[] headers, List<string[]> data, string sheetName)

and the only public method

CreateXlsxAndFillData(Stream stream)

The usage of the class to create Excel file can be like the following

var excelData = new DataForExcel (
    // column Header
    new[]{"Col1", "Col2", "Col3"},
    new[]{DataForExcel.DataType.String, DataForExcel.DataType.Integer,
          DataForExcel.DataType.String},
    new List<string[]> {
        new[] {"a", "1", "c1"},
        new[] {"a", "2", "c2"}
    },
    "Test Grid");
Stream stream = new FileStream ("Test.xlsx", FileMode.Create);
excelData.CreateXlsxAndFillData (stream);
stream.Close();

The usage in the demo from ASP.NET MVC is the following

static readonly string[] HeadersQuestions = {
    "Id", "Votes", "Title"
};
static readonly DataForExcel.DataType[] ColunmTypesQuestions = {
    DataForExcel.DataType.Integer,
    DataForExcel.DataType.Integer,
    DataForExcel.DataType.String
};

public ActionResult ExportAllQuestionsToExcel () {
    var context = new HaackOverflowEntities ();
    var questions = context.Questions;
    questions.MergeOption = MergeOption.NoTracking; // we don't want to update the data

    // to be able to use ToString() below which is NOT exist in the LINQ to Entity
    // we should include in query only the properies which we will use below
    var query = questions.ToList ();
    if (query.Count == 0)
        return new EmptyResult ();
    var data = new List<string[]> (query.Count);
    data.AddRange (query.Select (item => new[] {
        item.Id.ToString(CultureInfo.InvariantCulture),
        item.Votes.ToString(CultureInfo.InvariantCulture),
        item.Title
    }));

    return new ExcelResult (HeadersQuestions, ColunmTypesQuestions, data,
                            "Questions.xlsx", "Questions");
}

where ExcelResult are defined as

public class ExcelResult : ActionResult {
    private readonly DataForExcel _data;
    private readonly string _fileName;

    public ExcelResult (string[] headers, List<string[]> data, string fileName, string sheetName) {
        _data = new DataForExcel (headers, data, sheetName);
        _fileName = fileName;
    }

    public ExcelResult (string[] headers, DataForExcel.DataType[] colunmTypes, List<string[]> data, string fileName, string sheetName) {
        _data = new DataForExcel (headers, colunmTypes, data, sheetName);
        _fileName = fileName;
    }

    public override void ExecuteResult (ControllerContext context) {
        var response = context.HttpContext.Response;
        response.ClearContent();
        response.ClearHeaders();
        response.Cache.SetMaxAge (new TimeSpan (0));

        using (var stream = new MemoryStream()) {
            _data.CreateXlsxAndFillData (stream);

            //Return it to the client - strFile has been updated, so return it. 
            response.AddHeader ("content-disposition", "attachment; filename=" + _fileName);

            // see http://filext.com/faq/office_mime_types.php
            response.ContentType = "application/vnd.openxmlformats-officedocument.spreadsheetml.sheet";
            response.ContentEncoding = Encoding.UTF8;
            stream.WriteTo (response.OutputStream);
        }
        response.Flush();
        response.Close();
    }
}

To make the code full I have to include the code of the class DataForExcel:

public class DataForExcel {
    public enum DataType {
        String,
        Integer
    }
    private readonly string[] _headers;
    private readonly DataType[] _colunmTypes;
    private readonly List<string[]> _data;
    private readonly string _sheetName = "Grid1";
    private readonly SortedSet<string> _os = new SortedSet<string> ();
    private string[] _sharedStrings;

    private static string ConvertIntToColumnHeader(int index) {
        var sb = new StringBuilder ();
        while (index > 0) {
            if (index <= 'Z' - 'A') // index=0 -> 'A', 25 -> 'Z'
                break;
            sb.Append (ConvertIntToColumnHeader (index / ('Z' - 'A' + 1) - 1));
            index = index % ('Z' - 'A' + 1);
        }
        sb.Append ((char)('A' + index));
        return sb.ToString ();
    }

    private static Row CreateRow(UInt32 index, IList<string> data) {
        var r = new Row { RowIndex = index };
        for (var i = 0; i < data.Count; i++)
            r.Append (new OpenXmlElement[] { CreateTextCell (ConvertIntToColumnHeader (i), index, data[i]) });

        return r;
    }

    private Row CreateRowWithSharedStrings(UInt32 index, IList<string> data) {
        var r = new Row { RowIndex = index };
        for (var i = 0; i < data.Count; i++)
            r.Append (new OpenXmlElement[] { CreateSharedTextCell (ConvertIntToColumnHeader (i), index, data[i]) });

        return r;
    }

    private Row CreateRowWithSharedStrings(UInt32 index, IList<string> data, IList<DataType> colunmTypes) {
        var r = new Row { RowIndex = index };
        for (var i = 0; i < data.Count; i++)
            if (colunmTypes != null && i < colunmTypes.Count && colunmTypes[i] == DataType.Integer)
                r.Append (new OpenXmlElement[] { CreateNumberCell (ConvertIntToColumnHeader (i), index, data[i]) });
            else
                r.Append (new OpenXmlElement[] { CreateSharedTextCell (ConvertIntToColumnHeader (i), index, data[i]) });

        return r;
    }

    private static Cell CreateTextCell(string header, UInt32 index, string text) {
        // create Cell with InlineString as a child, which has Text as a child
        return new Cell (new InlineString (new Text { Text = text })) {
            // Cell properties
            DataType = CellValues.InlineString,
            CellReference = header + index
        };
    }

    private Cell CreateSharedTextCell(string header, UInt32 index, string text) {
        for (var i=0; i<_sharedStrings.Length; i++) {
            if (String.Compare (_sharedStrings[i], text, StringComparison.Ordinal) == 0) {
                return new Cell (new CellValue { Text = i.ToString (CultureInfo.InvariantCulture) }) {
                    // Cell properties
                    DataType = CellValues.SharedString,
                    CellReference = header + index
                };
            }
        }
        // create Cell with InlineString as a child, which has Text as a child
        throw new InstanceNotFoundException();
    }

    private static Cell CreateNumberCell(string header, UInt32 index, string numberAsString) {
        // create Cell with CellValue as a child, which has Text as a child
        return new Cell (new CellValue { Text = numberAsString }) {
            // Cell properties
            CellReference = header + index
        };
    }

    private void FillSharedStringTable(IEnumerable<string> data) {
        foreach (var item in data)
            _os.Add (item);
    }

    private void FillSharedStringTable(IList<string> data, IList<DataType> colunmTypes) {
        for (var i = 0; i < data.Count; i++)
            if (colunmTypes == null || i >= colunmTypes.Count || colunmTypes[i] == DataType.String)
                _os.Add (data[i]);
    }

    public DataForExcel(string[] headers, List<string[]> data, string sheetName) {
        _headers = headers;
        _data = data;
        _sheetName = sheetName;
    }

    public DataForExcel(string[] headers, DataType[] colunmTypes, List<string[]> data, string sheetName) {
        _headers = headers;
        _colunmTypes = colunmTypes;
        _data = data;
        _sheetName = sheetName;
    }

    private void FillSpreadsheetDocument(SpreadsheetDocument spreadsheetDocument) {
        // create and fill SheetData
        var sheetData = new SheetData ();

        // first row is the header
        sheetData.AppendChild (CreateRow (1, _headers));

        //const UInt32 iAutoFilter = 2;
        // skip next row (number 2) for the AutoFilter
        //var i = iAutoFilter + 1;
        UInt32 i = 2;

        // first of all collect all different strings in OrderedSet<string> _os
        foreach (var dataRow in _data)
            if (_colunmTypes != null)
                FillSharedStringTable (dataRow, _colunmTypes);
            else
                FillSharedStringTable (dataRow);
        _sharedStrings = _os.ToArray ();

        foreach (var dataRow in _data)
            sheetData.AppendChild (_colunmTypes != null
                                      ? CreateRowWithSharedStrings (i++, dataRow, _colunmTypes)
                                      : CreateRowWithSharedStrings (i++, dataRow));

        var sst = new SharedStringTable ();
        foreach (var text in _os)
            sst.AppendChild (new SharedStringItem (new Text (text)));

        // add empty workbook and worksheet to the SpreadsheetDocument
        var workbookPart = spreadsheetDocument.AddWorkbookPart ();
        var worksheetPart = workbookPart.AddNewPart<WorksheetPart> ();

        var shareStringPart = workbookPart.AddNewPart<SharedStringTablePart> ();
        shareStringPart.SharedStringTable = sst;

        shareStringPart.SharedStringTable.Save ();

        // add sheet data to Worksheet
        worksheetPart.Worksheet = new Worksheet (sheetData);
        worksheetPart.Worksheet.Save ();

        // fill workbook with the Worksheet
        spreadsheetDocument.WorkbookPart.Workbook = new Workbook (
                new FileVersion { ApplicationName = "Microsoft Office Excel" },
                new Sheets (
                    new Sheet {
                        Name = _sheetName,
                        SheetId = (UInt32Value)1U,

                        // generate the id for sheet
                        Id = workbookPart.GetIdOfPart (worksheetPart)
                    }
                )
            );
        spreadsheetDocument.WorkbookPart.Workbook.Save ();
        spreadsheetDocument.Close ();
    }

    public void CreateXlsxAndFillData(Stream stream) {
        // Create workbook document
        using (var spreadsheetDocument = SpreadsheetDocument.Create (stream, SpreadsheetDocumentType.Workbook)) {
            FillSpreadsheetDocument (spreadsheetDocument);
        }
    }
}

The above code create new XLSX file directly. You can extend the code to support more data types as String and Integer which I used in the code.

In more professional version of your application you can create some XLSX templates for exporting different tables. In the code you can place the data in the cells instead, so modify the spreadsheet instead of creating. In the way you can create perfect formatted XLSX files. The examples from the MSDN (see here) will help you to implement the way when it will be required.

UPDATED: The answer contains updated code which allows generate Excel documented with more cell formatting.

Sarchet answered 19/2, 2012 at 13:42 Comment(18)
Thank you so much Oleg! Your answers are always thorough and educational, thank you very much for everything you do, you see that you put passion and dedication. Unfortunately I was not able to find other answers, sorry...however you provide more precious informations.Just a curiosity, if is possible...did you write books? THX!Musetta
@Larry: You are welcome! I wrote books in mathematics many years ago. Recently I started to write a book about jqGrid, but I am still not sure whether I will have enough time to finish it. After enough materials will be prepared I could post URL to the first chapters to you if you want.Sarchet
The world would be better if there were more people like you ... but that's what makes you unique and rare. THANK YOU! ;)Musetta
@Larry: I made minor code optimization in the code from the answer and updated the demo project too. You can reload it.Sarchet
let us continue this discussion in chatMusetta
I succeed to make filtered export, taking inspiration by @simpatric greg solution (https://mcmap.net/q/430408/-jqgrid-export-to-excel-with-current-filter-post-data-in-an-asp-net-mvc-site). I set one session variable for each grid parameter, when data is requested and then passing again them to the excel export service. For example: CONTROLLER GRID ACTION Session["jqsidx"] = sidx; Session["jqsord"] = sord; Session["jqpage"] = page; Session["jqrows"] = rows; Session["jq_search"] = _search; Session["jqfilters"] = filters; RECALLED INSIDE OF EXCEL EXPORT ^^Musetta
@Sarchet Is there a way to apply color to headers in addition to this?Comity
@RustinCohle: Yes, of cause. Look at the answer which I referenced in the UPDATED part of my answer. Search for "// Index 2 - no pattern text on gray background". It uses PatternFill with gray background. The method CreateColumnHeaderRow set the StyleIndex of the row. It's all.Sarchet
Thanks. I will try that. Is there a specific way to get the headers and gridData from client side? I am getting them, but it brings the button columns and checkbox columns as well.Comity
@RustinCohle: Sorry, but I don't understand your question. What scenario you mean? What is gridData? The current answer is just about returning Excel file dynamically generated.Sarchet
In Current demo you are converting hardcoded data to excel, if I am not wrong. I have a grid with columns having buttons, checkboxes. When I get grid's data and headers to pass them to DataExcelFile, I get html elements in data.Comity
@RustinCohle: The same code work with not only hardcoded data. For me there are exist original data in the database. MVC application and provide the data to display in jqGrid for example. The bit data, for example, will be presented as Boolean in C# and will be displayed as chechboxs in jqGrid. If I export such data to Excel I use typically x symbol for 1 and empty string for 0. The buttons in grid don't corresponds any data in original dataset and there don't needed be exist in Excel. If general you can use any possibilities of Excel by Open XML SDK, you will just get more long code.Sarchet
I am getting grid's data by var gridData = jQuery(tableCtrl).jqGrid('getRowData'); to pass data to DataExcelFile. Do you suggest to get the data from database or from grid itself?Comity
@RustinCohle: Sorry, but it's absolutely wrong. One has data in the database. One read the data on the server side and then one can either provide the data as JSON, which can be used to fill jqGrid, or as binary XLSX file generated by the server. Thus one should not get any data from jqGrid and especially getRowData, which return the data from one page only. Sending the data to the server, which one previously get from the server, seems be not the best choice. Instead of that one should just implement new controller method, which returns XLSX file instead of JSON.Sarchet
Yes, you are absolutely right. I have all the jqgrid related code as separate project as dll, so i thought i dont have to contact the consuming application once more for the data. Looks like I will have to. Thanks.Comity
@RustinCohle: You are welcome! It's important to think that one can't start Excel from JavaScript code, but the Excel will be automatically started by web browser if the response contains HTTP header ContentType: application/vnd.openxmlformats-officedocument.spreadsheetml.sheet. Thus it's native to generate the XLSX directly by the server. Getting the data from the database is more native and more quickly (database have typically quick network connection to the web server, but not to every web client) as unformatting the data from jqGrid abd sending there back to the web server.Sarchet
Yes, you are right, I am going in the same approach. One more question regarding this, assume I am ppassing the color name also along with headers, is there way to dynamically create styleindex/cellformat for the respective colors?Comity
@RustinCohle: Everything is possible, you need just modify the code which I posted in the answer.Sarchet
B
1

I looked at Stephen's post and it's old as hell, which btw doesn't make it wrong. If you don't need custom formatting, headers and styles, then I think use CSV as it's very simple.
More importantly, don't think that excel export from MVC site that internally uses EF for data access is harder than, say, Ruby on Rails site that uses ActiveRecord. For me it's independent concerns, export shouldn't new anything about underlying technologies (at least not directly), just the structure of your data, that's all.
Search for codeplex libraries that allows to do Excel reading/writing and export, there are plenty of them these days, many really good solutions that's regularly maintained and tested by thousand of developers all over the globe. If I were you I won't use Stephen solution because it looks like he occasionally typed it in a notepad and then pasted to the post - no unit tests, no extensibility points + it's in VB so it even harder to understand, but may be that's just me. Hope this help and good luck

Breechblock answered 18/2, 2012 at 13:21 Comment(2)
Thank you for your reply and suggestions. If you take a look at the blog, Stephen's solution includes vb + c# code with a download link with the ready examples. Anyway, I'd like to have a complete example which describes how to do an export of jqgrid's data with MVC. Until now, I did not find nothing complete, and my still poor knowlege get me confused not only about what library to use for export, but mainly how to pass jqgrid data to my controller. Any further help will be precious. Thank you very much!Musetta
also, I believe your export functionality sholdn't be tied to jqGridBreechblock

© 2022 - 2024 — McMap. All rights reserved.