Month Summarised tabular data output from a table

  • Using SQL how is it possible to get this data transformed in a tabular summary report?

    data sample

    supplier number selection_date document_type

    0000001 01/07/2012 AB10019

    0000002 01/07/2012 AB20011

    0000001 01/07/2012 FR10089

    0000031 01/08/2012 AB10084

    0000021 01/08/2012 FR10089

    0000001 01/08/2012 FR10089

    0000005 01/09/2012 FR13019

    0000003 01/09/2012 AB15006

    0000010 01/11/2012 FR10019

    0000012 01/11/2012 FR13449

    0000010 01/11/2012 FR13319

    0000011 01/11/2012 AB14215

    Report output:

    Month Name Count of AB-Types Count of FR-Types

    July 2 1

    Aug 1 2

    Sept 1 1

    Nov 1 3

    The report should be in order of the month

    I will filter it by Year 2012/2011.

    Assume there are only AB and FR type documents with different numberings at end (so use of like operator is required)

    There will be no Zero count months

    Thank you.

  • I see that you are pretty new around here. It is recommended that you post ddl and sample data in a consumable format so the people helping can get right to work on your problem instead of working on creating the problem so we can start on the solution. I took the liberty of creating this information as an example. This is something you should do in future posts.

    if object_id('tempdb..#Data') is not null

    drop table #Data

    create table #Data

    (

    Supplier int,

    SelectionDate datetime,

    document_type char(7)

    )

    set dateformat dmy

    insert #Data

    select 1, '01/07/2012', 'AB10019' union all

    select 2, '01/07/2012', 'AB20011' union all

    select 1, '01/07/2012', 'FR10089' union all

    select 31, '01/08/2012', 'AB10084' union all

    select 21, '01/08/2012', 'FR10089' union all

    select 1, '01/08/2012', 'FR10089' union all

    select 5, '01/09/2012', 'FR13019' union all

    select 3, '01/09/2012', 'AB15006' union all

    select 10, '01/11/2012', 'FR10019' union all

    select 12, '01/11/2012', 'FR13449' union all

    select 10, '01/11/2012', 'FR13319' union all

    select 11, '01/11/2012', 'AB14215'

    select * from #Data

    select datename(Month, SelectionDate),

    sum(case when left(document_type, 2) = 'AB' then 1 else 0 end) as AB_Count,

    sum(case when left(document_type, 2) = 'FR' then 1 else 0 end) as FR_Count

    from #Data

    group by datename(Month, SelectionDate), SelectionDate

    order by SelectionDate

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks Sean for that.

    Infact I wanted unique counts of the document types, so I took the distinct data into a temp table and then using your SQL queried from that to give month-by-month totals.

    Almost forgot the dynamic "sum".

    And thanks for the ddl example, I will remember to post data like that.

    Bij

  • You're welcome. Glad that helped.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

Viewing 4 posts - 1 through 3 (of 3 total)

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