Issue with query

  • narayanamoorthy.a (6/28/2016)


    Its foreign key. Unique identifier Not Null.

    Both columns?

    Please post CREATE TABLE scripts for both tables.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Yes ID column is primary key and ID_TASK_USER is foreign key with unique identifiers. Below is the script

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    CREATE TABLE [dbo].[task_attach](

    [id] [uniqueidentifier] NOT NULL,

    [id_task_user] [uniqueidentifier] NOT NULL,

    [detail] [nvarchar](255) NULL,

    [file_name] [nvarchar](255) NULL,

    [file_url] [nvarchar](255) NULL,

    [file_format] [nvarchar](255) NULL,

    [file_type] [int] NULL,

    [include_mode] [tinyint] NULL,

    [embedded_data] [image] NULL,

    PRIMARY KEY CLUSTERED

    (

    [id] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]

    ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

    GO

    ALTER TABLE [dbo].[task_attach] WITH NOCHECK ADD CONSTRAINT [FK_task_attach_task_user] FOREIGN KEY([id_task_user])

    REFERENCES [dbo].[task_user] ([id])

    ON UPDATE CASCADE

    ON DELETE CASCADE

    GO

    ALTER TABLE [dbo].[task_attach] CHECK CONSTRAINT [FK_task_attach_task_user]

    GO

  • narayanamoorthy.a (6/28/2016)


    Yes ID column is primary key and ID_TASK_USER is foreign key with unique identifiers. Below is the script

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    CREATE TABLE [dbo].[task_attach](

    [id] [uniqueidentifier] NOT NULL,

    [id_task_user] [uniqueidentifier] NOT NULL,

    [detail] [nvarchar](255) NULL,

    [file_name] [nvarchar](255) NULL,

    [file_url] [nvarchar](255) NULL,

    [file_format] [nvarchar](255) NULL,

    [file_type] [int] NULL,

    [include_mode] [tinyint] NULL,

    [embedded_data] [image] NULL,

    PRIMARY KEY CLUSTERED

    (

    [id] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]

    ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

    GO

    ALTER TABLE [dbo].[task_attach] WITH NOCHECK ADD CONSTRAINT [FK_task_attach_task_user] FOREIGN KEY([id_task_user])

    REFERENCES [dbo].[task_user] ([id])

    ON UPDATE CASCADE

    ON DELETE CASCADE

    GO

    ALTER TABLE [dbo].[task_attach] CHECK CONSTRAINT [FK_task_attach_task_user]

    GO

    Same for task_user please.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Can you include the CREATE TABLE script for task_user as well?

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Below script is of task_user

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    CREATE TABLE [dbo].[task_user](

    [id] [uniqueidentifier] NOT NULL,

    [id_acs_user] [uniqueidentifier] NOT NULL,

    [task_type] [int] NOT NULL,

    [name] [nvarchar](15) NOT NULL,

    [status] [smallint] NULL,

    [xoperation] [ntext] NULL,

    [xparameters] [ntext] NULL,

    [xreport] [ntext] NULL,

    [date_begin] [datetime] NULL,

    [date_end] [datetime] NULL,

    [date_schedule] [datetime] NULL,

    [id_link] [uniqueidentifier] NULL,

    [id_supertask] [uniqueidentifier] NULL,

    CONSTRAINT [PK__task_user__26509D48] PRIMARY KEY CLUSTERED

    (

    [id] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]

    ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

    GO

    ALTER TABLE [dbo].[task_user] WITH NOCHECK ADD CONSTRAINT [FK_task_user_acs_user] FOREIGN KEY([id_acs_user])

    REFERENCES [dbo].[acs_user] ([id])

    ON UPDATE CASCADE

    ON DELETE CASCADE

    GO

    ALTER TABLE [dbo].[task_user] CHECK CONSTRAINT [FK_task_user_acs_user]

    GO

    ALTER TABLE [dbo].[task_user] ADD CONSTRAINT [DF_task_user_task_type] DEFAULT (0) FOR [task_type]

    GO

  • Just to recap, when you run the third query, this one:

    -- checkin

    select count(*), avg(datalength(embedded_data)) from task_attach where id_task_user in (

    select id

    from task_user

    where task_type = 2

    and date_begin >= CAST(CAST(DATEADD(DAY,-180,GETDATE()) AS DATE) AS DATETIME)

    )

    you get an error?

    What about when you run just the subquery:

    (

    select id

    from task_user

    where task_type = 2

    and date_begin >= CAST(CAST(DATEADD(DAY,-180,GETDATE()) AS DATE) AS DATETIME)

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • The sub query gets executed successfully.

  • When i run the whole query below i get error. The subquery runs successfully.

    Msg 8115, Level 16, State 2, Line 1

    Arithmetic overflow error converting expression to data type int.

    select count(*), avg(datalength(embedded_data)) from task_attach where id_task_user in (

    select id

    from task_user

    where task_type = 2

    and date_begin >= CAST(CAST(DATEADD(DAY,-180,GETDATE()) AS DATE) AS DATETIME)

    )

  • select count(*), avg(datalength(embedded_data)) from task_attach where id_task_user = NEWID()

    AVG_BIG()?

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • The output is

    0, NULL

  • Just a thought - try this mod:

    AVG(CAST(datalength(embedded_data) AS BIGINT))

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Wow, it worked. 🙂

    select count(*), AVG(CAST(datalength(embedded_data) AS BIGINT)) from task_attach where id_task_user in (

    select id

    from task_user

    where task_type = 2

    and date_begin >= CAST(CAST(DATEADD(DAY,-180,GETDATE()) AS DATE) AS DATETIME)

    )

  • ChrisM@Work (6/28/2016)


    Just a thought - try this mod:

    AVG(CAST(datalength(embedded_data) AS BIGINT))

    More like this:

    AVG(datalength(CAST(embedded_data AS varbinary(MAX))))

    However, the image data type length can fit in an int.

    From BOL for DATALENGTH:

    Return Types

    bigint if expression is of the varchar(max), nvarchar(max) or varbinary(max) data types; otherwise int.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • So is it a problem with the code ?

  • Luis Cazares (6/28/2016)


    ChrisM@Work (6/28/2016)


    Just a thought - try this mod:

    AVG(CAST(datalength(embedded_data) AS BIGINT))

    More like this:

    AVG(datalength(CAST(embedded_data AS varbinary(MAX))))

    However, the image data type length can fit in an int.

    From BOL for DATALENGTH:

    Return Types

    bigint if expression is of the varchar(max), nvarchar(max) or varbinary(max) data types; otherwise int.

    Yes, but n (rows) * datalength might not. Good catch though Luis.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

Viewing 15 posts - 16 through 30 (of 32 total)

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