Problem With View and Changing Field Length

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • Neil

    Problem With View and Changing Field Length

    I had a strange situation with a view in SQL 7, that I could use some input
    on.

    I had a very simple view -- select a, b, c from table1 where x=y and z=q.
    Field a in table1 originally was varchar 70. A long time ago I changed it to
    varchar 95.

    I used this view as an ODBC linked table in an Access MDB. Recently, there
    was one row which has a value in field a that was more than 70 characters
    long. This caused an error when the view as opened in the MDB file: "string
    data, right truncation (#0)"

    I went to the view in SQL Server, and displayed the row fine. So I delete
    the link to the view in Access, compacted the Access database, and recreated
    the link. Same results. The row showed #Error in the linked view, and the
    message box with the truncation error would come up.

    I went into SQL Server, took the SQL from the view and created a new view. I
    linked the new view in Access, and it worked fine. No error.

    So it seems that, somehow, view was holding onto the old field length, even
    though it was using the new field length when displayed. But when the view
    was linked, it used the old field length.

    Is there something I could have or should have done short of recreating the
    view? Any idea why the view used the old field length when it was linked,
    but used the new field length when it was opened directly?

    Thanks!

    Neil


  • Dan Guzman

    #2
    Re: Problem With View and Changing Field Length

    Is there something I could have or should have done short of recreating
    the view? Any idea why the view used the old field length when it was
    linked, but used the new field length when it was opened directly?
    View meta data are stored at the time the view is created so subsequent
    changes to the underlying objects won't be reflected in the view. After
    making changes to tables referenced by views, you'll need to either recreate
    the views or execute sp_refreshview against the views to sync the meta data.

    --
    Hope this helps.

    Dan Guzman
    SQL Server MVP


    "Neil" <nospam@nospam. netwrote in message
    news:hiI3k.1083 $LG4.901@nlpi06 5.nbdc.sbc.com. ..
    >I had a strange situation with a view in SQL 7, that I could use some input
    >on.
    >
    I had a very simple view -- select a, b, c from table1 where x=y and z=q.
    Field a in table1 originally was varchar 70. A long time ago I changed it
    to varchar 95.
    >
    I used this view as an ODBC linked table in an Access MDB. Recently, there
    was one row which has a value in field a that was more than 70 characters
    long. This caused an error when the view as opened in the MDB file:
    "string data, right truncation (#0)"
    >
    I went to the view in SQL Server, and displayed the row fine. So I delete
    the link to the view in Access, compacted the Access database, and
    recreated the link. Same results. The row showed #Error in the linked
    view, and the message box with the truncation error would come up.
    >
    I went into SQL Server, took the SQL from the view and created a new view.
    I linked the new view in Access, and it worked fine. No error.
    >
    So it seems that, somehow, view was holding onto the old field length,
    even though it was using the new field length when displayed. But when the
    view was linked, it used the old field length.
    >
    Is there something I could have or should have done short of recreating
    the view? Any idea why the view used the old field length when it was
    linked, but used the new field length when it was opened directly?
    >
    Thanks!
    >
    Neil
    >

    Comment

    • Neil

      #3
      Re: Problem With View and Changing Field Length


      "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.netwrote in message
      news:u7P3k.3396 $L_.1118@flpi15 0.ffdc.sbc.com. ..
      >Is there something I could have or should have done short of recreating
      >the view? Any idea why the view used the old field length when it was
      >linked, but used the new field length when it was opened directly?
      >
      View meta data are stored at the time the view is created so subsequent
      changes to the underlying objects won't be reflected in the view. After
      making changes to tables referenced by views, you'll need to either
      recreate the views or execute sp_refreshview against the views to sync the
      meta data.
      Thanks. Good to know. Is there a way to run sp_refreshview against all
      views, sort of as a global refresh? Or is there a feature in EM that might
      do this? Thanks.


      Comment

      • Erland Sommarskog

        #4
        Re: Problem With View and Changing Field Length

        Neil (nospam@nospam. net) writes:
        Thanks. Good to know. Is there a way to run sp_refreshview against all
        views, sort of as a global refresh? Or is there a feature in EM that might
        do this? Thanks.
        SELECT 'EXEC sp_refreshview ' + quotename(name)
        FROM sysobjects
        WHERE type = 'V'

        Copy result into a query window and run it.

        --
        Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

        Books Online for SQL Server 2005 at

        Books Online for SQL Server 2000 at

        Comment

        • Neil

          #5
          Re: Problem With View and Changing Field Length

          Thanks, Erland! Just curious, as more of a theoretical point: why, do you
          suppose, SQL Server doesn't reset the metadata when a table's structure has
          changed? Seems that if the table structure has changed, the old meta data is
          no longer valid. So why not automatically change it?

          Thanks.


          "Erland Sommarskog" <esquel@sommars kog.sewrote in message
          news:Xns9ABAF1C FCEBE3Yazorman@ 127.0.0.1...
          Neil (nospam@nospam. net) writes:
          >Thanks. Good to know. Is there a way to run sp_refreshview against all
          >views, sort of as a global refresh? Or is there a feature in EM that
          >might
          >do this? Thanks.
          >
          SELECT 'EXEC sp_refreshview ' + quotename(name)
          FROM sysobjects
          WHERE type = 'V'
          >
          Copy result into a query window and run it.
          >
          --
          Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
          >
          Books Online for SQL Server 2005 at

          Books Online for SQL Server 2000 at
          http://www.microsoft.com/sql/prodinf...ons/books.mspx

          Comment

          • Erland Sommarskog

            #6
            Re: Problem With View and Changing Field Length

            Neil (nospam@nospam. net) writes:
            Thanks, Erland! Just curious, as more of a theoretical point: why, do
            you suppose, SQL Server doesn't reset the metadata when a table's
            structure has changed? Seems that if the table structure has changed,
            the old meta data is no longer valid. So why not automatically change
            it?
            I think my answer to that question is that you should put this
            suggestion on Connect:



            --
            Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

            Books Online for SQL Server 2005 at

            Books Online for SQL Server 2000 at

            Comment

            • Neil

              #7
              Re: Problem With View and Changing Field Length


              "Erland Sommarskog" <esquel@sommars kog.sewrote in message
              news:Xns9ABBED4 029BD4Yazorman@ 127.0.0.1...
              Neil (nospam@nospam. net) writes:
              >Thanks, Erland! Just curious, as more of a theoretical point: why, do
              >you suppose, SQL Server doesn't reset the metadata when a table's
              >structure has changed? Seems that if the table structure has changed,
              >the old meta data is no longer valid. So why not automatically change
              >it?
              >
              I think my answer to that question is that you should put this
              suggestion on Connect:

              >
              Ah, so it's not a question of some deep technological mystery, but more of a
              deep MS mystery. :-) Thanks!


              Comment

              Working...