Character '*' in float column

  • Hi everybody,

    I m an intern in charge of creating an sql server database for production data. We got basically parts numbers and measurements which are float columns. To avoid having any doubt considering blanks (to differentiate between bugs and normal NULLS as far as i understood), the engineering team here decided to put "*" instead of nothing. (Data is csv files).

    I need to consider this '*' as NULL in a column which has float type.

    I tried a trigger "instead of insert" and NULLIF on '*' character but obviously the two parameters of the NULLIF need to be of the same type.

    I've been told the easiest thing to do would be to modify the data before insert. Is it true

    Here is a reduced part of the code :

    CREATE TRIGGER etoilenulle4 ON dbo.Tablebase

    AFTER INSERT

    AS

    BEGIN

    INSERT [dbo].[Tablebase]

    ([N° CAM]

    ,[C# fourn]

    ,[date]

    ,[heure]

    ,[banc]

    ,[N° Pale#]

    ,[Module_Status]

    ,[Code défaut]

    ,[NeutralBefore_13]

    ,[NeutralBefore_60]

    ,[S_T4]

    ,[S13_IminPPV1])

    SELECT

    [N° CAM]

    ,[C# fourn]

    ,[date]

    ,[heure]

    ,[banc]

    ,[N° Pale#]

    ,[Module_Status]

    ,[Code défaut]

    ,NULLIF([NeutralBefore_13],'*')

    ,NULLIF([NeutralBefore_60],'*')

    ,NULLIF([S_T4],'*')

    ,NULLIF([S13_IminPPV1],'*')

    FROM INSERTED

    END

  • not sure about the trigger being what you want to do or not...

    it should be an instead of trigger and not a FOR/AFTER trigger, i think

    a float cannot have an asterisk in it, so the data must be a char/varchar data type.

    to put it in a float column, you should explcitly convert it to a float datatype i think:

    SELECT

    [N° CAM]

    ,[C# fourn]

    ,[date]

    ,[heure]

    ,[banc]

    ,[N° Pale#]

    ,[Module_Status]

    ,[Code défaut]

    ,CONVERT(float,NULLIF([NeutralBefore_13],'*'))

    ,CONVERT(float,NULLIF([NeutralBefore_60],'*'))

    ,CONVERT(float,NULLIF([S_T4],'*'))

    ,CONVERT(float,NULLIF([S13_IminPPV1],'*'))

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • That is exactly what i was looking for. thanks a lot Lowell!

    PS : Sorry for the error in my post, I actually did an INSTEAD OF trigger.

  • ohpenot (2/13/2013)


    That is exactly what i was looking for.

    Not sure about that.

    Did you try to run it?

    It won't work if those columns in dbo.Tablebase are of FLOAT data type.

    Table INSERTED will have the same column definitions as dbo.Tablebase, so an attempt to place '*' into a FLOAT column will result in run time error.

    And if the columns are of a one of the CHAR data types you face the issues coming from implicit conversions from FLOAT to VARCHAR.

    You may get some nasty surprises on this way.

    _____________
    Code for TallyGenerator

  • Hi Sergiy,

    Indeed, i tried to run today and it s not working.

    USE [test1]

    GO

    BULK INSERT [dbo].[TABLETEST1]

    FROM 'C:\Users\HPENOT\Documents\data_xls\ligneEOLT2etoile.txt'

    WITH

    (

    FIELDTERMINATOR =';',

    ROWTERMINATOR = '',

    FIRE_TRIGGERS

    )

    GO

    Msg 4864, Niveau 16, État 1, Ligne 2

    Erreur de conversion des données de chargement en masse (incompatibilité de type ou caractère non valide pour la page de codes spécifiée) pour la ligne 1, colonne 12 (ST_13).

    (0 ligne(s) affectée(s))

    USE [test1]

    GO

    /****** Object: Trigger [dbo].[nullifetoile] Script Date: 14/02/2013 13:06:44 ******/

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    ALTER TRIGGER [dbo].[nullifetoile] ON [dbo].[TABLETEST1]

    INSTEAD OF INSERT

    AS

    BEGIN

    INSERT [dbo].[TABLETEST1]

    ([NUMCAM]

    ,[Code_Fournisseur]

    ,[JOURJ]

    ,[HEUREH]

    ,[BANC]

    ,[NUMPALE]

    ,[Module_Status]

    ,[Code_defaut]

    ,[NeutralBefore_13]

    ,[NeutralBefore_60]

    ,[ST_4]

    ,[ST_13])

    SELECT

    [NUMCAM]

    ,[Code_Fournisseur]

    ,[JOURJ]

    ,[HEUREH]

    ,[BANC]

    ,[NUMPALE]

    ,[Module_Status]

    ,[Code_defaut]

    ,CONVERT(float,NULLIF([NeutralBefore_13],'*'))

    ,CONVERT(float,NULLIF([NeutralBefore_60],'*'))

    ,CONVERT(float,NULLIF([ST_4],'*'))

    ,CONVERT(float,NULLIF([ST_13],'*'))

    FROM INSERTED

    END

  • Bottom line, you can't put a * into a float column, it's not a float. It you want to badly mess thing up, you could convert the column to a varchar then spend huge time and effort fixing bad data, correcting 'broken' calculations and making massive amounts of work for yourself. If the data is numeric then the column should not be a varchar.

    You can convert nulls to * in the queries that retrieve from the table.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Or you can create a view on top of the table with those FLOAT columns converted to VARCHAR and set up an INSTEAD OF INSERT, UPDATE trigger on it - same code as posted above.

    _____________
    Code for TallyGenerator

  • WARNING! Storing PART NUMBERS as FLOAT will eventually and absolutely screw you to the deck without warning.

    DECLARE @PartNumber FLOAT;

    SELECT @PartNumber = 1234567890123456;

    SELECT @PartNumber AS ScrewedALittle;

    SELECT @PartNumber = 12345678901234567;

    SELECT @PartNumber AS ScrewedALot;

    If you store the part "number" as a VARCHAR (as you would other "numbers" that aren't really numbers such as telephone numbers, zip codes, SSNs, etc) , then you can have your "*" cake and eat it, too! 😀

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Hi guys,

    Part number is a varchar column. Float columns are measurements.

    The solution i think is what u said Sergyie. I m going to insert first temp table with varchar columns and then use the "TRY_CONVERT" function in "INSTEAD OF INSERT" trigger. I'll let u know if it works....!

  • It does work.

    I did create a copy of the table with varchar columns instead of float and i insert the data in this table. An "instead of" trigger insert then the data in the proper table. That suits me cose it seems that they want to differentiate between when "*" is being written and when it s a blank. So i ll have a "text copy" of my measurements columns obviously.

    Thanks Sergiy! thanks to everyone for your advices, first step of a long run i think!

    [SELECT

    [Code_Fournisseur]

    ,[JOURJ]

    ,[HEUREH]

    ,[BANC]

    ,[NUMPALE]

    ,[Module_Status]

    ,[Code_defaut]

    ,TRY_CONVERT(float,[NeutralBefore_13])

    ,TRY_CONVERT(float,[NeutralBefore_60])

    ,TRY_CONVERT(float,[ST_4])

    ,TRY_CONVERT(float,[ST_13])

    FROM inserted

    END

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply