Vba line of code takes a long time to run

  • MODERATOR NOTICE: This topic has also been posted on other sites and may already have an answer elsewhere. Please take this into consideration when answering this question

    Hi all,

    New to the forum but wondering if anyone could help. I have inherited a vba database in excel with code i'm trying to edit without needing to rewrite.

    The purpose of the database is to house transactions for customers. Users update templates which get pulled into a log sort and formatted and then update to the database which holds single/unique records with history.


    It has quite alot of modules but one in particular runs extremely slow. This entire module deals with loading the templates into the log. Stepping through the code i can see that the below section of code is the reason. This problematic bit of code comes after the data in the templates are collated into one temporary 'holding file' and formatted. Everything before and after here takes seconds this section however can take upto hours depending kn the number of rows of data.


    (1) What is it doing?

    (2) Can i rewrite to do the same/similar thing but faster


    I've tried just removing it but it has an impact on the overall sequence of code.

    /////Problematic bit of code takes a long time run depending on number of records:


    change_data is long

    IN_UPDATE is a column name "update"



    Code
    1. For change_data = 1 To range_in.Rows.Count
    2. range_in.Cells(change_data, IN_UPDATE).Value = Trim(CStr(rg_in.Cells(change_data, IN_UPDATE).Value))
    3. Next change_data
  • Welcome to the Forum. Please read the Forum Rules to understand how the Forum works and why I have added Code Tags to your post


    All VBA code posted in the forum must be wrapped in code tags, which you omitted, including single-line code snippets.Be sure to use them in future posts.


    How to use code tags


    Just highlight all of the code and press the <> in the post menu above button to add the code tags.


    Thanks.

  • Reading and writing cell by cell is slow - use an array instead. For example:


    Code
    1. Dim data
    2. data = range_in.Columns(IN_UPDATE).Value
    3. For change_data = 1 To UBound(data)
    4. data(change_data, 1) = Trim$(data(change_data, 1))
    5. Next change_data
    6. range_in.Columns(IN_UPDATE).Value = data

    Rory
    Theory is when you know something, but it doesn’t work. Practice is when something works, but you don’t know why. Programmers combine theory and practice: nothing works and they don’t know why

  • Cross-posting is when you post the same question in other forums on the web. You'll find people are disinclined to respond to cross-posts because they may be wasting their time solving a problem that has been solved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post. We are here to help so help us help you!




    Read this to understand why we ask you to do this



    https://www.excelguru.ca/content.php?184

  • hi all, thanks for your help.


    Seems i have broken some rules posting in different forums. Will respond to each to get removed and use the suggestions here for testing. My sincerest apologies

  • Reading and writing cell by cell is slow - use an array instead. For example:


    Code
    1. Dim data
    2. data = range_in.Columns(IN_UPDATE).Value
    3. For change_data = 1 To UBound(data)
    4. data(change_data, 1) = Trim$(data(change_data, 1))
    5. Next change_data
    6. range_in.Columns(IN_UPDATE).Value = data

    Thanks rory👍🏾