473,394 Members | 1,879 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,394 software developers and data experts.

How to force Cross tab to show row when no value?

Let us say, that I have a table structured like this:

tblExpenses
===========
uid autonumber (key)
ExpenseArea text
ExpenseType text
Year Number
Value Number


With the following posts:

uid ExpenseArea ExpenseType Year Value
=== =========== =========== ==== =====
001 Gynger Investering 2010 15
002 Gynger Investering 2011 10
003 Gynger Investering 2012 8
004 Gynger Investering 2013 12
005 Gynger Investering 2014 13
006 Gynger Drift 2010 2
007 Gynger Drift 2011 2
008 Gynger Drift 2012 3
009 Gynger Drift 2013 2
010 Gynger Drift 2014 3
011 Karuseller Drift 2010 12
012 Karuseller Drift 2011 12
013 Karuseller Drift 2012 13
014 Karuseller Drift 2013 12
015 Karuseller Drift 2014 13


Using the below query I get the data summed for each year.

TRANSFORM Sum(tblExpenses.Value) AS SumOfValue
SELECT tblExpenses.[ExpenseArea], tblExpenses.[ExpenseType]
FROM tblExpenses
GROUP BY tblExpenses.[ExpenseArea], tblExpenses.[ExpenseType]
PIVOT tblExpenses.[Year];


Now, As you can see in the dataset, there are no values for 'Karuseller', 'Investering', and my question is, if there is some way of forcing the query to return a row for this but without any values?

One thought I had was to have the expensetypes listed in a separate table and using a nested SQL (or something along those lines) to force it to show all expensetypes as described.


/Soren
Jan 18 '11 #1
10 2960
Rabbit
12,516 Expert Mod 8TB
You could either cross join an expensearea table with an expensetype table and then outer join that to expenses table or you could create a table with all the combinations you need and then outer join that with the expenses table.
Jan 18 '11 #2
parodux
26
Expand|Select|Wrap|Line Numbers
  1. TRANSFORM Val(NZ(Sum(tblExpenses.Value),0)) AS SumOfValue
  2. SELECT tblExpenses.[ExpenseArea], tblExpenses.[ExpenseType]
  3. FROM tblExpenses
  4. GROUP BY tblExpenses.[ExpenseArea], tblExpenses.[ExpenseType]
  5. PIVOT tblExpenses.[Year]; 
er der andet, så kan du fange mig her!~)
Jan 19 '11 #3
Parodux,

(will write in English in order for others to be able to read along)
I tried your suggestion, but it still does not give me a row for 'Karuseller', 'Investering'.
Could I be missing something?

/Søren
Feb 1 '11 #4
Rabbit
12,516 Expert Mod 8TB
He misunderstood what you wanted to do. You have to use my suggestion.
Feb 1 '11 #5
I was actually trying to get that to work.
I created the two additional tables (ExpensesArea and ExpensesType), and added to id fields to the Expenses table.

I can get it to handle one of them by using outer join, but it will not accept two. It suggests that I first do one query with one join, and then use that query for the next join.
Is that what you mean by cross join?

And could you perhaps give an example?
Feb 1 '11 #6
Ok, I believe that I get the cross join part now:
SELECT * FROM tblExpenseAreas, tblExpenseTypes

But can I use that directly in the other query? Or do I need to save it as a separate qeury, and then use that like a table?
Feb 1 '11 #7
Rabbit
12,516 Expert Mod 8TB
You can do it all in one query by making that into a subquery but it might be easier for you to understand if you save it into a separate query. Whichever way you decide to do it, next you'll want to left or right outer join (depending on how you order the tables) that subquery or query.
Feb 1 '11 #8
Ok, I got the following to work:

Created a cross join query named qryCrossJoin:
Expand|Select|Wrap|Line Numbers
  1. SELECT tblExpenseAreas.ExpenseArea, tblExpenseTypes.ExpenseType, tblExpenseAreas.uid AS AreaId, tblExpenseTypes.uid AS TypeId
  2. FROM tblExpenseAreas, tblExpenseTypes;
And used that in my cross tab query:
Expand|Select|Wrap|Line Numbers
  1. TRANSFORM Sum(tblExpenses.Value) AS SumOfValue
  2. SELECT qryCrossJoin.ExpenseArea, qryCrossJoin.ExpenseType
  3. FROM qryCrossJoin LEFT JOIN tblExpenses ON (qryCrossJoin.TypeId = tblExpenses.TypeId) AND (qryCrossJoin.AreaId = tblExpenses.AreaId)
  4. GROUP BY qryCrossJoin.ExpenseArea, qryCrossJoin.ExpenseType
  5. PIVOT tblExpenses.Year;
As mentioned this works :-)


Now, the example above is a lot simpler than my actual queries, which combines a number of different tables.
So I would really like to learn how to achieve the above in a single query.
Care to help?
Feb 1 '11 #9
Yes! Got it!

Expand|Select|Wrap|Line Numbers
  1. TRANSFORM Sum(tblExpenses.Value) AS SumOfValue
  2. SELECT Q.ExpenseArea, Q.ExpenseType
  3. FROM (SELECT tblExpenseAreas.ExpenseArea, tblExpenseTypes.ExpenseType, tblExpenseAreas.uid AS AreaId, tblExpenseTypes.uid AS TypeId
  4. FROM tblExpenseAreas, tblExpenseTypes) As Q LEFT JOIN tblExpenses ON (Q.AreaId=tblExpenses.AreaId) AND (Q.TypeId=tblExpenses.TypeId)
  5. GROUP BY Q.ExpenseArea, Q.ExpenseType
  6. PIVOT tblExpenses.Year;
  7.  
I see a brand new world unfolding before me ;-)

Thanks a bunch, Rabbit!
Feb 1 '11 #10
Rabbit
12,516 Expert Mod 8TB
No problem, good luck with the rest of the project!
Feb 1 '11 #11

Sign in to post your reply or Sign up for a free account.

Similar topics

4
by: Ruel | last post by:
Is there an equivalent to the "Break When Value is True" Watch option in .NET. I have yet to discover it.
16
by: Charles Kerekes | last post by:
Hello everyone, I am still learning C++, so I'm not sure what I'm trying to do is possible. Her is a simplified example: char Test = 'L'; cout << "Test Char as decimal: " << dec << Test <<...
5
by: jrefactors | last post by:
I am trying to debug some values in production server. I want to print the value of rRes(10), but I don't want to show it in the screen. I just want to show it in the source code but comment out,...
9
by: garima puri | last post by:
hi ihad made a form in which dynamic rows are added to a table. now when i send there values to next page by GETmethod then in between alphabets where space is given + is shown and where new line...
2
by: Johann Schuler | last post by:
Let's say I have a Person class with a private int age member variable. I have a get and set accessor for the Age property. When I am running the code in debug mode, I would like to have a debug...
0
by: cipcip | last post by:
hello wolrd, how can i show a value in the datagrid instead of a value in the db eg. show "stopped" instead of "0"
2
by: SergioQ | last post by:
Hi all, am trying to show a dollar figure on my webpage, but defining this for the cents value: font-size: 80%; vertical-align: super; just isn't cutting it! Is there a way to reduce the...
5
by: Proaccesspro | last post by:
Hello All, I've created a report that lists un-filled orders by age (in days). When the user clicks on the report it will ask them to input the number of days. (If the user wanted to see all...
3
by: j dillard | last post by:
I am trying to add date/time stamps to an access record to show when certain fields were updated. For Example: when I change a field from being blank to a Y i need to show a date/time stamp in...
0
by: Charles Arthur | last post by:
How do i turn on java script on a villaon, callus and itel keypad mobile phone
0
BarryA
by: BarryA | last post by:
What are the essential steps and strategies outlined in the Data Structures and Algorithms (DSA) roadmap for aspiring data scientists? How can individuals effectively utilize this roadmap to progress...
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...
0
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows...
0
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.