More questions about porting from MySQL to MS SQL

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

    More questions about porting from MySQL to MS SQL

    1) In several tables, in my MySQL version, I created columns using
    something like the following:

    `ab_timestamp` timestamp NOT NULL default CURRENT_TIMESTA MP on update
    CURRENT_TIMESTA MP,

    This allowed me to ensure that when a record is either added or edited,
    the value in the field is set to the current date and time. I.E.,
    ab_timestamp is given the current date and time when a record is
    created, and then it is updated to the date and time at which the
    record is updated. I learned the hard way that MS SQL does not like
    "on update CURRENT_TIMESTA MP". So, it looks like MS SQL will allow me
    to initialize ab_timestamp to the current date and time, but not
    automatically update it to the date and time at which the record is
    updated. I have plenty of code to port that depends on the behaviour
    supported by MySQL. DO I have to modify all that code, or is there a
    way to get MS SQL to provide it? (Yes, I know 'timestamp' is
    deprecated in MS SQL and that I should use datetime instead, and in
    fact have already done so.)

    2) I began with a single SQL script that creates all the tables, views,
    functions and triggers the database needs. On trying to get MS SQL to
    accept it, I encountered a number of error messages saying that CREATE
    FUNCTION and CREATE VIEW need to be the first statement in a script.
    Why? I know I can work around this odd constraint by putting each
    function and view (and IIRC trigger) into its own script, but that
    seems like a make work effort imposed for some unknown reason by MS
    SQL, unless there is another way to get around it.

    3) I see, in the documentation for CREATE FUNCTION, functions are not
    allowed to use a timestamp for either a parameter or a return value.
    This is in reference to a pair of scalar functions I am using which
    need to manipulate date and time values. For the purpose of
    clarification, is this documentation refering to all date/time data
    types, or only the deprecated timestamp type? As examples, consider
    one function that needs to return the most recent date in a date column
    in a specific table, or another function that computes a date from a
    date and an offset (e.g. if called with the value returned by the first
    function as the first argument and '-7' as the second, returns the date
    of the day that is a week earlier than that date). These two functions
    are frequently used in the SQL code I'm trying to port and I really
    don't want to complicate so many of those statements if I don't have
    to.

    Thanks

    Ted

  • David Portas

    #2
    Re: More questions about porting from MySQL to MS SQL

    Ted wrote:
    1) In several tables, in my MySQL version, I created columns using
    something like the following:
    >
    `ab_timestamp` timestamp NOT NULL default CURRENT_TIMESTA MP on update
    CURRENT_TIMESTA MP,
    >
    This allowed me to ensure that when a record is either added or edited,
    the value in the field is set to the current date and time. I.E.,
    ab_timestamp is given the current date and time when a record is
    created, and then it is updated to the date and time at which the
    record is updated. I learned the hard way that MS SQL does not like
    "on update CURRENT_TIMESTA MP". So, it looks like MS SQL will allow me
    to initialize ab_timestamp to the current date and time, but not
    automatically update it to the date and time at which the record is
    updated. I have plenty of code to port that depends on the behaviour
    supported by MySQL. DO I have to modify all that code, or is there a
    way to get MS SQL to provide it? (Yes, I know 'timestamp' is
    deprecated in MS SQL and that I should use datetime instead, and in
    fact have already done so.)
    >
    2) I began with a single SQL script that creates all the tables, views,
    functions and triggers the database needs. On trying to get MS SQL to
    accept it, I encountered a number of error messages saying that CREATE
    FUNCTION and CREATE VIEW need to be the first statement in a script.
    Why? I know I can work around this odd constraint by putting each
    function and view (and IIRC trigger) into its own script, but that
    seems like a make work effort imposed for some unknown reason by MS
    SQL, unless there is another way to get around it.
    >
    3) I see, in the documentation for CREATE FUNCTION, functions are not
    allowed to use a timestamp for either a parameter or a return value.
    This is in reference to a pair of scalar functions I am using which
    need to manipulate date and time values. For the purpose of
    clarification, is this documentation refering to all date/time data
    types, or only the deprecated timestamp type? As examples, consider
    one function that needs to return the most recent date in a date column
    in a specific table, or another function that computes a date from a
    date and an offset (e.g. if called with the value returned by the first
    function as the first argument and '-7' as the second, returns the date
    of the day that is a week earlier than that date). These two functions
    are frequently used in the SQL code I'm trying to port and I really
    don't want to complicate so many of those statements if I don't have
    to.
    >
    Thanks
    >
    Ted

    1) You can use an UPDATE trigger to simulate the same functionality.
    Usually though it is better to use stored procedures to perform all
    your data access. That way you can easily include the timestamp as part
    of your update procs.

    2) You don't need separate scripts for each View / Function. You do
    need separate batches. A batch is separated using the GO keyword in
    Query Analyzer.

    3) Don't confuse TIMESTAMP with DATETIME. They are not at all the same!
    You are referring to DATETIME values, which ARE permitted as parameters
    and return values in functions. BTW, you don't need to write a function
    to do date arithmetic - it already exists as a built-in function:
    DATEADD().

    --
    David Portas, SQL Server MVP

    Whenever possible please post enough code to reproduce your problem.
    Including CREATE TABLE and INSERT statements usually helps.
    State what version of SQL Server you are using and specify the content
    of any error messages.

    SQL Server Books Online:

    --

    Comment

    • Erland Sommarskog

      #3
      Re: More questions about porting from MySQL to MS SQL

      Ted (r.ted.byers@ro gers.com) writes:
      1) In several tables, in my MySQL version, I created columns using
      something like the following:
      >
      `ab_timestamp` timestamp NOT NULL default CURRENT_TIMESTA MP on update
      CURRENT_TIMESTA MP,
      >
      This allowed me to ensure that when a record is either added or edited,
      the value in the field is set to the current date and time. I.E.,
      ab_timestamp is given the current date and time when a record is
      created, and then it is updated to the date and time at which the
      record is updated. I learned the hard way that MS SQL does not like
      "on update CURRENT_TIMESTA MP". So, it looks like MS SQL will allow me
      to initialize ab_timestamp to the current date and time, but not
      automatically update it to the date and time at which the record is
      updated. I have plenty of code to port that depends on the behaviour
      supported by MySQL. DO I have to modify all that code, or is there a
      way to get MS SQL to provide it?
      You will have to modify all that code. To have to be portable is indeed
      painful, and a good start is to pay attention to what is in ANSI standards,
      what is commonly supported. And not to the least to what are extensions
      added by a certain vendor. My knowledge of ANSI and other engines are
      poor (since I live in a sheltered world where I only need to support
      SQL Server), but I would suspect that the ON UPDATE clause for the
      default constraint is properitary to MySQL.

      The way to do this in SQL Server is to use a trigger. Not that triggers
      usually are very portable...

      You can also modify the UPDATE statements so that they read:

      UPDATE tbl
      SET ...,
      ab_timestamp = DEFAULT,
      WHERE ...

      I believe this syntax is portable.
      (Yes, I know 'timestamp' is deprecated in MS SQL and that I should use
      datetime instead, and in fact have already done so.)
      timestamp is not deprecated in SQL Server, but it's a completely different
      data type, which is used to implement optimistic locking. A timestamp
      is an 8-bit value is updated each time the row is updated and it's
      unique within the database. Further more timestamp value are monotonically
      increasing. But there is no correlation with time. Timestamp is
      proprietary to SQL Server, so you should probably stay away from it
      entirely.
      2) I began with a single SQL script that creates all the tables, views,
      functions and triggers the database needs. On trying to get MS SQL to
      accept it, I encountered a number of error messages saying that CREATE
      FUNCTION and CREATE VIEW need to be the first statement in a script.
      Why? I know I can work around this odd constraint by putting each
      function and view (and IIRC trigger) into its own script, but that
      seems like a make work effort imposed for some unknown reason by MS
      SQL, unless there is another way to get around it.
      Not a separate script, but a separate batch. Batches are separated with
      "go" in all query tools. The graphic tools permit you to specify a
      different batch separator.

      Why? Because else it would be difficult to tell where a procedure ends.
      Say that you have:

      CREATE PROCEDURE .... AS
      ....
      CREATE TABLE ....

      Is that CREATE TABLE part of the procedure or not? (Yes, if you have
      BEGIN END it's clear. But of legacy BEGIN END is not required in
      stored procedures.)

      3) I see, in the documentation for CREATE FUNCTION, functions are not
      allowed to use a timestamp for either a parameter or a return value.
      As noted above, there is little reason for your to use the timestamp
      data type.


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

      Books Online for SQL Server 2005 at

      Books Online for SQL Server 2000 at

      Comment

      Working...